docs.md 94.7 KB
Newer Older
1 2
# TAOS SQL

G
Ganlin Zhao 已提交
3
TDengine provides a SQL-style language, TAOS SQL, to insert or query data. This document introduces TAOS SQL and supports other common tips. To read through this document, readers should have basic understanding about SQL.
4

G
Ganlin Zhao 已提交
5
TAOS SQL is the main tool for users to write and query data into/from TDengine. TAOS SQL provides a syntax style similar to standard SQL to facilitate users to get started quickly. Strictly speaking, TAOS SQL is not and does not attempt to provide SQL standard syntax. In addition, since TDengine does not provide deletion functionality for time-series data, the relevant functions of data deletion is unsupported in TAO SQL.
6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36

Let’s take a look at the conventions used for syntax descriptions.

- The content in < > is what the user needs to enter, but do not enter < > itself
- [] indicates that the content is optional, but do not enter [] itself
- "|" means you can select one of multiple choices, but you cannot enter | yourself
- "…" means repeating for as many times

In order to better explain the rules and characteristics of SQL syntax, this document assumes that there is a data set. Take smart meters as an example, each smart meter collects three metrics: current, voltage and phase. It is modeled as follows:

```mysql
taos> DESCRIBE meters;
             Field              |        Type        |   Length    |    Note    |
=================================================================================
 ts                             | TIMESTAMP          |           8 |            |
 current                        | FLOAT              |           4 |            |
 voltage                        | INT                |           4 |            |
 phase                          | FLOAT              |           4 |            |
 location                       | BINARY             |          64 | TAG        |
 groupid                        | INT                |           4 | TAG        |
```

The data set contains data from four smart meters, which correspond to four sub-tables according to the modeling rules of TDengine, and their names are D1001, D1002, D1003 and D1004 respectively.

## <a class="anchor" id="data-type"></a> Data Types

With TDengine, the most important thing is timestamp. When creating and inserting records and querying history records, you need to specify a timestamp. The timestamp has the following rules:

- Time Format: 'YYYY-MM-DD HH:mm:ss.MS', default in milliseconds. For example,'2017-08-12 18:52:58.128'
- Internal Function **now** : this is the current time of the server
- When inserting a record, if timestamp is NOW, then use the server current time.
37
- Epoch Time: a timestamp value can also be a long integer representing milliseconds since 1970-01-01 08:00:00.000.
38 39
- Arithmetic operations can be applied to timestamp. For example: now-2h represents a timestamp which is 2 hours ago from the current server time. Units include u( microsecond), a (milliseconds), s (seconds), m (minutes), h (hours), d (days), w (weeks). In `select * from t1 where ts > now-2w and ts <= now-1w`, which queries data of the whole week before two weeks. To specify the interval of down sampling, you can also use n(calendar month) and y(calendar year) as time units.

E
Elias Soong 已提交
40
TDengine's timestamp is set to millisecond accuracy by default. Microsecond/nanosecond accuracy can be set using CREATE DATABASE with PRECISION parameter. (Nanosecond resolution is supported from version 2.1.5.0 onwards.)
41 42 43 44 45 46

In TDengine, the following 10 data types can be used in data model of an ordinary table.

|      | **Data Type** | **Bytes** | **Note**                                                     |
| ---- | ------------- | --------- | ------------------------------------------------------------ |
| 1    | TIMESTAMP     | 8         | Time stamp. Default in milliseconds, and support microseconds. Starting from 1970-01-01 00:00:00. 000 (UTC/GMT), the timing cannot be earlier than this time. |
47 48 49 50
| 2    | INT           | 4         | A null-able integer type with a range of [-2^31+1, 2^31-1 ]   |
| 3    | BIGINT        | 8         | A null-able integer type with a range of [-2^59, 2^59 ]       |
| 4    | FLOAT         | 4         | A standard null-able float type with 6 -7 significant digits and a range of [-3.4E38, 3.4E38] |
| 5    | DOUBLE        | 8         | A standard null-able double float type with 15-16 significant digits and a range of [-1.7E308, 1.7E308] |
51
| 6    | BINARY        | Custom    | Used to record ASCII strings. Theoretically, the maximum length can be 16,374 bytes, but since each row of data can be up to 16K bytes, the actual limit is generally smaller than the theoretical value. Binary only supports string input, and single quotation marks are used at both ends of the string, otherwise all English will be automatically converted to lowercase. When using, the size must be specified. For example, binary (20) defines a string with a maximum length of 20 characters, and each character occupies 1 byte of storage space. In this case, if the user string exceeds 20 bytes, an error will be reported. For single quotation marks in strings, they can be represented by escape character backslash plus single quotation marks, that is\ '. |
52 53
| 7    | SMALLINT      | 2         | A null-able integer type with a range of [-32767, 32767]      |
| 8    | TINYINT       | 1         | A null-able integer type with a range of [-127, 127]          |
54 55
| 9    | BOOL          | 1         | Boolean type,{true, false}                                  |
| 10   | NCHAR         | Custom    | Used to record non-ASCII strings, such as Chinese characters. Each nchar character takes up 4 bytes of storage space. Single quotation marks are used at both ends of the string, and escape characters are required for single quotation marks in the string, that is \’. When nchar is used, the string size must be specified. A column of type nchar (10) indicates that the string of this column stores up to 10 nchar characters, which will take up 40 bytes of space. If the length of the user string exceeds the declared length, an error will be reported. |
wmmhello's avatar
wmmhello 已提交
56
| 11   | JSON          |           | Json type,only support for tag                                  |
57 58 59 60 61 62


**Tips**:

1. TDengine is case-insensitive to English characters in SQL statements and automatically converts them to lowercase for execution. Therefore, the user's case-sensitive strings and passwords need to be enclosed in single quotation marks.
2. Avoid using BINARY type to save non-ASCII type strings, which will easily lead to errors such as garbled data. The correct way is to use NCHAR type to save Chinese characters.
G
Ganlin Zhao 已提交
63
3. The numerical values in SQL statements are treated as floating or integer numbers, depends on if the value contains decimal point or is in scientific notation format. Therefore, caution is needed since overflow might happen for corresponding data types. E.g., 9999999999999999999 is overflowed as the number is greater than the largest integer number. However, 9999999999999999999.0 is treated as a valid floating number. 
64 65 66

## <a class="anchor" id="management"></a>Database Management

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
67
- **Create a Database**
68 69 70 71 72 73 74 75 76 77 78

   ```mysql
      CREATE DATABASE [IF NOT EXISTS] db_name [KEEP keep] [DAYS days] [UPDATE 1];
   ```

Note:

1. KEEP is how long the data of the database is kept, the default is 3650 days (10 years), and the database will automatically delete the data expired;
2. UPDATE marks the database support updating the same timestamp data;
3. Maximum length of the database name is 33;
4. Maximum length of a SQL statement is 65480 characters;
E
Elias Soong 已提交
79
5. Database has more storage-related configuration parameters, see [Server-side Configuration](https://www.taosdata.com/en/documentation/administrator#config) .
80

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
81
- **Show current system parameters**
82

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
83 84 85
    ```mysql
    SHOW VARIABLES;
    ```
86

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
87
- **Use a database**
88

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
89 90 91
    ```mysql
    USE db_name;
    ```
A
Anaïs Huang 已提交
92
    Use/switch database (Invalid when accessing through RESTful connection)
93

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
94 95 96 97 98
- **Drop a database**
    ```mysql
    DROP DATABASE [IF EXISTS] db_name;
    ```
    Delete a database, all data tables included will be deleted. Please use with caution.
99

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
100
- **Modify database parameters**
101

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
102 103 104 105
    ```mysql
    ALTER DATABASE db_name COMP 2;
    ```
    COMP parameter modifies the database file compression flag bit, with the default value of 2 and the value range is [0, 2]. 0 means no compression, 1 means one-stage compression, and 2 means two-stage compression.
106

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
107
    ```mysql
108
    ALTER DATABASE db_name REPLICA 2;
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
109 110
    ```
    REPLICA parameter refers to the number of replicas of the modified database, and the value range is [1, 3]. For use in a cluster, the number of replicas must be less than or equal to the number of DNODE.
111

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
112 113 114 115
    ```mysql
    ALTER DATABASE db_name KEEP 365;
    ```
    The KEEP parameter refers to the number of days to save a modified data file. The default value is 3650, and the value range is [days, 365000]. It must be greater than or equal to the days parameter value.
116 117

   ```mysql
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
118
   ALTER DATABASE db_name QUORUM 2;
119
   ```
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
120
   QUORUM parameter refers to the number of confirmations required for successful data writing, and the value range is [1, 3]. For asynchronous replication, quorum is set to 1, and the virtual node with master role can confirm it by itself. For synchronous replication, it needs to be at least 2 or greater. In principle, Quorum > = 1 and Quorum < = replica number, which is required when starting a synchronization module instance.
121

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
122
    ```mysql
123
    ALTER DATABASE db_name BLOCKS 100;
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
124 125
    ```
   BLOCKS parameter is the number of cache-sized memory blocks in each VNODE (TSDB), so the memory size used for a VNODE equals roughly (cache * blocks). Value range is [3,1000].
126

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
127
    ```mysql
128
    ALTER DATABASE db_name CACHELAST 0;
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
129 130
    ```
    CACHELAST parameter controls whether last_row of the data subtable is cached in memory. The default value is 0, and the value range is [0, 1]. Where 0 means not enabled and 1 means enabled. (supported from version 2.0. 11)
131
   
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
132
    **Tips**: After all the above parameters are modified, show databases can be used to confirm whether the modification is successful.
133

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
134
- **Show all databases in system**
135

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
136 137 138
    ```mysql
    SHOW DATABASES;
    ```
139 140 141

## <a class="anchor" id="table"></a> Table Management

142
- **Create a table**
143

144 145 146 147 148 149
    ```mysql
    CREATE TABLE [IF NOT EXISTS] tb_name (timestamp_field_name TIMESTAMP, field1_name data_type1 [, field2_name data_type2 ...]);
    ```
  Note:
   1. The first field must be a timestamp, and system will set it as the primary key;
   2. The max length of table name is 192;
150
   3. The length of each row of the table cannot exceed 48K (it's 16K prior to 2.1.7.0) characters;
151 152
   4. Sub-table names can only consist of letters, numbers, and underscores, and cannot begin with numbers
   5. If the data type binary or nchar is used, the maximum number of bytes should be specified, such as binary (20), which means 20 bytes;
153

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
154
- **Create a table via STable**
155

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
156 157 158 159
    ```mysql
    CREATE TABLE [IF NOT EXISTS] tb_name USING stb_name TAGS (tag_value1, ...);
    ```
    Use a STable as template and assign tag values to create a data table.
160 161 162

- **Create a data table using STable as a template and specify a specific tags column**

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
163 164 165 166 167
   ```mysql
   CREATE TABLE [IF NOT EXISTS] tb_name USING stb_name (tag_name1, ...) TAGS (tag_value1, ...);
   ```
   Using the specified STable as a template, specify the values of some tags columns to create a data table. (Unspecified tags columns are set to null values.)
   Note: This method has been supported since version 2.0. 17. In previous versions, tags columns were not allowed to be specified, but the values of all tags columns must be explicitly given.
168

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
169
- **Create tables in batches**
170

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
171
   ```mysql
172
   CREATE TABLE [IF NOT EXISTS] tb_name1 USING stb_name TAGS (tag_value1, ...) [IF NOT EXISTS] tb_name2 USING stb_name TAGS (tag_value2, ...) ...;
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
173 174 175 176 177
   ```
   Create a large number of data tables in batches faster. (Server side 2.0. 14 and above)
   
   Note:
   1. The method of batch creating tables requires that the data table must use STable as a template.
178
   2. On the premise of not exceeding the length limit of SQL statements, it is suggested that the number of tables in a single statement should be controlled between 1000 and 3000, which will obtain an ideal speed of table creating.
179

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
180
- **Drop a table**
181
  
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
182 183 184
    ```mysql
    DROP TABLE [IF EXISTS] tb_name;
    ```
185

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
186
- **Show all data table information under the current database**
187

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
188
    ```mysql
189
    SHOW TABLES [LIKE tb_name_wildcard];
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
190 191 192 193
    ```
    Show all data table information under the current database.
    Note: Wildcard characters can be used to match names in like. The maximum length of this wildcard character string cannot exceed 24 bytes.
    Wildcard matching: 1) '%' (percent sign) matches 0 to any number of characters; 2) '_' underscore matches one character.
194

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
195
- **Modify display character width online**
196

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
197 198 199
    ```mysql
    SET MAX_BINARY_DISPLAY_WIDTH <nn>;
    ```
200

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
201 202 203 204 205
- **Get schema information of a table**
  
    ```mysql
    DESCRIBE tb_name;
    ```
206

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
207
- **Add a column to table**
208

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
209 210 211 212 213 214
   ```mysql
   ALTER TABLE tb_name ADD COLUMN field_name data_type;
   ```
   Note:
   1. The maximum number of columns is 1024 and the minimum number is 2;
   2. The maximum length of a column name is 64; 
215

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
216
- **Drop a column in table**
217

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
218 219 220 221
   ```mysql
   ALTER TABLE tb_name DROP COLUMN field_name; 
   ```
   If the table is created through a STable, the operation of table schema changing can only be carried out on the STable. Moreover, the schema changes for the STable take effect for all tables created through the schema. For tables that are not created through STables, you can modify the table schema directly.
222 223 224

## <a class="anchor" id="super-table"></a> STable Management

225
Note: In 2.0.15.0 and later versions, STABLE reserved words are supported. That is, in the instruction description later in this section, the three instructions of CREATE, DROP and ALTER need to write TABLE instead of STABLE in the old version as the reserved word.
226

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
227
- **Create a STable**
228

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
229 230 231
    ```mysql
    CREATE STABLE [IF NOT EXISTS] stb_name (timestamp_field_name TIMESTAMP, field1_name data_type1 [, field2_name data_type2 ...]) TAGS (tag1_name tag_type1, tag2_name tag_type2 [, tag3_name tag_type3]);
    ```
B
Bo Ding 已提交
232
    Similar to a standard table creation SQL, but you need to specify name and type of TAGS field.
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
233 234 235 236 237 238
    
    Note:
    
    1. Data types of TAGS column cannot be timestamp;
    2. No duplicated TAGS column names;
    3. Reversed word cannot be used as a TAGS column name;
239
    4. The maximum number of TAGS is 128, and at least 1 TAG allowed, with a total length of no more than 16K characters.
240

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
241
- **Drop a STable**
242

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
243 244 245 246
    ```mysql
    DROP STABLE [IF EXISTS] stb_name;
    ```
    Drop a STable automatically deletes all sub-tables created through the STable.
247

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
248
- **Show all STable information under the current database**
249

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
250 251 252 253
    ```mysql
    SHOW STABLES [LIKE tb_name_wildcard];
    ```
    View all STables under the current database and relevant information, including name, creation time, column number, tag number, number of tables created through the STable, etc.
254

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
255
- **Obtain schema information of a STable**
256

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
257 258 259
    ```mysql
    DESCRIBE stb_name;
    ```
260

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
261
- **Add column to STable**
262

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
263 264 265
    ```mysql
    ALTER STABLE stb_name ADD COLUMN field_name data_type;
    ```
266

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
267
- **Drop column in STable**
268

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
269 270 271
    ```mysql
    ALTER STABLE stb_name DROP COLUMN field_name; 
    ```
272 273 274

## <a class="anchor" id="tags"></a> TAG Management in STable

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
275
- **Add a tag**
276

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
277 278 279 280
    ```mysql
    ALTER STABLE stb_name ADD TAG new_tag_name tag_type;
    ```
    Add a new tag to the STable and specify a type of the new tag. The total number of tags cannot exceed 128 and the total length does not exceed 16K characters.
281

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
282
- **Drop a tag**
283

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
284 285 286 287
    ```mysql
    ALTER STABLE stb_name DROP TAG tag_name;
    ```
    Delete a tag of STable. After deleting the tag, all sub-tables under the STable will also automatically delete the same tag.
288

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
289
- **Modify a tag name**
290

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
291 292 293 294
    ```mysql
    ALTER STABLE stb_name CHANGE TAG old_tag_name new_tag_name;
    ```
    Modify a tag name of STable. After modifying, all sub-tables under the STable will automatically update the new tag name.
295

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
296
- **Modify a tag value of sub-table**
297
  
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
298 299 300 301
    ```mysql
    ALTER TABLE tb_name SET TAG tag_name=new_tag_value;
    ```
    Note: Except that the operation of tag value updating is carried out for sub-tables, all other tag operations (adding tags, deleting tags, etc.) can only be applied to STable, and cannot be operated on a single sub-table. After adding a tag to a STable, all tables established based on that will automatically add a new tag, and the default value is NULL.
302 303 304

## <a class="anchor" id="insert"></a> Data Writing

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
305
- **Insert a record**
306 307

  ```mysql
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
308
  INSERT INTO tb_name VALUES (field_value, ...);
309
  ```
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
310
  Insert a record into table tb_name.
311

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
312
- **Insert a record with data corresponding to a given column**
313
  
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
314 315 316 317
    ```mysql
    INSERT INTO tb_name (field1_name, ...) VALUES (field1_value1, ...);
    ```
    Insert a record into table tb_name, and the data corresponds to a given column. For columns that do not appear in the SQL statement, database will automatically populate them with NULL. Primary key (timestamp) cannot be NULL.
318

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
319
- **Insert multiple records**
320

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
321 322 323 324
    ```mysql
    INSERT INTO tb_name VALUES (field1_value1, ...) (field1_value2, ...) ...;
    ```
    Insert multiple records into table tb_name.
325

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
326
- **Insert multiple records into a given column**
327
  
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
328 329 330 331
    ```mysql
    INSERT INTO tb_name (field1_name, ...) VALUES (field1_value1, ...) (field1_value2, ...) ...;
    ```
    Insert multiple records into a given column of table tb_name.
332

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
333
- **Insert multiple records into multiple tables**
334
  
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
335 336 337 338 339
    ```mysql
    INSERT INTO tb1_name VALUES (field1_value1, ...) (field1_value2, ...) ...
                tb2_name VALUES (field1_value1, ...) (field1_value2, ...) ...;
    ```
    Insert multiple records into tables tb1_name and tb2_name at the same time.
340

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
341
- **Insert multiple records per column into multiple tables**
342

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
343 344 345 346 347 348
    ```mysql
    INSERT INTO tb1_name (tb1_field1_name, ...) VALUES (field1_value1, ...) (field1_value2, ...) ...
                tb2_name (tb2_field1_name, ...) VALUES (field1_value1, ...) (field1_value2, ...) ...;
    ```
    Insert multiple records per column into tables tb1_name and tb2_name at the same time.
    Note: The timestamp of the oldest record allowed to be inserted is relative to the current server time, minus the configured keep value (days of data retention), and the timestamp of the latest record allowed to be inserted is relative to the current server time, plus the configured days value (interval of data storage in the data file, in days). Both keep and days can be specified when the database is created, and the default values are 3650 days and 10 days, respectively.
349 350 351

- <a class="anchor" id="auto_create_table"></a> Automatically create a table when inserting

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
352 353 354 355
    ```mysql
    INSERT INTO tb_name USING stb_name TAGS (tag_value1, ...) VALUES (field_value1, ...);
    ```
    If user is not sure whether a table exists when writing data, the automatic table building syntax can be used to create a non-existent table when writing. If the table already exists, no new table will be created. When automatically creating a table, it is required to use the STable as a template and specify tags value for the data table.
356

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
357 358 359 360 361 362
- **Automatically create a table when inserting, and specify a given tags column**
  
    ```mysql
    INSERT INTO tb_name USING stb_name (tag_name1, ...) TAGS (tag_value1, ...) VALUES (field_value1, ...);
    ```
    During automatic table creation, only the values of some tags columns can be specified, and the unspecified tags columns will be null.
363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411

**History writing**: The IMPORT or INSERT command can be used. The syntax and function of IMPORT are exactly the same as those of INSERT.

Note: For SQL statements in insert type, the stream parsing strategy we adopt will still execute the correct part of SQL before the following errors are found. In the following sql, insert statement is invalid, but d1001 will still be created.

```mysql
taos> CREATE TABLE meters(ts TIMESTAMP, current FLOAT, voltage INT, phase FLOAT) TAGS(location BINARY(30), groupId INT);
Query OK, 0 row(s) affected (0.008245s)

taos> SHOW STABLES;
              name              |      created_time       | columns |  tags  |   tables    |
============================================================================================
 meters                         | 2020-08-06 17:50:27.831 |       4 |      2 |           0 |
Query OK, 1 row(s) in set (0.001029s)

taos> SHOW TABLES;
Query OK, 0 row(s) in set (0.000946s)

taos> INSERT INTO d1001 USING meters TAGS('Beijing.Chaoyang', 2) VALUES('a');

DB error: invalid SQL: 'a' (invalid timestamp) (0.039494s)

taos> SHOW TABLES;
           table_name           |      created_time       | columns |          stable_name           |
======================================================================================================
 d1001                          | 2020-08-06 17:52:02.097 |       4 | meters                         |
Query OK, 1 row(s) in set (0.001091s)
```

## <a class="anchor" id="select"></a> Data Query

### Query Syntax:

```mysql
SELECT select_expr [, select_expr ...]
    FROM {tb_name_list}
    [WHERE where_condition]
    [INTERVAL (interval_val [, interval_offset])]
    [SLIDING sliding_val]
    [FILL fill_val]
    [GROUP BY col_list]
    [ORDER BY col_list { DESC | ASC }]
    [SLIMIT limit_val [SOFFSET offset_val]]
    [LIMIT limit_val [OFFSET offset_val]]
    [>> export_file];
```

#### SELECT Clause

412
A select clause can be a sub-query of UNION and another query.
413 414 415 416 417 418 419 420 421 422 423 424 425 426 427

#### Wildcard character

The wildcard \* can be used to refer to all columns. For ordinary tables, there’re only ordinary columns in results.

```mysql
taos> SELECT * FROM d1001;
           ts            |       current        |   voltage   |        phase         |
======================================================================================
 2018-10-03 14:38:05.000 |             10.30000 |         219 |              0.31000 |
 2018-10-03 14:38:15.000 |             12.60000 |         218 |              0.33000 |
 2018-10-03 14:38:16.800 |             12.30000 |         221 |              0.31000 |
Query OK, 3 row(s) in set (0.001165s)
```

428
For STables, wildcards contain *tag columns*.
429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534

```mysql
taos> SELECT * FROM meters;
           ts            |       current        |   voltage   |        phase         |            location            |   groupid   |
=====================================================================================================================================
 2018-10-03 14:38:05.500 |             11.80000 |         221 |              0.28000 | Beijing.Haidian                |           2 |
 2018-10-03 14:38:16.600 |             13.40000 |         223 |              0.29000 | Beijing.Haidian                |           2 |
 2018-10-03 14:38:05.000 |             10.80000 |         223 |              0.29000 | Beijing.Haidian                |           3 |
 2018-10-03 14:38:06.500 |             11.50000 |         221 |              0.35000 | Beijing.Haidian                |           3 |
 2018-10-03 14:38:04.000 |             10.20000 |         220 |              0.23000 | Beijing.Chaoyang               |           3 |
 2018-10-03 14:38:16.650 |             10.30000 |         218 |              0.25000 | Beijing.Chaoyang               |           3 |
 2018-10-03 14:38:05.000 |             10.30000 |         219 |              0.31000 | Beijing.Chaoyang               |           2 |
 2018-10-03 14:38:15.000 |             12.60000 |         218 |              0.33000 | Beijing.Chaoyang               |           2 |
 2018-10-03 14:38:16.800 |             12.30000 |         221 |              0.31000 | Beijing.Chaoyang               |           2 |
Query OK, 9 row(s) in set (0.002022s)
```

Wildcards support table name prefixes, the two following SQL statements will return all columns:

```mysql
SELECT * FROM d1001;
SELECT d1001.* FROM d1001;
```

In Join query, the results returned by \* with prefix and \* without prefix are different. \* returns all column data of all tables (excluding tags), while wildcards with prefix only return column data of the corresponding table.

```mysql
taos> SELECT * FROM d1001, d1003 WHERE d1001.ts=d1003.ts;
           ts            | current |   voltage   |    phase     |           ts            | current |   voltage   |    phase     |
==================================================================================================================================
 2018-10-03 14:38:05.000 | 10.30000|         219 |      0.31000 | 2018-10-03 14:38:05.000 | 10.80000|         223 |      0.29000 |
Query OK, 1 row(s) in set (0.017385s)
```
```mysql
taos> SELECT d1001.* FROM d1001,d1003 WHERE d1001.ts = d1003.ts;
           ts            |       current        |   voltage   |        phase         |
======================================================================================
 2018-10-03 14:38:05.000 |             10.30000 |         219 |              0.31000 |
Query OK, 1 row(s) in set (0.020443s)
```

In the process of using SQL functions for query, some SQL functions support wildcard operation. The difference is that the `count(\*)` function returns only one column, but the `first`,`last`,`last_row` functions return all columns.

```mysql
taos> SELECT COUNT(*) FROM d1001;
       count(*)        |
========================
                     3 |
Query OK, 1 row(s) in set (0.001035s)
```

```mysql
taos> SELECT FIRST(*) FROM d1001;
        first(ts)        |    first(current)    | first(voltage) |     first(phase)     |
=========================================================================================
 2018-10-03 14:38:05.000 |             10.30000 |            219 |              0.31000 |
Query OK, 1 row(s) in set (0.000849s)
```

####  Tag Column

Since version 2.0. 14, it is supported to specify *tag column* in queries of ordinary tables, and the values of tag columns will be returned together with the data of other ordinary columns.

```mysql
taos> SELECT location, groupid, current FROM d1001 LIMIT 2;
            location            |   groupid   |       current        |
======================================================================
 Beijing.Chaoyang               |           2 |             10.30000 |
 Beijing.Chaoyang               |           2 |             12.60000 |
Query OK, 2 row(s) in set (0.003112s)
```

Note: The wildcard \* of ordinary tables does not contain *tag columns*.

#### Obtain the de-duplicated value of a tag column

Since version 2.0. 15, it is supported to specify `DISTINCT` keyword when querying tag columns in STables, which will return all non-duplicate values of given tag columns.

```mysql
SELECT DISTINCT tag_name FROM stb_name;
```

Note: At present, `DISTINCT` keyword only supports deduplication of tag columns of STables, and cannot be used for ordinary columns.

#### Column name in result set

In `SELECT` clause, if there’s no returning of column name in result set, the result set column name defaults to the expression name in `SELECT` clause as the column name. In addition, user can use `AS` to rename the columns in the returned result set. For example:

```mysql
taos> SELECT ts, ts AS primary_key_ts FROM d1001;
           ts            |     primary_key_ts      |
====================================================
 2018-10-03 14:38:05.000 | 2018-10-03 14:38:05.000 |
 2018-10-03 14:38:15.000 | 2018-10-03 14:38:15.000 |
 2018-10-03 14:38:16.800 | 2018-10-03 14:38:16.800 |
Query OK, 3 row(s) in set (0.001191s)
```

However, renaming for one single column is not supported for `first(*)`,`last(*)`,`last_row(*)`.

#### Implicit result column

`Select_exprs` can be the name of a column belongs to a table, or it can be a column-based functional expression or calculation formula, with an upper limit of 256. When user uses `interval` or `group by tags` clause, the timestamp column (the first column) and the tag column in `group by` clause are forced to be returned in the final returned result. Later versions can support turning off the output of implicit columns in `group by` clause, and the column output is completely controlled by select clause.

#### List of STable

535
The `FROM` keyword can be followed by a list of several tables (STables) or result of a sub-query. 
536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604

If you do not specify user's current database, you can use the database name before the table name to specify the database to which the table belongs. For example: `power.d1001` to use tables across databases.

```mysql
SELECT * FROM power.d1001;
------------------------------
USE power;
SELECT * FROM d1001;
```

#### Special Functions

Some special query functions can be performed without using FROM clause. Obtain the current database database ():

```mysql
taos> SELECT DATABASE();
           database()           |
=================================
 power                          |
Query OK, 1 row(s) in set (0.000079s)
```

If no default database is specified when logging in, and `USE` command is not used to switch data, then `NULL` is returned.

```mysql
taos> SELECT DATABASE();
           database()           |
=================================
 NULL                           |
Query OK, 1 row(s) in set (0.000184s)
```

Get server and client version numbers:

```mysql
taos> SELECT CLIENT_VERSION();
 client_version() |
===================
 2.0.0.0          |
Query OK, 1 row(s) in set (0.000070s)

taos> SELECT SERVER_VERSION();
 server_version() |
===================
 2.0.0.0          |
Query OK, 1 row(s) in set (0.000077s)
```

A server state detection statement. If server is normal, return a number (for example, 1). If server is exceptional, return error code. The SQL syntax can be compatible with the check of TDengine status by connection pool and the check of database server status by third-party tools. And can avoid connection loss of connection pool caused by using a wrong heartbeat detection SQL statement.

```mysql
taos> SELECT SERVER_STATUS();
 server_status() |
==================
               1 |
Query OK, 1 row(s) in set (0.000074s)

taos> SELECT SERVER_STATUS() AS status;
   status    |
==============
           1 |
Query OK, 1 row(s) in set (0.000081s)
```

#### Special keywords in TAOS SQL

>  `TBNAME`: It can be regarded as a special tag in a STable query, representing the name of sub-table involved in the query
>
> _c0: Represents the first column of a table (STable)
G
Ganlin Zhao 已提交
605 606
> _qstart,_qstop,_qduration: Represents starting time/stopping time/duration of query time window filter in where condition (supported since 2.6.0.0)
> _wstart,_wstop,_wduration: Used in time-dimension aggregation query(e.g. interval/session window/state window)to represent starting time/stopping time/duration of each generated time window (supported since 2.6.0.0)
607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667

#### Tips

Get all sub-table names and related tags information of a STable:

```mysql
SELECT TBNAME, location FROM meters;
```

Statistics of sub-tables number under a STable:

```mysql
SELECT COUNT(TBNAME) FROM meters;
```

The  two queries above only support adding filters for TAGS in Where conditional clause. For example:

```mysql
taos> SELECT TBNAME, location FROM meters;
             tbname             |            location            |
==================================================================
 d1004                          | Beijing.Haidian                |
 d1003                          | Beijing.Haidian                |
 d1002                          | Beijing.Chaoyang               |
 d1001                          | Beijing.Chaoyang               |
Query OK, 4 row(s) in set (0.000881s)

taos> SELECT COUNT(tbname) FROM meters WHERE groupId > 2;
     count(tbname)     |
========================
                     2 |
Query OK, 1 row(s) in set (0.001091s)
```

- You can use \* to return all columns, or given column names. Four operations can be performed on numeric columns, and column names can be given to output columns.
- `WHERE` statement can use various logical decisions to filter numeric values, or wildcards to filter strings
- The output is sorted by default in ascending order by timestamps in the first column, but you can specify descending order (\_c0 refers to the first column timestamp). It is illegal to use ORDER BY to sort other fields.
- Parameter LIMIT controls the number of outputs, and OFFSET specifies which output starts from. LIMIT/OFFSET executes the result set after ORDER BY.
- "> >" output can be exported to a specified file

#### Supported Filtering Operations

| **Operation** | **Note**                      | **Applicable Data Types**           |
| ------------- | ----------------------------- | ----------------------------------- |
| >             | larger than                   | **timestamp** and all numeric types |
| <             | smaller than                  | **timestamp** and all numeric types |
| >=            | larger than or equal to       | **timestamp** and all numeric types |
| <=            | smaller than or equal to      | **timestamp** and all numeric types |
| =             | equal to                      | all types                           |
| <>            | not equal to                  | all types                           |
| between and   | within a certain range        | **timestamp** and all numeric types |
| %             | match with any char sequences | **binary** **nchar**                |
| _             | match with a single char      | **binary** **nchar**                |

1. To filter the range of multiple fields at the same time, you need to use keyword AND to connect different query conditions. The query filtering between different columns connected by OR are not supported at the moment.
2. For filtering a single field, if it is a time filtering condition, only one condition in a statement can be set; however, for other (ordinary) columns or tag columns, OR keyword can be used for query filtering of combined conditions. For example: ((value > 20 AND value < 30) OR (value < 12)).
3. Since version 2.0. 17, condition filtering supports BETWEEN AND syntax. For example, WHERE col2 BETWEEN 1.5 AND 3.25 means that the query condition is "1.5 ≤ col2 ≤ 3.25".

### SQL Example

- For example, table tb1 is created with the following statement
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
668 669 670 671
  
    ```mysql
    CREATE TABLE tb1 (ts TIMESTAMP, col1 INT, col2 FLOAT, col3 BINARY(50));
    ```
672 673 674

- Query all records of the last hour of tb1

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
675 676 677 678
    ```mysql
    SELECT * FROM tb1 WHERE ts >= NOW - 1h;
    ```

B
Bo Ding 已提交
679
- Look up table tb1 from 2018-06-01 08:00:00. 000 to 2018-06-02 08:00:00. 000, and col3 string is a record ending in 'nny ', and the result is in descending order of timestamp:
680

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
681 682 683
    ```mysql
    SELECT * FROM tb1 WHERE ts > '2018-06-01 08:00:00.000' AND ts <= '2018-06-02 08:00:00.000' AND col3 LIKE '%nny' ORDER BY ts DESC;
    ```
684 685 686

- Query the sum of col1 and col2, and name it complex. The time is greater than 2018-06-01 08:00:00. 000, and col2 is greater than 1.2. As a result, only 10 records are outputted, starting from item 5

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
687 688 689
    ```mysql
    SELECT (col1 + col2) AS 'complex' FROM tb1 WHERE ts > '2018-06-01 08:00:00.000' AND col2 > 1.2 LIMIT 10 OFFSET 5;
    ```
690

691
- Query the records of past 10 minutes, the value of col2 is greater than 3.14, and output the result to the file /home/testoutput.csv.
692

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
693
    ```mysql
694
    SELECT COUNT(*) FROM tb1 WHERE ts >= NOW - 10m AND col2 > 3.14 >> /home/testoutput.csv;
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
695
    ```
696 697 698 699 700 701 702 703 704

<a class="anchor" id="functions"></a>

## SQL Functions

TDengine supports aggregations over data, they are listed below:

- **COUNT**

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728
    ```mysql
    SELECT COUNT([*|field_name]) FROM tb_name [WHERE clause];
    ```
    Function: record the number of rows or non-null values in a column of statistics/STable.
    
    Returned result data type: long integer INT64.
    
    Applicable Fields: Applied to all fields.
    
    Applied to: **table, STable**.
    
    Note:
    1. You can use \* instead of specific fields, and use *() to return the total number of records.
    2. The query results for fields of the same table (excluding NULL values) are the same.
    3. If the statistic object is a specific column, return the number of records with non-NULL values in that column.
    
    Example:
    
    ```mysql
    taos> SELECT COUNT(*), COUNT(voltage) FROM meters;
        count(*)        |    count(voltage)     |
    ================================================
                        9 |                     9 |
    Query OK, 1 row(s) in set (0.004475s)
729
    
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
730 731 732 733 734
    taos> SELECT COUNT(*), COUNT(voltage) FROM d1001;
        count(*)        |    count(voltage)     |
    ================================================
                        3 |                     3 |
    Query OK, 1 row(s) in set (0.001075s)
735 736 737 738
    ```

- **AVG**

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
739 740
  ```mysql
  SELECT AVG(field_name) FROM tb_name [WHERE clause];
741
  ```
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
742
  Function: return the average value of a column in statistics/STable.
743
  
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764
  Return Data Type: double.
  
  Applicable Fields: all types except timestamp, binary, nchar, bool.
  
  Applied to: **table,STable**.
  
  Example:
  
  ```mysql
  taos> SELECT AVG(current), AVG(voltage), AVG(phase) FROM meters;
      avg(current)        |       avg(voltage)        |        avg(phase)         |
  ====================================================================================
              11.466666751 |             220.444444444 |               0.293333333 |
  Query OK, 1 row(s) in set (0.004135s)
  
  taos> SELECT AVG(current), AVG(voltage), AVG(phase) FROM d1001;
      avg(current)        |       avg(voltage)        |        avg(phase)         |
  ====================================================================================
              11.733333588 |             219.333333333 |               0.316666673 |
  Query OK, 1 row(s) in set (0.000943s)
  ```
765 766

- **TWA**
767
  
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
768 769
  ```mysql
  SELECT TWA(field_name) FROM tb_name WHERE clause;
770
  ```
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
771 772 773 774 775 776 777 778
  
  Function: Time weighted average function. The time-weighted average of a column in a statistical table over a period of time.
  
  Return Data Type: double.
  
  Applicable Fields: all types except timestamp, binary, nchar, bool.
  
  Applied to: **table**.
779 780 781

- **SUM**

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
782 783
  ```mysql
  SELECT SUM(field_name) FROM tb_name [WHERE clause];
784
  ```
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
785 786 787
  
  Function: return the sum of a statistics/STable.
  
B
Bo Ding 已提交
788
  Return Data Type: INT64 and Double.
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
789 790 791 792 793 794
  
  Applicable Fields: All types except timestamp, binary, nchar, bool.
  
  Applied to:  **table,STable**.
  
  Example:
795

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
796 797 798 799 800 801
  ```mysql
  taos> SELECT SUM(current), SUM(voltage), SUM(phase) FROM meters;
      sum(current)        |     sum(voltage)      |        sum(phase)         |
  ================================================================================
              103.200000763 |                  1984 |               2.640000001 |
  Query OK, 1 row(s) in set (0.001702s)
802
  
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
803 804 805 806 807
  taos> SELECT SUM(current), SUM(voltage), SUM(phase) FROM d1001;
      sum(current)        |     sum(voltage)      |        sum(phase)         |
  ================================================================================
              35.200000763 |                   658 |               0.950000018 |
  Query OK, 1 row(s) in set (0.000980s)
808
  ```
809 810

- **STDDEV**
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831
  
  ```mysql
  SELECT STDDEV(field_name) FROM tb_name [WHERE clause];
  ```
  
  Function: Mean square deviation of a column in statistics table.
  
  Return Data Type: Double.
  
  Applicable Fields: All types except timestamp, binary, nchar, bool.
  
  Applied to: **table**. (also support **STable** since version 2.0.15.1)
  
  Example:
  
  ```mysql
  taos> SELECT STDDEV(current) FROM d1001;
      stddev(current)      |
  ============================
              1.020892909 |
  Query OK, 1 row(s) in set (0.000915s)
832 833 834
  ```

- **LEASTSQUARES**
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855
    ```mysql
    SELECT LEASTSQUARES(field_name, start_val, step_val) FROM tb_name [WHERE clause];
    ```
    Function: Value of a column in statistical table is a fitting straight equation of primary key (timestamp). Start_val is the initial value of independent variable, and step_val is the step size value of independent variable.
    
    Return Data Type: String expression (slope, intercept).
    
    Applicable Fields: All types except timestamp, binary, nchar, bool.
    
    Note: Independent variable is the timestamp, and dependent variable is the value of the column.
    
    Applied to: **table**.
    
    Example:
    ```mysql
    taos> SELECT LEASTSQUARES(current, 1, 1) FROM d1001;
                leastsquares(current, 1, 1)             |
    =====================================================
    {slop:1.000000, intercept:9.733334}                 |
    Query OK, 1 row(s) in set (0.000921s)
    ```
856

857 858 859 860 861 862 863 864 865 866 867
- **MODE**
    ```mysql
    SELECT MODE(field_name) FROM tb_name [WHERE clause];
    ```
    Function: Returns the value with the highest frequency. If there are multiple highest values with the same frequency, the output is NULL.

    Return Data Type: Same as applicable fields.

    Applicable Fields: All types except timestamp.

    Supported version: Version after 2.6.0 .
wmmhello's avatar
wmmhello 已提交
868 869 870
    
    Note: Since the amount of returned data is unknown, considering the memory factor, in order to return the result normally, it is recommended that the amount of non repeated data is 100000, otherwise an error will be reported.
    
871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892
    Example:
    ```mysql
    taos> select voltage from d002;
        voltage        |
    ========================
           1           |
           1           |
           2           |
           19          |
    Query OK, 4 row(s) in set (0.003545s)
  
    taos> select mode(voltage) from d002;
      mode(voltage)    |
    ========================
           1           |
   Query OK, 1 row(s) in set (0.019393s)
    ```  

- **HYPERLOGLOG**
    ```mysql
    SELECT HYPERLOGLOG(field_name) FROM { tb_name | stb_name } [WHERE clause];
    ```
wmmhello's avatar
wmmhello 已提交
893 894 895
    Function: 
    - The hyperloglog algorithm is used to return the cardinality of a column. In the case of large amount of data, the algorithm can significantly reduce the occupation of memory, but the cardinality is an estimated value, and the standard error(the standard error is the standard deviation of the average of multiple experiments, not the error with the real result) is 0.81%.
    - When the amount of data is small, the algorithm is not very accurate. You can use the method like this: select count(data) from (select unique(col) as data from table).
896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923

    Return Data Type:Integer.

    Applicable Fields: All types.

    Supported version: Version after 2.6.0 .

    Example:
    ```mysql
    taos> select dbig from shll;
         dbig          |
    ========================
           1           |
           1           |
           1           |
           NULL        |
           2           |
           19          |
           NULL        |
           9           |
    Query OK, 8 row(s) in set (0.003755s)
  
    taos> select hyperloglog(dbig) from shll;
      hyperloglog(dbig)|
    ========================
           4           |
    Query OK, 1 row(s) in set (0.008388s)
  
924 925 926
### Selector Functions

- **MIN**
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
927 928 929 930 931 932 933 934 935 936
    ```mysql
    SELECT MIN(field_name) FROM {tb_name | stb_name} [WHERE clause];
    ```
    Function: return the minimum value of a specific column in statistics/STable.
    
    Return Data Type: Same as applicable fields.
    
    Applicable Fields: All types except timestamp, binary, nchar, bool.
    
    Example:
937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953

    ```mysql
    taos> SELECT MIN(current), MIN(voltage) FROM meters;
        min(current)     | min(voltage) |
    ======================================
                10.20000 |          218 |
    Query OK, 1 row(s) in set (0.001765s)
    
    taos> SELECT MIN(current), MIN(voltage) FROM d1001;
        min(current)     | min(voltage) |
    ======================================
                10.30000 |          218 |
    Query OK, 1 row(s) in set (0.000950s)
    ```

- **MAX**

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
954 955 956 957 958 959 960 961 962 963 964
   ```mysql
   SELECT MAX(field_name) FROM { tb_name | stb_name } [WHERE clause];
   ```
   
   Function: return the maximum value of a specific column in statistics/STable.
   
   Return Data Type: Same as applicable fields.
   
   Applicable Fields: All types except timestamp, binary, nchar, bool.
   
   Example:
965

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
966 967 968 969 970 971
   ```mysql
   taos> SELECT MAX(current), MAX(voltage) FROM meters;
       max(current)     | max(voltage) |
   ======================================
               13.40000 |          223 |
   Query OK, 1 row(s) in set (0.001123s)
972
    
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
973 974 975 976 977 978
   taos> SELECT MAX(current), MAX(voltage) FROM d1001;
       max(current)     | max(voltage) |
   ======================================
               12.60000 |          221 |
   Query OK, 1 row(s) in set (0.000987s)
   ```
979 980 981

- **FIRST**

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
982 983 984 985 986 987 988 989 990 991 992 993
   ```mysql
   SELECT FIRST(field_name) FROM { tb_name | stb_name } [WHERE clause];
   ```
   
   Function: The first non-NULL value written into a column in statistics/STable.
   
   Return Data Type: Same as applicable fields.
   
   Applicable Fields: All types.
   
   Note:
   1. To return the first (minimum timestamp) non-NULL value of each column, use FIRST (\*);
994 995
   2. if all columns in the result set are NULL values, the return result of the column is also NULL;
   3. If all columns in the result set are NULL values, no result is returned.
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
996 997
   
   Example:
998 999

   ```mysql
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1000 1001 1002 1003 1004 1005 1006 1007 1008
   taos> SELECT FIRST(*) FROM meters;
          first(ts)        |    first(current)    | first(voltage) |     first(phase)     |
   =========================================================================================
   2018-10-03 14:38:04.000 |             10.20000 |            220 |              0.23000 |
   Query OK, 1 row(s) in set (0.004767s)

   taos> SELECT FIRST(current) FROM d1002;
         first(current)    |
   =======================
1009
                10.20000 |
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1010
   Query OK, 1 row(s) in set (0.001023s)
1011 1012 1013 1014
   ```

- **LAST**

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026
   ```mysql
   SELECT LAST(field_name) FROM { tb_name | stb_name } [WHERE clause];
   ```
   
   Function: The last non-NULL value written by the value of a column in statistics/STable.
   
   Return Data Type: Same as applicable fields.
   
   Applicable Fields: All types.
   
   Note:
   1. To return the last (maximum timestamp) non-NULL value of each column, use LAST (\*);
1027
   2. If a column in the result set has a NULL value, the returned result of the column is also NULL; if all columns in the result set have NULL values, no result is returned.
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1028 1029
   
   Example:
1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045

   ```mysql
    taos> SELECT LAST(*) FROM meters;
            last(ts)         |    last(current)     | last(voltage) |     last(phase)      |
    ========================================================================================
    2018-10-03 14:38:16.800 |             12.30000 |           221 |              0.31000 |
    Query OK, 1 row(s) in set (0.001452s)

    taos> SELECT LAST(current) FROM d1002;
        last(current)     |
    =======================
                10.30000 |
    Query OK, 1 row(s) in set (0.000843s)
   ```

- **TOP**
1046
  
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060
    ```mysql
    SELECT TOP(field_name, K) FROM { tb_name | stb_name } [WHERE clause];
    ```
    Function: The top k non-NULL values of a column in statistics/STable. If there are more than k column values tied for the largest, the one with smaller timestamp is returned.
    
    Return Data Type: Same as applicable fields.
    
    Applicable Fields: All types except timestamp, binary, nchar, bool.
    
    Note:
    1. The range of *k* value is 1≤*k*≤100;
    2. System also returns the timestamp column associated with the record.
    
    Example:
1061

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1062 1063 1064 1065 1066 1067 1068 1069
    ```mysql
    taos> SELECT TOP(current, 3) FROM meters;
            ts            |   top(current, 3)    |
    =================================================
    2018-10-03 14:38:15.000 |             12.60000 |
    2018-10-03 14:38:16.600 |             13.40000 |
    2018-10-03 14:38:16.800 |             12.30000 |
    Query OK, 3 row(s) in set (0.001548s)
1070
      
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1071 1072 1073 1074 1075 1076 1077
    taos> SELECT TOP(current, 2) FROM d1001;
            ts            |   top(current, 2)    |
    =================================================
    2018-10-03 14:38:15.000 |             12.60000 |
    2018-10-03 14:38:16.800 |             12.30000 |
    Query OK, 2 row(s) in set (0.000810s)
    ```
1078 1079 1080

- **BOTTOM**

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1081 1082 1083 1084 1085 1086 1087 1088
    ```mysql
    SELECT BOTTOM(field_name, K) FROM { tb_name | stb_name } [WHERE clause];
    ```
    Function: The last k non-NULL values of a column in statistics/STable. If there are more than k column values tied for the smallest, the one with smaller timestamp is returned.
    
    Return Data Type: Same as applicable fields.
    
    Applicable Fields: All types except timestamp, binary, nchar, bool.
1089

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1090 1091 1092
    Note:
    1. The range of *k* value is 1≤*k*≤100;
    2. System also returns the timestamp column associated with the record.
1093

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1094
    Example:
1095

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1096 1097 1098 1099 1100 1101 1102
    ```mysql
    taos> SELECT BOTTOM(voltage, 2) FROM meters;
            ts            | bottom(voltage, 2) |
    ===============================================
    2018-10-03 14:38:15.000 |                218 |
    2018-10-03 14:38:16.650 |                218 |
    Query OK, 2 row(s) in set (0.001332s)
1103
    
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1104 1105 1106 1107 1108 1109
    taos> SELECT BOTTOM(current, 2) FROM d1001;
            ts            |  bottom(current, 2)  |
    =================================================
    2018-10-03 14:38:05.000 |             10.30000 |
    2018-10-03 14:38:16.800 |             12.30000 |
    Query OK, 2 row(s) in set (0.000793s)
1110 1111 1112
    ```

- **PERCENTILE**
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1113 1114 1115 1116 1117 1118 1119 1120 1121 1122 1123 1124
    ```mysql
    SELECT PERCENTILE(field_name, P) FROM { tb_name } [WHERE clause];
    ```
    Function: Percentile of the value of a column in statistical table.
    
    Return Data Type: Double.
    
    Applicable Fields: All types except timestamp, binary, nchar, bool.
    
    Note: The range of P value is 0 ≤ P ≤ 100. P equals to MIN when, and equals MAX when it’s 100.
    
    Example:
1125

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1126
    ```mysql
1127 1128 1129 1130 1131
    taos> SELECT PERCENTILE(current, 20) FROM d1001;
    percentile(current, 20)  |
    ============================
                11.100000191 |
    Query OK, 1 row(s) in set (0.000787s)
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1132
    ```
1133 1134

- **APERCENTILE**
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1135 1136 1137 1138 1139 1140 1141 1142 1143 1144
    ```mysql
    SELECT APERCENTILE(field_name, P) FROM { tb_name | stb_name } [WHERE clause];
    ```
    Function: The value percentile of a column in statistical table is similar to the PERCENTILE function, but returns approximate results.
    
    Return Data Type: Double.
    
    Applicable Fields: All types except timestamp, binary, nchar, bool.
    
    Note: The range of *P* value is 0 ≤ *P* ≤ 100. *P* equals to MIN when, and equals MAX when it’s 100. APERCENTILE function is recommended, which performs far better than PERCENTILE function.
1145 1146

- **LAST_ROW**
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158
    ```mysql
    SELECT LAST_ROW(field_name) FROM { tb_name | stb_name };
    ```
    Function: Return the last record of a table (STtable).
    
    Return Data Type: Double.
    
    Applicable Fields: All types.
    
    Note: Unlike last function, last_row does not support time range restriction and forces the last record to be returned.
    
    Example:
1159

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1160 1161 1162 1163 1164 1165
    ```mysql
    taos> SELECT LAST_ROW(current) FROM meters;
    last_row(current)   |
    =======================
                12.30000 |
    Query OK, 1 row(s) in set (0.001238s)
1166
    
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1167 1168 1169 1170
    taos> SELECT LAST_ROW(current) FROM d1002;
    last_row(current)   |
    =======================
                10.30000 |
1171 1172 1173
      Query OK, 1 row(s) in set (0.001042s)
    ```

1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223
- **TAIL**
    ```mysql
    SELECT TAIL(field_name, k, offset_val) FROM {tb_name | stb_name} [WHERE clause];
    ```
    Function: Skip the last num of offset_value, return the k consecutive records without ignoring NULL value. offset_val can be empty, then the last K records are returned.The function is equivalent to:order by ts desc LIMIT k OFFSET offset_val.

    Range:k: [1,100]  offset_val: [0,100]。

    Return Data Type: Same as applicable fields.

    Applicable Fields: All types except timestamp.

    Applied to: **table stable**.

    Supported version: Version after 2.6.0 .

    Example:
    ```mysql
    taos> select ts,dbig from tail2;
           ts            |         dbig          |
    ==================================================
    2021-10-15 00:31:33.000 |                     1 |
    2021-10-17 00:31:31.000 |                  NULL |
    2021-12-24 00:31:34.000 |                     2 |
    2022-01-01 08:00:05.000 |                    19 |
    2022-01-01 08:00:06.000 |                  NULL |
    2022-01-01 08:00:07.000 |                     9 |
    Query OK, 6 row(s) in set (0.001952s)
  
    taos> select tail(dbig,2,2) from tail2;
    ts                      |    tail(dbig,2,2)     |
    ==================================================
    2021-12-24 00:31:34.000 |                     2 |
    2022-01-01 08:00:05.000 |                    19 |
    Query OK, 2 row(s) in set (0.002307s)

- **UNIQUE**
    ```mysql
    SELECT UNIQUE(field_name) FROM {tb_name | stb_name} [WHERE clause];
    ```
    Function: Returns the first occurrence of a value in this column.

    Return Data Type: Same as applicable fields.

    Applicable Fields: All types except timestamp.

    Applied to: **table stable**.

    Supported version: Version after 2.6.0 .

wmmhello's avatar
wmmhello 已提交
1224 1225 1226 1227
    Note: 
    - This function can be applied to ordinary tables and super tables. Cannot be used with window operations,such as interval/state_window/session_window.
    - Since the amount of returned data is unknown, considering the memory factor, in order to return the result normally, it is recommended that the amount of non repeated data is 100000, otherwise an error will be reported.
    
1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252
    Example:
    ```mysql
    taos> select ts,voltage from unique1;
           ts            |        voltage        |
    ==================================================
    2021-10-17 00:31:31.000 |                     1 |
    2022-01-24 00:31:31.000 |                     1 |
    2021-10-17 00:31:31.000 |                     1 |
    2021-12-24 00:31:31.000 |                     2 |
    2022-01-01 08:00:01.000 |                    19 |
    2021-10-17 00:31:31.000 |                  NULL |
    2022-01-01 08:00:02.000 |                  NULL |
    2022-01-01 08:00:03.000 |                     9 |
    Query OK, 8 row(s) in set (0.003018s)
  
    taos> select unique(voltage) from unique1;
    ts                      |    unique(voltage)    |
    ==================================================
    2021-10-17 00:31:31.000 |                     1 |
    2021-10-17 00:31:31.000 |                  NULL |
    2021-12-24 00:31:31.000 |                     2 |
    2022-01-01 08:00:01.000 |                    19 |
    2022-01-01 08:00:03.000 |                     9 |
    Query OK, 5 row(s) in set (0.108458s)

1253 1254 1255
### Computing Functions

- **DIFF**
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267
    ```mysql
    SELECT DIFF(field_name) FROM tb_name [WHERE clause];
    ```
    Function: Return the value difference between a column and the previous column.
    
    Return Data Type: Same as applicable fields.
    
    Applicable Fields: All types except timestamp, binary, nchar, bool.
    
    Note: The number of output result lines is the total number of lines in the range minus one, and there is no result output in the first line.
    
    Example:
1268

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1269 1270 1271 1272 1273 1274 1275 1276
    ```mysql
    taos> SELECT DIFF(current) FROM d1001;
            ts            |    diff(current)     |
    =================================================
    2018-10-03 14:38:15.000 |              2.30000 |
    2018-10-03 14:38:16.800 |             -0.30000 |
    Query OK, 2 row(s) in set (0.001162s)
    ```
1277 1278 1279

- **SPREAD**

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1280 1281 1282 1283 1284
    ```mysql
    SELECT SPREAD(field_name) FROM { tb_name | stb_name } [WHERE clause];
    ```
    Function: Return the difference between the max value and the min value of a column in statistics /STable.
    
1285
    Return Data Type: Double.
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1286 1287 1288 1289 1290 1291
    
    Applicable Fields: All types except binary, nchar, bool.
    
    Note: Applicable for TIMESTAMP field, which indicates the time range of a record.
    
    Example:
1292

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1293 1294 1295 1296 1297 1298
    ```mysql
    taos> SELECT SPREAD(voltage) FROM meters;
        spread(voltage)      |
    ============================
                5.000000000 |
    Query OK, 1 row(s) in set (0.001792s)
1299
    
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1300 1301 1302 1303 1304 1305
    taos> SELECT SPREAD(voltage) FROM d1001;
        spread(voltage)      |
    ============================
                3.000000000 |
    Query OK, 1 row(s) in set (0.000836s)
    ```
1306

1307 1308 1309 1310 1311 1312 1313 1314 1315 1316 1317 1318 1319 1320 1321 1322 1323 1324 1325
- **ASIN**
    ```mysql
    SELECT ASIN(field_name) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the arc-sine of the input value.

    Output Data Type: DOUBLE.

    Input: applies to value of all types except timestamp, binary, nchar, and bool. Can not apply to tag column of super table.

    Embedded Query Support: Both Outer Query and Inner Query 

    Notes:

      If input value is NULL, the output value is NULL.

      It is a scalar function and can not be used together with aggregate function

      Applies to columns of normal table, child table and super table
1326 1327 1328
      
      Supported after version 2.6.0.x

1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349

- **ACOS**
    ```mysql
    SELECT ACOS(field_name) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the arc-cosine of the input value.

    Output Data Type: DOUBLE.

    Input: applies to value of all types except timestamp, binary, nchar, and bool. Can not apply to tag column of super table.

    Embedded Query Support: Both Outer Query and Inner Query 

    Notes:

      If input value is NULL, the output value is NULL.

      It is a scalar function and can not be used together with aggregate function

      Applies to columns of normal table, child table and super table

1350 1351
      Supported after version 2.6.0.x

1352 1353 1354 1355 1356 1357 1358 1359 1360 1361 1362 1363 1364 1365 1366 1367 1368 1369 1370 1371 1372

- **ATAN**
    ```mysql
    SELECT ATAN(field_name) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the arc-tangent of the input value.

    Output Data Type: DOUBLE.

    Input: applies to value of all types except timestamp, binary, nchar, and bool. Can not apply to tag column of super table.

    Embedded Query Support: Both Outer Query and Inner Query 

    Notes:

      If input value is NULL, the output value is NULL.

      It is a scalar function and can not be used together with aggregate function

      Applies to columns of normal table, child table and super table

1373 1374
      Supported after version 2.6.0.x

1375 1376 1377 1378 1379 1380 1381 1382 1383 1384 1385 1386 1387 1388 1389 1390 1391 1392 1393 1394 1395

- **SIN**
    ```mysql
    SELECT SIN(field_name) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the sine of the input value.

    Output Data Type: DOUBLE.

    Input: applies to value of all types except timestamp, binary, nchar, and bool. Can not apply to tag column of super table.

    Embedded Query Support: Both Outer Query and Inner Query 

    Notes:

      If input value is NULL, the output value is NULL.

      It is a scalar function and can not be used together with aggregate function

      Applies to columns of normal table, child table and super table

1396 1397
      Supported after version 2.6.0.x

1398 1399 1400 1401 1402 1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418

- **COS**
    ```mysql
    SELECT COS(field_name) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the cosine of the input value.

    Output Data Type: DOUBLE.

    Input: applies to value of all types except timestamp, binary, nchar, and bool. Can not apply to tag column of super table.

    Embedded Query Support: Both Outer Query and Inner Query 

    Notes:

      If input value is NULL, the output value is NULL.

      It is a scalar function and can not be used together with aggregate function

      Applies to columns of normal table, child table and super table

1419 1420
      Supported after version 2.6.0.x

1421 1422 1423 1424 1425 1426 1427 1428 1429 1430 1431 1432 1433 1434 1435 1436 1437 1438 1439 1440
- **TAN**
    ```mysql
    SELECT TAN(field_name) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the tangent of the input value.

    Output Data Type: DOUBLE.

    Input: applies to value of all types except timestamp, binary, nchar, and bool. Can not apply to tag column of super table.

    Embedded Query Support: Both Outer Query and Inner Query 

    Notes:

      If input value is NULL, the output value is NULL.

      It is a scalar function and can not be used together with aggregate function

      Applies to columns of normal table, child table and super table

1441 1442
      Supported after version 2.6.0.x

1443 1444 1445 1446 1447 1448 1449 1450 1451 1452 1453 1454 1455 1456 1457 1458 1459 1460 1461 1462 1463 1464 1465


- **POW**
    ```mysql
    SELECT POW(field_name, power) FROM { tb_name | stb_name } [WHERE clause]
    ```

    Function: Returns the input value raised to the specified power of the second argument

    Output Data Type: DOUBLE.

    Input: applies to value of all types except timestamp, binary, nchar, and bool. Can not apply to tag column of super table.

    Embedded Query Support: Both Outer Query and Inner Query 

    Notes:

      If input value is NULL, the output value is NULL.

      It is a scalar function and can not be used together with aggregate function

      Applies to columns of normal table, child table and super table

1466 1467
      Supported after version 2.6.0.x

1468 1469 1470 1471 1472 1473 1474 1475 1476 1477 1478 1479 1480 1481 1482 1483 1484 1485 1486 1487
- **LOG**
    ```mysql
    SELECT LOG(field_name, base) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the logarithm of the input value with base

    Output Data Type: DOUBLE.

    Input: applies to value of all types except timestamp, binary, nchar, and bool. Can not apply to tag column of super table.

    Embedded Query Support: Both Outer Query and Inner Query 

    Notes:

      If input value is NULL, the output value is NULL.

      It is a scalar function and can not be used together with aggregate function

      Applies to columns of normal table, child table and super table

1488 1489
      Supported after version 2.6.0.x

1490 1491 1492 1493 1494 1495 1496 1497 1498 1499 1500 1501 1502 1503 1504 1505 1506 1507 1508 1509
- **ABS**
    ```mysql
    SELECT ABS(field_name) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the absolute value of the input value

    Output Data Type: If the input data is an integer numeric value, the output data type is ubigint. If the input data is a float or double value, the output data type is double

    Input: applies to value of all types except timestamp, binary, nchar, and bool. Can not apply to tag column of super table.

    Embedded Query Support: Both Outer Query and Inner Query 

    Notes:

      If input value is NULL, the output value is NULL.

      It is a scalar function and can not be used together with aggregate function

      Applies to columns of normal table, child table and super table

1510 1511
      Supported after version 2.6.0.x

1512 1513 1514 1515 1516 1517 1518 1519 1520 1521 1522 1523 1524 1525 1526 1527 1528 1529 1530 1531 1532

- **SQRT**
    ```mysql
    SELECT SQRT(field_name) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the square root value of the input value

    Output Data Type: DOUBLE.

    Input: applies to value of all types except timestamp, binary, nchar, and bool. Can not apply to tag column of super table.

    Embedded Query Support: Both Outer Query and Inner Query 

    Notes:

      If input value is NULL, the output value is NULL.

      It is a scalar function and can not be used together with aggregate function

      Applies to columns of normal table, child table and super table

1533 1534
      Supported after version 2.6.0.x

1535 1536 1537 1538 1539 1540
- **CAST**
    ```mysql
    SELECT CAST(expression AS type_name) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Converts a value into as a specific data type of type_name.

1541
    Output Data Type: type_name specified. Supported types include BIGINT, BINARY(N), TIMESTAMP and NCHAR(N) and BIGINT UNSIGNED
1542 1543 1544 1545 1546 1547 1548 1549 1550

    Input: Normal column, constant, scalar function and the arithmetic computation(+,-,*,/,%) among them. Input data type includes BOOL, TINYINT, SMALLINT, INT, BIGINT, FLOAT, DOUBLE, BINARY(M), TIMESTAMP, NCHAR(M), TINYINT UNSIGNED, SMALLINT UNSIGNED, INT UNSIGNED, and BIGINT UNSIGNED

    Notes:

      Reports error for unsupported cast

      It is a scalar function and its output is NULL for input NULL

1551 1552
      Supported after version 2.6.0.x

1553 1554 1555 1556 1557 1558 1559 1560 1561 1562 1563 1564 1565 1566 1567 1568 1569

- **CONCAT**
    ```mysql
    SELECT CONCAT(str1|column1, str2|column2, ...) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the string from concatenating the arguments

    Output Data Type: With binary inputs, the output data type is binary. With nchar inputs, the output data type is nchar.

    Input: all inputs shall be of data type binary or nchar. Can not apply to tag columns.

    Notes:
    
      If one of the string inputs is NULL, the resulting output is NULL.
      The function takes 2 to 8 string values as input. all inputs must be of the same data type.
      This function applies to normal table, child table and super table
      This function applies to bother out query and inner query
1570
      Supported after version 2.6.0.x
1571 1572 1573 1574 1575 1576 1577 1578 1579 1580 1581 1582 1583 1584 1585 1586 1587
      
- **CONCAT_WS**
    ```
    SELECT CONCAT_WS(separator, str1|column1, str2|column2, ...) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the string from concatenating the arguments with separator.

    Output Data Type: With binary inputs, the output data type is binary. With nchar inputs, the output data type is nchar.

    Input: all inputs shall be of data type binary or nchar. Can not apply to tag columns.

    Notes:
    
      Returns NULL when the separator is NULL. If the separator is not NULL and all the other string values are NULL, the result is an empty string. 
      The function takes 3 to 9 string values as input. all inputs must be of the same data type.
      This function applies to normal table, child table and super table
      This function applies to bother out query and inner query
1588
      Supported after version 2.6.0.x
1589 1590 1591 1592 1593 1594 1595 1596 1597 1598 1599 1600 1601 1602 1603 1604 1605
      

- **LENGTH**
    ```
    SELECT LENGTH(str|column) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the length of the string measure in bytes

    Output Data Type: INT。

    Input: BINARY or NCHAR values. Can not apply to tag columns

    Notes:
    
      Returns NULL when input is NULL. 
      This function applies to normal table, child table and super table
      This function applies to bother out query and inner query
1606
      Supported after version 2.6.0.x
1607 1608 1609 1610 1611 1612 1613 1614 1615 1616 1617 1618 1619 1620 1621 1622

- **CHAR_LENGTH**
    ```
    SELECT CHAR_LENGTH(str|column) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the length of the string measure in characters

    Output Data Type: INT。

    Input: BINARY or NCHAR values. Can not apply to tag columns

    Notes:
    
      Returns NULL when input is NULL. 
      This function applies to normal table, child table and super table
      This function applies to bother out query and inner query
1623
      Supported after version 2.6.0.x
1624 1625 1626 1627 1628 1629 1630 1631 1632 1633 1634 1635 1636 1637 1638 1639

- **LOWER**
    ```
    SELECT LOWER(str|column) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the lower case of input value

    Output Data Type: BINARY or NCHAR. Same data type as Input.

    Input: BINARY or NCHAR values. Can not apply to tag columns

    Notes:
    
      Returns NULL when input is NULL. 
      This function applies to normal table, child table and super table
      This function applies to bother out query and inner query
1640
      Supported after version 2.6.0.x
1641 1642 1643 1644 1645 1646 1647 1648 1649 1650 1651 1652 1653 1654 1655 1656

- **UPPER**
    ```
    SELECT UPPER(str|column) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: Returns the upper case of input value

    Output Data Type: BINARY or NCHAR. Same data type as Input.

    Input: BINARY or NCHAR values. Can not apply to tag columns

    Notes:
    
      Returns NULL when input is NULL. 
      This function applies to normal table, child table and super table
      This function applies to bother out query and inner query
1657
      Supported after version 2.6.0.x
1658 1659 1660 1661 1662 1663 1664 1665 1666 1667 1668 1669 1670 1671 1672 1673

- **LTRIM**
    ```
    SELECT LTRIM(str|column) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: removes leading spaces from a string

    Output Data Type: BINARY or NCHAR. Same data type as Input.

    Input: BINARY or NCHAR values. Can not apply to tag columns

    Notes:
    
      Returns NULL when input is NULL. 
      This function applies to normal table, child table and super table
      This function applies to bother out query and inner query
1674
      Supported after version 2.6.0.x
1675 1676 1677 1678 1679 1680 1681 1682 1683 1684 1685 1686 1687 1688 1689 1690

- **RTRIM**
    ```
    SELECT RTRIM(str|column) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: removes trailing spaces from a string

    Output Data Type: BINARY or NCHAR. Same data type as Input.

    Input: BINARY or NCHAR values. Can not apply to tag columns

    Notes:
    
      Returns NULL when input is NULL. 
      This function applies to normal table, child table and super table
      This function applies to bother out query and inner query
1691
      Supported after version 2.6.0.x
1692 1693 1694 1695 1696 1697 1698 1699 1700 1701 1702 1703 1704 1705 1706

- **SUBSTR**
    ```
    SELECT SUBSTR(str,pos[,len]) FROM { tb_name | stb_name } [WHERE clause]
    ```
    Function: extracts substring from a string str, starting from pos and extracting len characters.

    Output Data Type: BINARY or NCHAR. Same data type as Input.

    Input: BINARY or NCHAR values. Can not apply to tag columns

    Notes:
    
      Returns NULL when input is NULL. 
      Input pos can be negative or positive. If it is a positive number, this function extracts from the beginning of the string. If it is a negative number, this function extracts from the end of the string
1707
      If input len is omitted, the output is whole substring starting from pos.
1708
      This function applies to normal table, child table and super table
1709 1710
      This function applies to bother out query and inner query
      Supported after version 2.6.0.x    
1711 1712


涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1713
- **Four Operations**
1714

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
1715 1716 1717 1718 1719 1720 1721 1722 1723 1724 1725 1726 1727
    ```mysql
    SELECT field_name [+|-|*|/|%][Value|field_name] FROM { tb_name | stb_name }  [WHERE clause];
    ```
    Function: Calculation results of addition, subtraction, multiplication, division and remainder of values in a column or among multiple columns in statistics/STable.
    
    Returned Data Type: Double.
    
    Applicable Fields: All types except timestamp, binary, nchar, bool.
    
    Note: 
    
    1. Calculation between two or more columns is supported, and the calculation priorities can be controlled by parentheses();
    2. The NULL field does not participate in the calculation. If a row involved in calculation contains NULL, the calculation result of the row is NULL.
1728

1729 1730 1731 1732 1733 1734 1735 1736 1737 1738 1739 1740 1741 1742 1743 1744 1745 1746 1747 1748 1749 1750 1751 1752 1753 1754 1755 1756 1757 1758 1759 1760 1761 1762 1763 1764 1765 1766 1767 1768 1769 1770 1771 1772 1773 1774 1775 1776 1777 1778 1779 1780 1781 1782 1783 1784 1785 1786 1787 1788 1789 1790 1791 1792 1793 1794 1795 1796 1797 1798 1799 1800 1801 1802 1803 1804 1805 1806 1807 1808 1809 1810 1811 1812 1813 1814 1815 1816 1817 1818
- **STATECOUNT**
    ```mysql
    SELECT STATECOUNT(field_name, oper, val) FROM { tb_name | stb_name } [WHERE clause];
    ```
    Function: Returns the number of consecutive records that meet a certain condition, and the result is appended to each row as a new column. The condition is calculated according to the parameters. If the condition is true, it will be increased by 1. If the condition is false, it will be reset to -1. If the data is NULL, the data will be skipped.

    Range:
    - oper : LT(<),GT(>),LE(<=),GE(>=),NE(!=),EQ(=),case insensitive.
    - val  : Number.

    Returned Data Type: Integer。

    Applicable Fields: All types except timestamp, binary, nchar, bool.

    Supported version: Version after 2.6.0 .

    Note:
    - This function can be applied to ordinary tables. When a separate timeline is divided by group by, it is used for super tables (i.e. group by TBNAME).
    - Cannot be used with window operations,such as interval/state_window/session_window.

    Example:
    ```mysql
    taos> select ts,dbig from statef2;
              ts               |         dbig          |
    ========================================================
    2021-10-15 00:31:33.000000000 |                     1 |
    2021-10-17 00:31:31.000000000 |                  NULL |
    2021-12-24 00:31:34.000000000 |                     2 |
    2022-01-01 08:00:05.000000000 |                    19 |
    2022-01-01 08:00:06.000000000 |                  NULL |
    2022-01-01 08:00:07.000000000 |                     9 |
    Query OK, 6 row(s) in set (0.002977s)
  
    taos> select stateCount(dbig,GT,2) from statef2;
    ts               |         dbig          | statecount(dbig,gt,2) |
    ================================================================================
    2021-10-15 00:31:33.000000000 |                     1 |                    -1 |
    2021-10-17 00:31:31.000000000 |                  NULL |                  NULL |
    2021-12-24 00:31:34.000000000 |                     2 |                    -1 |
    2022-01-01 08:00:05.000000000 |                    19 |                     1 |
    2022-01-01 08:00:06.000000000 |                  NULL |                  NULL |
    2022-01-01 08:00:07.000000000 |                     9 |                     2 |
    Query OK, 6 row(s) in set (0.002791s)
   ```

- **STATEDURATION**
    ```mysql
    SELECT stateDuration(field_name, oper, val, unit) FROM { tb_name | stb_name } [WHERE clause];
    ```
    Function: Returns the length of time of continuous records that meet a certain condition, and the result is appended to each row as a new column. The condition is calculated according to the parameters. If the condition is true, the length of time between two records will be added (the length of time of the first record that meets the condition is recorded as 0). If the condition is false, it will be reset to -1. If the data is NULL, the data will be skipped.

    Range:
    - oper : LT(<),GT(>),LE(<=),GE(>=),NE(!=),EQ(=),case insensitive.
    - val  : Number.
    - unit : Unit of time length, range [1s, 1M, 1H], less than one unit is rounded off. The default is 1s.

    Returned Data Type: Integer。

    Applicable Fields: All types except timestamp, binary, nchar, bool.

    Supported version: Version after 2.6.0 .
    
    Note:
    - This function can be applied to ordinary tables. When a separate timeline is divided by group by, it is used for super tables (i.e. group by TBNAME).
    - Cannot be used with window operations,such as interval/state_window/session_window.

    Example:
    ```mysql
    taos> select ts,dbig from statef2;
              ts               |         dbig          |
    ========================================================
    2021-10-15 00:31:33.000000000 |                     1 |
    2021-10-17 00:31:31.000000000 |                  NULL |
    2021-12-24 00:31:34.000000000 |                     2 |
    2022-01-01 08:00:05.000000000 |                    19 |
    2022-01-01 08:00:06.000000000 |                  NULL |
    2022-01-01 08:00:07.000000000 |                     9 |
    Query OK, 6 row(s) in set (0.002407s)
  
    taos> select stateDuration(dbig,GT,2) from statef2;
    ts               |         dbig          | stateduration(dbig,gt,2) |
    ===================================================================================
    2021-10-15 00:31:33.000000000 |                     1 |                       -1 |
    2021-10-17 00:31:31.000000000 |                  NULL |                     NULL |
    2021-12-24 00:31:34.000000000 |                     2 |                       -1 |
    2022-01-01 08:00:05.000000000 |                    19 |                        0 |
    2022-01-01 08:00:06.000000000 |                  NULL |                     NULL |
    2022-01-01 08:00:07.000000000 |                     9 |                        2 |
    Query OK, 6 row(s) in set (0.002613s)
     ```
G
Ganlin Zhao 已提交
1819 1820 1821 1822
- **HISTOGRAM**
    ```mysql
    SELECT HISTOGRAM(field_name,bin_type, bin_description, normalized) FROM tb_name [WHERE clause];
    ```
G
Ganlin Zhao 已提交
1823
    Function: Returns count of data points in user-specified ranges.
G
Ganlin Zhao 已提交
1824

G
Ganlin Zhao 已提交
1825
    Return Data Type: Double or INT64, depends on normalized parameter settings.
G
Ganlin Zhao 已提交
1826

G
Ganlin Zhao 已提交
1827
    Applicable Fields: Numerical types.
G
Ganlin Zhao 已提交
1828 1829 1830

    Applied to: **table stable**.

G
Ganlin Zhao 已提交
1831
    Note:
G
Ganlin Zhao 已提交
1832 1833 1834 1835 1836 1837 1838 1839 1840 1841 1842 1843 1844 1845 1846 1847 1848 1849 1850 1851 1852
    1. This function is supported since 2.6.0.0.
    2. bin_type: parameter to indicate the bucket type, valid inputs are: "user_input", "linear_bin", "log_bin"。
    3)bin_description: parameter to describe how to generate buckets,can be in the following JSON formats for each bin_type respectively:
       - "user_input": "[1, 3, 5, 7]"
       User defined specified bin values.

       - "linear_bin": "{"start": 0.0, "width": 5.0, "count": 5, "infinity": true}"
       "start" - bin starting point.
       "width" - bin offset.
       "count" - number of bins generated.
       "infinity" - whether to add(-inf, inf)as start/end point in generated set of bins.
       The above "linear_bin" descriptor generates a set of bins: [-inf, 0.0, 5.0, 10.0, 15.0, 20.0, +inf].

       - "log_bin": "{"start":1.0, "factor": 2.0, "count": 5, "infinity": true}"
       "start" - bin starting point.
       "factor" - exponential factor of bin offset.
       "count" - number of bins generated.
       "infinity" - whether to add(-inf, inf)as start/end point in generated range of bins.
       The above "log_bin" descriptor generates a set of bins:[-inf, 1.0, 2.0, 4.0, 8.0, 16.0, +inf].
    4)normalized: setting to 1/0 to turn on/off result normalization.

G
Ganlin Zhao 已提交
1853
    Example:
G
Ganlin Zhao 已提交
1854 1855 1856 1857 1858 1859 1860 1861 1862 1863 1864 1865 1866 1867 1868 1869 1870 1871 1872 1873 1874 1875 1876 1877 1878 1879
    ```mysql
     taos> SELECT HISTOGRAM(voltage, "user_input", "[1,3,5,7]", 1) FROM meters;
         histogram(voltage, "user_input", "[1,3,5,7]", 1) |
     =======================================================
     {"lower_bin":1, "upper_bin":3, "count":0.333333}     |
     {"lower_bin":3, "upper_bin":5, "count":0.333333}     |
     {"lower_bin":5, "upper_bin":7, "count":0.333333}     |
     Query OK, 3 row(s) in set (0.004273s)
     
     taos> SELECT HISTOGRAM(voltage, 'linear_bin', '{"start": 1, "width": 3, "count": 3, "infinity": false}', 0) FROM meters;
         histogram(voltage, 'linear_bin', '{"start": 1, "width": 3, " |
     ===================================================================
     {"lower_bin":1, "upper_bin":4, "count":3}                        |
     {"lower_bin":4, "upper_bin":7, "count":3}                        |
     {"lower_bin":7, "upper_bin":10, "count":3}                       |
     Query OK, 3 row(s) in set (0.004887s)
    
     taos> SELECT HISTOGRAM(voltage, 'log_bin', '{"start": 1, "factor": 3, "count": 3, "infinity": true}', 0) FROM meters;
     histogram(voltage, 'log_bin', '{"start": 1, "factor": 3, "count" |
     ===================================================================
     {"lower_bin":-inf, "upper_bin":1, "count":3}                     |
     {"lower_bin":1, "upper_bin":3, "count":2}                        |
     {"lower_bin":3, "upper_bin":9, "count":6}                        |
     {"lower_bin":9, "upper_bin":27, "count":3}                       |
     {"lower_bin":27, "upper_bin":inf, "count":1}                     |
    ```
G
Ganlin Zhao 已提交
1880 1881 1882 1883 1884 1885 1886
### Time Functions

Starting from version 2.6.0.0, TDengine supports following time related functions:

- **NOW**
    ```mysql
    SELECT NOW() FROM { tb_name | stb_name } [WHERE clause];
1887
    SELECT select_expr FROM { tb_name | stb_name } WHERE ts_col cond_operator NOW();
G
Ganlin Zhao 已提交
1888 1889 1890 1891 1892 1893 1894 1895 1896 1897 1898 1899 1900 1901 1902 1903 1904 1905 1906 1907 1908 1909 1910 1911 1912 1913 1914 1915 1916 1917 1918 1919 1920 1921 1922 1923 1924 1925 1926 1927 1928 1929
    INSERT INTO tb_name VALUES (NOW(), ...);
    ```
    Function: Returns current time of client.

    Returned Data Type: TIMESTAMP type.

    Applicable Fields: Can only be applied to TIMESTAMP field when used in WHERE or INSERT clause.

    Applied to: **table stable**.

    Note:
      1)Support arithmetic operations,e.g. NOW() + 1s. Valid time unit:
         b(nanosecond)、u(microsecond)、a(millisecond)、s(second)、m(minute)、h(hour)、d(day)、w(week).
      2)Returned timestamp precision is consist with current DATABASE precision settings.

    Example:
    ```mysql
    taos> SELECT NOW() FROM meters;
              now()          |
    ==========================
      2022-02-02 02:02:02.456 |
    Query OK, 1 row(s) in set (0.002093s)
      
    taos> SELECT NOW() + 1h FROM meters;
           now() + 1h         |
    ==========================
      2022-02-02 03:02:02.456 |
    Query OK, 1 row(s) in set (0.002093s)
    
    taos> SELECT COUNT(voltage) FROM d1001 WHERE ts < NOW();
            count(voltage)       |
    =============================
                               5 |
    Query OK, 5 row(s) in set (0.004475s)
    
    taos> INSERT INTO d1001 VALUES (NOW(), 10.2, 219, 0.32);
    Query OK, 1 of 1 row(s) in database (0.002210s)
    ```

- **TODAY**
    ```mysql
    SELECT TODAY() FROM { tb_name | stb_name } [WHERE clause];
1930
    SELECT select_expr FROM { tb_name | stb_name } WHERE ts_col cond_operator TODAY()];
G
Ganlin Zhao 已提交
1931 1932 1933 1934 1935 1936 1937 1938 1939 1940 1941 1942 1943 1944 1945 1946 1947 1948 1949 1950 1951 1952 1953 1954 1955 1956 1957 1958 1959 1960 1961 1962 1963 1964 1965 1966 1967 1968 1969 1970 1971 1972 1973
    INSERT INTO tb_name VALUES (TODAY(), ...);
    ```
    Function: Returns current date of client.

    Returned Data Type: TIMESTAMP type。

    Applicable Fields: Can only be applied to TIMESTAMP field when used in WHERE or INSERT clause.

    Applied to: **table stable**.

    Note:
      1)Support arithmetic operations, e.g. TODAY() + 1s. Valid time unit:
         b(nanosecond)、u(microsecond)、a(millisecond)、s(second)、m(minute)、h(hour)、d(day)、w(week).
      2)Returned timestamp precision is consist with current DATABASE precision settings.

    Example:
    ```mysql
    taos> SELECT TODAY() FROM meters;
             today()          |
    ==========================
      2022-02-02 00:00:00.000 |
    Query OK, 1 row(s) in set (0.002093s)
      
    taos> SELECT TODAY() + 1h FROM meters;
          today() + 1h        |
    ==========================
      2022-02-02 01:00:00.000 |
    Query OK, 1 row(s) in set (0.002093s)
    
    taos> SELECT COUNT(voltage) FROM d1001 WHERE ts < TODAY();
            count(voltage)       |
    =============================
                               5 |
    Query OK, 5 row(s) in set (0.004475s)
    
    taos> INSERT INTO d1001 VALUES (TODAY(), 10.2, 219, 0.32);
    Query OK, 1 of 1 row(s) in database (0.002210s)
    ```

- **TIMEZONE**
    ```mysql
    SELECT TIMEZONE() FROM { tb_name | stb_name } [WHERE clause];
    ```
G
Ganlin Zhao 已提交
1974
    Function: Returns current time zone information of client.
G
Ganlin Zhao 已提交
1975 1976 1977 1978 1979 1980 1981 1982 1983

    Returned Data Type: BINARY type.

    Applicable Fields: N/A.

    Applied to: **table stable**.

    Example:
    ```mysql
G
Ganlin Zhao 已提交
1984
    taos> SELECT TIMEZONE() FROM meters;
G
Ganlin Zhao 已提交
1985 1986 1987 1988 1989 1990 1991 1992 1993 1994
               timezone()           |
    =================================
     UTC (UTC, +0000)               |
    Query OK, 1 row(s) in set (0.002093s)
    ```

- **TO_ISO8601**
    ```mysql
    SELECT TO_ISO8601(ts_val | ts_col) FROM { tb_name | stb_name } [WHERE clause];
    ```
G
Ganlin Zhao 已提交
1995
    Function: Convert UNIX timestamp to ISO8601 standard date-time format string, with client time zone information attached.
G
Ganlin Zhao 已提交
1996 1997 1998 1999 2000 2001 2002

    Returned Data Type: BINARY type.

    Applicable Fields: UNIX timestamp constant and TIMESTAMP type columns.

    Applied to: **table stable**.
    
2003
    Note: If input is UNIX timestamp constant,returned ISO8601 format precision is determined by input timestamp digits. If input is TIMESTAMP type column, returned ISO8601 format precision is consist with current DATABASE precision settings.
G
Ganlin Zhao 已提交
2004 2005 2006 2007 2008 2009 2010 2011 2012 2013 2014 2015 2016 2017 2018 2019 2020 2021 2022 2023 2024 2025 2026 2027 2028 2029 2030 2031 2032 2033 2034 2035 2036 2037 2038 2039 2040 2041 2042 2043 2044 2045 2046 2047 2048 2049 2050 2051 2052

    Example:
    ```mysql
    taos> SELECT TO_ISO8601(1643738400) FROM meters;
       to_iso8601(1643738400)    |
    ==============================
     2022-02-02T02:00:00+0800    |
     
    taos> SELECT TO_ISO8601(ts) FROM meters;
           to_iso8601(ts)        |
    ==============================
     2022-02-02T02:00:00+0800    |
     2022-02-02T02:00:00+0800    |
     2022-02-02T02:00:00+0800    |
    ```

 - **TO_UNIXTIMESTAMP**
    ```mysql
    SELECT TO_UNIXTIMESTAMP(datetime_string | ts_col) FROM { tb_name | stb_name } [WHERE clause];
    ```
    Function: Convert date-time format string to UNIX timestamp.

    Returned Data Type: INT64.

    Applicable Fields: String literal or BINARY/NCHAR type columns.

    Applied to: **table stable**.
    
    Note:
    1)Input date-time string format should conform ISO8601/RFC3339 standard,otherwise conversion will fail and 0 is returned.
    2)Returned timestamp precision is consist with current DATABASE precision settings.

    Example:
    ```mysql
    taos> SELECT TO_UNIXTIMESTAMP("2022-02-02T02:00:00.000Z") FROM meters;
    to_unixtimestamp("2022-02-02T02:00:00.000Z") |
    ==============================================
                                   1643767200000 |
     
    taos> SELECT TO_UNIXTIMESTAMP(col_binary) FROM meters;
          to_unixtimestamp(col_binary)     |
    ========================================
                             1643767200000 |
                             1643767200000 |
                             1643767200000 |
    ```

 - **TIMETRUNCATE**
    ```mysql
G
Ganlin Zhao 已提交
2053
    SELECT TIMETRUNCATE(ts_val | datetime_string | ts_col, time_unit) FROM { tb_name | stb_name } [WHERE clause];
G
Ganlin Zhao 已提交
2054 2055 2056 2057
    ```
    Function: Truncate timestamp by time_unit.

    Returned Data Type: TIMESTAMP type.
G
Ganlin Zhao 已提交
2058

G
Ganlin Zhao 已提交
2059 2060 2061 2062 2063 2064 2065 2066 2067 2068 2069 2070 2071 2072 2073 2074 2075 2076 2077 2078 2079 2080 2081 2082 2083 2084 2085 2086 2087 2088 2089 2090 2091 2092 2093 2094 2095 2096 2097 2098 2099 2100 2101 2102 2103 2104 2105 2106 2107 2108 2109 2110 2111 2112 2113 2114 2115 2116 2117 2118 2119 2120 2121 2122 2123 2124 2125 2126 2127 2128 2129 2130 2131 2132
    Applicable Fields: UNIX timestamp, date-time format string, and TIMESTAMP type columns.

    Applied to: **table stable**.
    
    Note:
    1)Supported time_unit:
         1u(microsecond),1a(millisecond),1s(second),1m(minute),1h(hour),1d(day)。
    2)Returned timestamp precision is consist with current DATABASE precision settings.

    Example:
    ```mysql
    taos> SELECT TIMETRUNCATE(1643738522000, 1h) FROM meters;
      timetruncate(1643738522000, 1h) |
    ===================================
          2022-02-02 02:00:00.000     |
    Query OK, 1 row(s) in set (0.001499s)
    
    taos> SELECT TIMETRUNCATE("2022-02-02 02:02:02", 1h) FROM meters;
      timetruncate("2022-02-02 02:02:02", 1h) |
    ===========================================
          2022-02-02 02:00:00.000             |
    Query OK, 1 row(s) in set (0.003903s)
    
    taos> SELECT TIMETRUNCATE(ts, 1h) FROM meters;
      timetruncate(ts, 1h)   |
    ==========================
     2022-02-02 02:00:00.000 |
     2022-02-02 02:00:00.000 |
     2022-02-02 02:00:00.000 |
    Query OK, 3 row(s) in set (0.003903s)
    ```

 - **TIMEDIFF**
    ```mysql
    SELECT TIMEDIFF(ts_val1 | datetime_string1 | ts_col1, ts_val2 | datetime_string2 | ts_col2 [, time_unit]) FROM { tb_name | stb_name } [WHERE clause];
    ```
    Function: Calculate duration between two timestamps with time_unit precision。

    Returned Data Type: INT64.

    Applicable Fields: UNIX timestamp, date-time format string, and TIMESTAMP type columns.

    Applied to: **table stable**.
    
    Note:
    1)Supported time_unit:
         1u(microsecond),1a(millisecond),1s(second),1m(minute),1h(hour),1d(day)。
    2)If time_unit is unspecified, returned time duration unit is consist with current DATABASE precision settings.

    Example:
    ```mysql
    taos> SELECT TIMEDIFF(1643738400000, 1643742000000) FROM meters;
     timediff(1643738400000, 1643742000000) |
    =========================================
                                    3600000 |
    Query OK, 1 row(s) in set (0.002553s)
    taos> SELECT TIMEDIFF(1643738400000, 1643742000000, 1h) FROM meters;
     timediff(1643738400000, 1643742000000, 1h) |
    =============================================
                                              1 |
    Query OK, 1 row(s) in set (0.003726s)
    
    taos> SELECT TIMEDIFF("2022-02-02 03:00:00", "2022-02-02 02:00:00", 1h) FROM meters;
     timediff("2022-02-02 03:00:00", "2022-02-02 02:00:00", 1h) |
    =============================================================
                                                              1 |
    Query OK, 1 row(s) in set (0.001937s)
    
    taos> SELECT TIMEDIFF(ts_col1, ts_col2, 1h) FROM meters;
       timediff(ts_col1, ts_col2, 1h) |
    ===================================
                                    1 |
    Query OK, 1 row(s) in set (0.001937s)
    ```
2133

2134 2135
## <a class="anchor" id="aggregation"></a> Time-dimension Aggregation

2136
TDengine supports aggregating by intervals (time range). Data in a table can partitioned by intervals and aggregated to generate results. For example, a temperature sensor collects data once per second, but the average temperature needs to be queried every 10 minutes. This aggregation is suitable for down sample operation, and the syntax is as follows:
2137 2138 2139 2140 2141 2142 2143 2144 2145 2146 2147 2148 2149 2150 2151 2152 2153 2154 2155 2156 2157

```mysql
SELECT function_list FROM tb_name
  [WHERE where_condition]
  INTERVAL (interval [, offset])
  [SLIDING sliding]
  [FILL ({NONE | VALUE | PREV | NULL | LINEAR | NEXT})]

SELECT function_list FROM stb_name
  [WHERE where_condition]
  INTERVAL (interval [, offset])
  [SLIDING sliding]
  [FILL ({ VALUE | PREV | NULL | LINEAR | NEXT})]
  [GROUP BY tags]
```

- The length of aggregation interval is specified by keyword INTERVAL, the min time interval is 10 milliseconds (10a), and offset is supported (the offset must be less than interval). In aggregation queries, the aggregator and selector functions that can be executed simultaneously are limited to functions with one single output: count, avg, sum, stddev, leastsquares, percentile, min, max, first, last. Functions with multiple rows of output results (such as top, bottom, diff, and four operations) cannot be used.

- WHERE statement specifies the start and end time of a query and other filters

- FILL statement specifies a filling mode when data missed in a certain interval. Applicable filling modes include the following:
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
2158
  
B
Bo Ding 已提交
2159
  1. Do not fill: NONE (default filing mode).
涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
2160 2161 2162 2163
  2. VALUE filling: Fixed value filling, where the filled value needs to be specified. For example: fill (VALUE, 1.23).
  3. NULL filling: Fill the data with NULL. For example: fill (NULL).
  4. PREV filling: Filling data with the previous non-NULL value. For example: fill (PREV).
  5. NEXT filling: Filling data with the next non-NULL value. For example: fill (NEXT).
2164 2165 2166

Note:

涛思数据(TDengine)'s avatar
涛思数据(TDengine) 已提交
2167 2168 2169
  1. When using a FILL statement, a large number of filling outputs may be generated. Be sure to specify the time interval for the query. For each query, system can return no more than 10 million results with interpolation.
  2. In a time-dimension aggregation, the time-series in returned results increases strictly monotonously.
  3. If the query object is a STable, the aggregator function will act on the data of all tables under the STable that meet the value filters. If group by statement is not used in the query, the returned result increases strictly monotonously according to time-series; If group by statement is used to group in the query, each group in the returned result does not increase strictly monotonously according to time-series.
2170 2171 2172 2173 2174 2175 2176 2177 2178 2179 2180 2181 2182 2183 2184 2185 2186 2187 2188

Example: The statement for building a database for smart meter is as follows:

```mysql
CREATE TABLE meters (ts TIMESTAMP, current FLOAT, voltage INT, phase FLOAT) TAGS (location BINARY(64), groupId INT);
```

According to the data collected by the smart meter, the average value, maximum value, median current of current data in the past 24 hours are calculated in a phase of 10 minutes, and the current trend with time changes is fitted to a straight line. If there is no calculated value, fill it with the previous non-NULL value. The query statement used is as follows:

```mysql
SELECT AVG(current), MAX(current), LEASTSQUARES(current, start_val, step_val), PERCENTILE(current, 50) FROM meters
  WHERE ts>=NOW-1d
  INTERVAL(10m)
  FILL(PREV);
```

## <a class="anchor" id="limitation"></a> TAOS SQL Boundary Restrictions

- Max database name length is 32
2189
- Max length of table name is 192, and max length of each data row is 48K (it's 16K prior to 2.1.7.0) characters
2190
- Max length of column name is 64, max number of columns allowed is 1024, and min number of columns allowed is 2. The first column must be a timestamp
2191
- Max number of tags allowed is 128, down to 1, and total length of tags does not exceed 16K characters
2192 2193 2194 2195 2196 2197 2198
- Max length of SQL statement is 65480 characters, but it can be modified by system configuration parameter maxSQLLength, and max length can be configured to 1M
- Number of databases, STables and tables are not limited by system, but only limited by system resources

## Other TAOS SQL Conventions

**Restrictions on group by**

2199
TAOS SQL supports group by operation on tags, tbnames and ordinary columns, required that only one column and which has less than 100,000 unique values.
2200 2201 2202

**Restrictions on join operation**

2203
TAOS SQL supports join columns of two tables by Primary Key timestamp between them, and does not support four arithmetic operations after tables aggregated for the time being.
2204 2205 2206

**Availability of is no null**

L
Lin_X 已提交
2207
Is not null supports all types of columns. Non-null expression is < > "" and only applies to columns of non-numeric types.
wmmhello's avatar
wmmhello 已提交
2208 2209 2210 2211 2212 2213 2214 2215 2216 2217 2218 2219 2220 2221 2222 2223 2224 2225 2226 2227 2228 2229 2230 2231 2232 2233 2234 2235 2236 2237 2238 2239 2240 2241 2242 2243 2244 2245 2246 2247 2248 2249 2250 2251 2252 2253 2254 2255 2256 2257 2258 2259 2260 2261 2262 2263 2264 2265 2266 2267 2268 2269 2270 2271 2272 2273 2274 2275 2276 2277 2278 2279 2280 2281 2282 2283 2284 2285 2286 2287 2288 2289 2290 2291 2292 2293 2294 2295 2296

**Restrictions on order by**

- A non super table can only have one order by.
- The super table can have at most two order by expression, and the second must be ts.
- Order by tag must be the same tag as group by tag. TBNAME is as logical as tag.
- Order by ordinary column must be the same ordinary column as group by or top/bottom. If both group by and top / bottom exist, order by must be in the same column as group by.
- There are both order by and group by. The internal of the group is sorted by ts
- Order by ts.

## JSON type instructions
- Syntax description

  1. Create JSON type tag

     ```mysql
     create stable s1 (ts timestamp, v1 int) tags (info json)

     create table s1_1 using s1 tags ('{"k1": "v1"}')
     ```
  3. JSON value operator(->)

     ```mysql   
     select * from s1 where info->'k1' = 'v1'

     select info->'k1' from s1 
     ```
  4. JSON key existence operator(contains)

     ```mysql
     select * from s1 where info contains 'k2'
    
     select * from s1 where info contains 'k1'
     ```

- Supported operations

  1. In where condition,support match/nmatch/between and/like/and/or/is null/is no null,in operator is not support.

     ```mysql 
     select * from s1 where info→'k1' match 'v*'; 

     select * from s1 where info→'k1' like 'v%' and info contains 'k2';

     select * from s1 where info is null; 
  
     select * from s1 where info->'k1' is not null
     ```

  2. JSON tag is supported in group by、order by、join clause、union all and subquery,like group by json->'key'

  3. Support distinct operator.

     ```mysql 
     select distinct info→'k1' from s1
     ```

  5. Tag

     Support change JSON tag(full coverage)

     Support change the name of JSON tag

     Not support add JSON tag, delete JSON tag

- Other constraints

  1. Only tag columns can use JSON type. If JSON tag is used, there can only be one tag column.

  2. Length limit:The length of the key in JSON cannot exceed 256, and the key must be printable ASCII characters; The total length of JSON string does not exceed 4096 bytes.

  3. JSON format restrictions:

    1. JSON input string can be empty (""," ","\t" or null) or object, and cannot be nonempty string, boolean or array.
    2. Object can be {}, if the object is {}, the whole JSON string is marked as empty. The key can be "", if the key is "", the K-V pair will be ignored in the JSON string.
    3. Value can be a number (int/double) or string, bool or null, not an array. Nesting is not allowed.
    4. If two identical keys appear in the JSON string, the first one will take effect.
    5. Escape is not supported in JSON string.

  4. Null is returned when querying the key that does not exist in JSON.

  5. When JSON tag is used as the sub query result, parsing and querying the JSON string in the sub query is no longer supported in the upper level query.

     The following query is not supported:
     ```mysql 
     select jtag→'key' from (select jtag from stable)
      
     select jtag->'key' from (select jtag from stable) where jtag->'key'>0
     ```
2297
## Escape character description
2298
- Special Character Escape Sequences (since version 2.4.0.4)
2299 2300 2301 2302 2303 2304 2305 2306 2307 2308 2309 2310 2311 2312 2313 2314 2315 2316

  | Escape Sequence    | **Character Represented by Sequence**  |
      | :--------:     |   -------------------   |
  | `\'`             |  A single quote (') character    | 
  | `\"`             |  A double quote (") character      |
  | \n             |  A newline (linefeed) character       |
  | \r             |  A carriage return character       |
  | \t             |  A tab character       |
  | `\\`             |  A backslash (\) character        |
  | `\%`            |  A % character; see note following the table    |
  | `\_`             |  A _ character; see note following the table    |

- Escape character usage rules
  - The escape characters that in a identifier (database name, table name, column name)
    1. Normal identifier:    The wrong identifier is prompted directly, because the identifier must be numbers, letters and underscores, and cannot start with a number.
    2. Backquote`` identifier: Keep it as it is.
  - The escape characters that in a data
    3. The escape character defined above will be escaped (% and _ see the description below). If there is no matching escape character, the escape character will be ignored.
2317
    4. The `\%` and `\_` sequences are used to search for literal instances of % and _ in pattern-matching contexts where they would otherwise be interpreted as wildcard characters.If you use `\%` or `\_` outside of pattern-matching contexts, they evaluate to the strings `\%` and `\_`, not to % and _.