10-function.md 38.0 KB
Newer Older
1
---
2
sidebar_label: Functions
3
title: Functions
4
toc_max_heading_level: 4
5 6
---

7
## Single Row Functions
8

9
Single row functions return a result for each row.
10

11
### Mathematical Functions
12

13
#### ABS
14

15
```sql
G
Ganlin Zhao 已提交
16
ABS(expr)
17
```
18

19
**Description**: The absolute value of a specific field.
20

21
**Return value type**: Same as the field being used
22

23
**Applicable data types**: Numeric
24

25
**Nested query**: It can be used in both the outer query and inner query in a nested query.
26

27
**Applicable table types**: standard tables and supertables
28

29
**Usage**: This function can only be used on data columns. It can be used with selection and projection functions but not with aggregation functions.
30

31
#### ACOS
32

33
```sql
G
Ganlin Zhao 已提交
34
ACOS(expr)
35 36
```

37
**Description**: The arc cosine of a specific field.
38

39
**Return value type**: Double
40

41
**Applicable data types**: Numeric
42

43
**Nested query**: It can be used in both the outer query and inner query in a nested query.
44

45
**Applicable table types**: standard tables and supertables
46

47
**Usage**: This function can only be used on data columns. It can be used with selection and projection functions but not with aggregation functions.
48

49
#### ASIN
50

51
```sql
G
Ganlin Zhao 已提交
52
ASIN(expr)
53 54
```

55
**Description**: The arc sine of a specific field.
56

57
**Return value type**: Double
58

59
**Applicable data types**: Numeric
60

61
**Nested query**: It can be used in both the outer query and inner query in a nested query.
62

63 64 65
**Applicable table types**: standard tables and supertables

**Usage**: This function can only be used on data columns. It can be used with selection and projection functions but not with aggregation functions.
66

67

68
#### ATAN
69

70
```sql
G
Ganlin Zhao 已提交
71
ATAN(expr)
72 73
```

74
**Description**: The arc tangent of a specific field.
75

76
**Return value type**: Double
77

78
**Applicable data types**: Numeric
79

80
**Nested query**: It can be used in both the outer query and inner query in a nested query.
81

82 83 84
**Applicable table types**: standard tables and supertables

**Usage**: This function can only be used on data columns. It can be used with selection and projection functions but not with aggregation functions.
85

86

87
#### CEIL
88

89
```sql
G
Ganlin Zhao 已提交
90
CEIL(expr)
91 92
```

93
**Description**: The rounded up value of a specific field
94

95
**Return value type**: Same as the field being used
96

97
**Applicable data types**: Numeric
98

99
**Applicable table types**: standard tables and supertables
100

101
**Nested query**: It can be used in both the outer query and inner query in a nested query.
102

103
**Usage**: This function can only be used on data columns. It can be used with selection and projection functions but not with aggregation functions.
104

105
#### COS
106

107
```sql
G
Ganlin Zhao 已提交
108
COS(expr)
109 110
```

111
**Description**: The cosine of a specific field.
112

113
**Return value type**: Double
114

115
**Applicable data types**: Numeric
116

117
**Nested query**: It can be used in both the outer query and inner query in a nested query.
118

119
**Applicable table types**: standard tables and supertables
120

121
**Usage**: This function can only be used on data columns. It can be used with selection and projection functions but not with aggregation functions.
122

123
#### FLOOR
124

125
```sql
G
Ganlin Zhao 已提交
126
FLOOR(expr)
127 128
```

G
Ganlin Zhao 已提交
129
**Description**: The rounded down value of a specific field
130
 **More explanations**: The restrictions are same as those of the `CEIL` function.
131 132 133 134

#### LOG

```sql
G
Ganlin Zhao 已提交
135
LOG(expr [, base])
136 137
```

138 139 140
**Description**: The logarithm of a specific field with `base` as the radix. If you do not enter a base, the natural logarithm of the field is returned.

**Return value type**: Double
141

142
**Applicable data types**: Numeric
143

144
**Nested query**: It can be used in both the outer query and inner query in a nested query.
145

146
**Applicable table types**: standard tables and supertables
147

148
**Usage**: This function can only be used on data columns. It can be used with selection and projection functions but not with aggregation functions.
149 150


151
#### POW
152

153
```sql
G
Ganlin Zhao 已提交
154
POW(expr, power)
155
```
156

157 158 159
**Description**: The power of a specific field with `power` as the exponent.

**Return value type**: Double
160

161
**Applicable data types**: Numeric
162

163
**Nested query**: It can be used in both the outer query and inner query in a nested query.
164

165
**Applicable table types**: standard tables and supertables
166

167
**Usage**: This function can only be used on data columns. It can be used with selection and projection functions but not with aggregation functions.
168 169


170
#### ROUND
171

172
```sql
G
Ganlin Zhao 已提交
173
ROUND(expr)
174 175
```

G
Ganlin Zhao 已提交
176
**Description**: The rounded value of a specific field.
177
 **More explanations**: The restrictions are same as those of the `CEIL` function.
178 179


180
#### SIN
181

182
```sql
G
Ganlin Zhao 已提交
183
SIN(expr)
184
```
185

186
**Description**: The sine of a specific field.
187

188
**Return value type**: Double
189

190
**Applicable data types**: Numeric
191

192
**Nested query**: It can be used in both the outer query and inner query in a nested query.
193

194
**Applicable table types**: standard tables and supertables
195

196
**Usage**: This function can only be used on data columns. It can be used with selection and projection functions but not with aggregation functions.
197

198
#### SQRT
199

200
```sql
G
Ganlin Zhao 已提交
201
SQRT(expr)
202
```
203

204
**Description**: The square root of a specific field.
205

206
**Return value type**: Double
207

208
**Applicable data types**: Numeric
G
gccgdb1234 已提交
209

210
**Nested query**: It can be used in both the outer query and inner query in a nested query.
G
gccgdb1234 已提交
211

212
**Applicable table types**: standard tables and supertables
213

214
**Usage**: This function can only be used on data columns. It can be used with selection and projection functions but not with aggregation functions.
G
gccgdb1234 已提交
215

216
#### TAN
217

218
```sql
G
Ganlin Zhao 已提交
219
TAN(expr)
220 221
```

222
**Description**: The tangent of a specific field.
G
gccgdb1234 已提交
223

224
**Return value type**: Double
G
gccgdb1234 已提交
225

226
**Applicable data types**: Numeric
G
gccgdb1234 已提交
227

228
**Nested query**: It can be used in both the outer query and inner query in a nested query.
G
gccgdb1234 已提交
229

230
**Applicable table types**: standard tables and supertables
G
gccgdb1234 已提交
231

232
**Usage**: This function can only be used on data columns. It can be used with selection and projection functions but not with aggregation functions.
G
gccgdb1234 已提交
233

234
### Concatenation Functions
235

236
Concatenation functions take strings as input and produce string or numeric values as output.
237

238
#### CHAR_LENGTH
239

240
```sql
G
Ganlin Zhao 已提交
241
CHAR_LENGTH(expr)
242 243
```

244
**Description**: The length in number of characters of a string
245

246
**Return value type**: Bigint
247

248
**Applicable data types**: VARCHAR and NCHAR
249

250
**Nested query**: It can be used in both the outer query and inner query in a nested query.
251

252
**Applicable table types**: standard tables and supertables
253

254
#### CONCAT
255

256
```sql
G
Ganlin Zhao 已提交
257
CONCAT(expr1, expr2 [, expr] ...)
258 259
```

260
**Description**: The concatenation result of two or more strings
261

262
**Return value type**: If the concatenated strings are VARCHARs, the result is a VARCHAR. If the concatenated strings are NCHARs, the result is an NCHAR. If an input value is null, the result is null.
263

264
**Applicable data types**: VARCHAR and NCHAR You can concatenate between 2 and 8 strings.
265

266
**Nested query**: It can be used in both the outer query and inner query in a nested query.
267

268
**Applicable table types**: standard tables and supertables
269 270


271
#### CONCAT_WS
272

273
```sql
G
Ganlin Zhao 已提交
274
CONCAT_WS(separator_expr, expr1, expr2 [, expr] ...)
275 276
```

277
**Description**: The concatenation result of two or more strings with separator
278

279
**Return value type**: If the concatenated strings are VARCHARs, the result is a VARCHAR. If the concatenated strings are NCHARs, the result is an NCHAR. If an input value is null, the result is null.
280

281
**Applicable data types**: VARCHAR and NCHAR You can concatenate between 3 and 9 strings.
282

283
**Nested query**: It can be used in both the outer query and inner query in a nested query.
284

285
**Applicable table types**: standard tables and supertables
286 287


288
#### LENGTH
289

290
```sql
G
Ganlin Zhao 已提交
291
LENGTH(expr)
292 293
```

294
**Description**: The length in bytes of a string
295

296
**Return value type**: Bigint
297

298
**Applicable data types**: VARCHAR and NCHAR fields or columns
299

300
**Nested query**: It can be used in both the outer query and inner query in a nested query.
301

302
**Applicable table types**: standard tables and supertables
303 304


305
#### LOWER
306

307
```sql
G
Ganlin Zhao 已提交
308
LOWER(expr)
309 310
```

311
**Description**: Convert the input string to lower case
312

313
**Return value type**: Same as input
314

315
**Applicable data types**: VARCHAR and NCHAR
316

317
**Nested query**: It can be used in both the outer query and inner query in a nested query.
318

319
**Applicable table types**: standard tables and supertables
320 321


322
#### LTRIM
323

324
```sql
G
Ganlin Zhao 已提交
325
LTRIM(expr)
326 327
```

328
**Description**: Remove the left leading blanks of a string
329

330
**Return value type**: Same as input
331

332
**Applicable data types**: VARCHAR and NCHAR
333

334
**Nested query**: It can be used in both the outer query and inner query in a nested query.
335

336
**Applicable table types**: standard tables and supertables
337 338


339
#### RTRIM
340

341
```sql
G
Ganlin Zhao 已提交
342
LTRIM(expr)
343 344
```

345
**Description**: Remove the right tailing blanks of a string
346

347
**Return value type**: Same as input
348

349
**Applicable data types**: VARCHAR and NCHAR
350

351
**Nested query**: It can be used in both the outer query and inner query in a nested query.
352

353
**Applicable table types**: standard tables and supertables
354 355


356
#### SUBSTR
357

358
```sql
G
Ganlin Zhao 已提交
359
SUBSTR(expr, pos [, len])
360 361
```

362
**Description**: The sub-string starting from `pos` with length of `len` from the original string `str` - If `len` is not specified, it means from `pos` to the end.
363

364
**Return value type**: Same as input
365

366
**Applicable data types**: VARCHAR and NCHAR Parameter `pos` can be an positive or negative integer; If it's positive, the starting position will be counted from the beginning of the string; if it's negative, the starting position will be counted from the end of the string.
367

368
**Nested query**: It can be used in both the outer query and inner query in a nested query.
369

370
**Applicable table types**: table, STable
371 372


373
#### UPPER
374

375
```sql
G
Ganlin Zhao 已提交
376
UPPER(expr)
377 378
```

379
**Description**: Convert the input string to upper case
380

381
**Return value type**: Same as input
382

383
**Applicable data types**: VARCHAR and NCHAR
384

385
**Nested query**: It can be used in both the outer query and inner query in a nested query.
386

387
**Applicable table types**: table, STable
388 389


390
### Conversion Functions
391

392
Conversion functions change the data type of a value.
393

394
#### CAST
395

396
```sql
G
Ganlin Zhao 已提交
397
CAST(expr AS type_name)
398 399
```

G
Ganlin Zhao 已提交
400
**Description**: Convert the input data `expr` into the type specified by `type_name`. This function can be used only in SELECT statements.
401

402 403 404 405 406
**Return value type**: The type specified by parameter `type_name`

**Applicable data types**: All data types except JSON

**Nested query**: It can be used in both the outer query and inner query in a nested query.
407

408
**Applicable table types**: standard tables and supertables
409

410
**More explanations**:
411

412
- Error will be reported for unsupported type casting
413
- Some values of some supported data types may not be casted, below are known issues:
414 415 416
        1. Some strings cannot be converted to numeric values. For example, the string `a` may be converted to `0`. However, this does not produce an error.
        2. If a converted numeric value is larger than the maximum size for the specified type, an overflow will occur. However, this does not produce an error.
        3. If a converted string value is larger than the maximum size for the specified type, the output value will be truncated. However, this does not produce an error.
417

418
#### TO_ISO8601
419

420
```sql
G
Ganlin Zhao 已提交
421
TO_ISO8601(expr [, timezone])
422 423
```

424
**Description**: The ISO8601 date/time format converted from a UNIX timestamp, plus the timezone. You can specify any time zone with the timezone parameter. If you do not enter this parameter, the time zone on the client is used.
425

426
**Return value type**: VARCHAR
427

428
**Applicable data types**: Integers and timestamps
429

430 431 432
**Nested query**: It can be used in both the outer query and inner query in a nested query.

**Applicable table types**: standard tables and supertables
433

434
**More explanations**:
435

436
- You can specify a time zone in the following format: [z/Z, +/-hhmm, +/-hh, +/-hh:mm]。 For example, TO_ISO8601(1, "+00:00").
G
Ganlin Zhao 已提交
437
- If the input is a UNIX timestamp, the precision of the returned value is determined by the digits of the input timestamp
438 439
- If the input is a column of TIMESTAMP type, the precision of the returned value is same as the precision set for the current data base in use

440

441
#### TO_JSON
442

443
```sql
G
Ganlin Zhao 已提交
444
TO_JSON(str_literal)
445 446
```

447
**Description**: Converts a string into JSON.
448

449
**Return value type**: JSON
450

451
**Applicable data types**: JSON strings in the form `{"literal": literal}`. `{}` indicates a null value. The key must be a string literal. The value can be a numeric literal, string literal, Boolean literal, or null literal. str_literal cannot include escape characters.
452

453 454 455
**Nested query**: It can be used in both the outer query and inner query in a nested query.

**Applicable table types**: table, STable
456 457


458
#### TO_UNIXTIMESTAMP
459

460
```sql
G
Ganlin Zhao 已提交
461
TO_UNIXTIMESTAMP(expr)
462 463
```

464
**Description**: UNIX timestamp converted from a string of date/time format
465

466
**Return value type**: BIGINT
467

468
**Applicable column types**: VARCHAR and NCHAR
469

470 471 472
**Nested query**: It can be used in both the outer query and inner query in a nested query.

**Applicable table types**: standard tables and supertables
473

474
**More explanations**:
475

476 477 478 479 480
- The input string must be compatible with ISO8601/RFC3339 standard, NULL will be returned if the string can't be converted
- The precision of the returned timestamp is same as the precision set for the current data base in use


### Time and Date Functions
481

482
These functions perform operations on times and dates.
483

484
All functions that return the current time, such as `NOW`, `TODAY`, and `TIMEZONE`, are calculated only once per statement even if they appear multiple times.
485

486
#### NOW
487

488
```sql
G
Ganlin Zhao 已提交
489
NOW()
490
```
491

492
**Description**: The current time of the client side system
493

494
**Return value type**: TIMESTAMP
495

496
**Applicable column types**: TIMESTAMP only
497

498 499 500
**Applicable table types**: standard tables and supertables

**Nested query**: It can be used in both the outer query and inner query in a nested query.
501

502
**More explanations**:
503

504 505 506 507
- Add and Subtract operation can be performed, for example NOW() + 1s, the time unit can be:
        b(nanosecond), u(microsecond), a(millisecond)), s(second), m(minute), h(hour), d(day), w(week)
- The precision of the returned timestamp is same as the precision set for the current data base in use

508

509 510 511
#### TIMEDIFF

```sql
G
Ganlin Zhao 已提交
512
TIMEDIFF(expr1, expr2 [, time_unit])
513 514
```

515
**Description**: The difference between two timestamps, and rounded to the time unit specified by `time_unit`
516

517
**Return value type**: BIGINT
518

519
**Applicable column types**: UNIX-style timestamps in BIGINT and TIMESTAMP format and other timestamps in VARCHAR and NCHAR format
520

521
**Applicable table types**: standard tables and supertables
522

523
**Nested query**: It can be used in both the outer query and inner query in a nested query.
524

525
**More explanations**:
526
- Time unit specified by `time_unit` can be:
527 528 529 530
          1b (nanoseconds), 1u (microseconds), 1a (milliseconds), 1s (seconds), 1m (minutes), 1h (hours), 1d (days), or 1w (weeks)
- The precision of the returned timestamp is same as the precision set for the current data base in use
- If the input data is not formatted as a timestamp, the returned value is null.

531

532
#### TIMETRUNCATE
533 534

```sql
G
Ganlin Zhao 已提交
535
TIMETRUNCATE(expr, time_unit)
536 537
```

538
**Description**: Truncate the input timestamp with unit specified by `time_unit`
539

540
**Return value type**: TIMESTAMP
541

542
**Applicable column types**: UNIX-style timestamps in BIGINT and TIMESTAMP format and other timestamps in VARCHAR and NCHAR format
543

544
**Applicable table types**: standard tables and supertables
545 546

**More explanations**:
547
- Time unit specified by `time_unit` can be:
548 549 550 551
          1b (nanoseconds), 1u (microseconds), 1a (milliseconds), 1s (seconds), 1m (minutes), 1h (hours), 1d (days), or 1w (weeks)
- The precision of the returned timestamp is same as the precision set for the current data base in use
- If the input data is not formatted as a timestamp, the returned value is null.

552

553
#### TIMEZONE
554 555

```sql
G
Ganlin Zhao 已提交
556
TIMEZONE()
557 558
```

559
**Description**: The timezone of the client side system
560

561
**Applicable data types**: VARCHAR
562

563 564 565
**Applicable column types**: None

**Applicable table types**: standard tables and supertables
566 567


568
#### TODAY
569

570
```sql
G
Ganlin Zhao 已提交
571
TODAY()
572 573
```

574
**Description**: The timestamp of 00:00:00 of the client side system
575

576
**Return value type**: TIMESTAMP
577

578
**Applicable column types**: TIMESTAMP only
579

580
**Applicable table types**: standard tables and supertables
581

582
**More explanations**:
583

584 585 586 587
- Add and Subtract operation can be performed, for example TODAY() + 1s, the time unit can be:
                b(nanosecond), u(microsecond), a(millisecond)), s(second), m(minute), h(hour), d(day), w(week)
- The precision of the returned timestamp is same as the precision set for the current data base in use

588

589
## Aggregate Functions
590

591 592 593
Aggregate functions return one row per group. You can use windows or GROUP BY to group data. Otherwise, the entire query is considered a single group.

TDengine supports the following aggregate functions:
594

G
Ganlin Zhao 已提交
595 596
### APERCENTILE

597
```sql
G
Ganlin Zhao 已提交
598 599 600 601 602 603
APERCENTILE(expr, p [, algo_type])

algo_type: {
    "default"
  | "t-digest"
}
G
Ganlin Zhao 已提交
604 605
```

606
**Description**: Similar to `PERCENTILE`, but a simulated result is returned
G
Ganlin Zhao 已提交
607

608
**Return value type**: DOUBLE
G
Ganlin Zhao 已提交
609

610
**Applicable data types**: Numeric
G
Ganlin Zhao 已提交
611

612
**Applicable table types**: standard tables and supertables
G
Ganlin Zhao 已提交
613

614
**Explanations**
G
Ganlin Zhao 已提交
615
- _p_ is in range [0,100], when _p_ is 0, the result is same as using function MIN; when _p_ is 100, the result is same as function MAX.
616
- `algo_type` can only be input as `default` or `t-digest` Enter `default` to use a histogram-based algorithm. Enter `t-digest` to use the t-digest algorithm to calculate the approximation of the quantile. `default` is used by default.
617
- The approximation result of `t-digest` algorithm is sensitive to input data order. For example, when querying STable with different input data order there might be minor differences in calculated results.
G
Ganlin Zhao 已提交
618

619
### AVG
620

621
```sql
G
Ganlin Zhao 已提交
622
AVG(expr)
623 624
```

625 626 627
**Description**: The average value of the specified fields.

**Return value type**: DOUBLE
628

629
**Applicable data types**: Numeric
630

631
**Applicable table types**: standard tables and supertables
632 633


634
### COUNT
635

636
```sql
G
Ganlin Zhao 已提交
637
COUNT({* | expr})
638 639
```

640
**Description**: The number of records in the specified fields.
641

642
**Return value type**: BIGINT
643

644
**Applicable data types**: Numeric
645

646
**Applicable table types**: standard tables and supertables
647

648
**More explanation**:
649

650 651 652
- Wildcard (\*) is used to represent all columns.
If you input a specific column, the number of non-null values in the column is returned.

653

654
### ELAPSED
655

656
```sql
G
Ganlin Zhao 已提交
657
ELAPSED(ts_primary_key [, time_unit])
658 659
```

660
**Description**`elapsed` function can be used to calculate the continuous time length in which there is valid data. If it's used with `INTERVAL` clause, the returned result is the calcualted time length within each time window. If it's used without `INTERVAL` caluse, the returned result is the calculated time length within the specified time range. Please be noted that the return value of `elapsed` is the number of `time_unit` in the calculated time length.
661

662
**Return value type**: Double if the input value is not NULL;
663

664
**Return value type**: TIMESTAMP
665

666
**Applicable tables**: table, STable, outter in nested query
667

668
**Explanations**
G
Ganlin Zhao 已提交
669
- `ts_primary_key` parameter can only be the first column of a table, i.e. timestamp primary key.
670 671
- The minimum value of `time_unit` is the time precision of the database. If `time_unit` is not specified, the time precision of the database is used as the default time unit. Time unit specified by `time_unit` can be:
          1b (nanoseconds), 1u (microseconds), 1a (milliseconds), 1s (seconds), 1m (minutes), 1h (hours), 1d (days), or 1w (weeks)
672 673 674 675
- It can be used with `INTERVAL` to get the time valid time length of each time window. Please be noted that the return value is same as the time window for all time windows except for the first and the last time window.
- `order by asc/desc` has no effect on the result.
- `group by tbname` must be used together when `elapsed` is used against a STable.
- `group by` must NOT be used together when `elapsed` is used against a table or sub table.
676 677 678
- When used in nested query, it's only applicable when the inner query outputs an implicit timestamp column as the primary key. For example, `select elapsed(ts) from (select diff(value) from sub1)` is legal usage while `select elapsed(ts) from (select * from sub1)` is not. In addition, because elapsed has a strict dependency on the timeline, a statement like `select elapsed(ts) from (select diff(value) from st group by tbname) will return a meaningless result.
- It can't be used with `leastsquares`, `diff`, `derivative`, `top`, `bottom`, `last_row`, `interp`.

679

680
### LEASTSQUARES
681

682
```sql
G
Ganlin Zhao 已提交
683
LEASTSQUARES(expr, start_val, step_val)
684
```
685

686
**Description**: The linear regression function of the specified column and the timestamp column (primary key), `start_val` is the initial value and `step_val` is the step value.
687

688 689 690
**Return value type**: A string in the format of "(slope, intercept)"

**Applicable data types**: Numeric
691

692
**Applicable table types**: table only
693

694

695
### SPREAD
696

697
```sql
G
Ganlin Zhao 已提交
698
SPREAD(expr)
699 700
```

701
**Description**: The difference between the max and the min of a specific column
702

703
**Return value type**: DOUBLE
704

705
**Applicable data types**: Integers and timestamps
706

707
**Applicable table types**: standard tables and supertables
708 709


710
### STDDEV
711

712
```sql
G
Ganlin Zhao 已提交
713
STDDEV(expr)
714 715
```

716
**Description**: Standard deviation of a specific column in a table or STable
717

718
**Return value type**: DOUBLE
719

720 721 722
**Applicable data types**: Numeric

**Applicable table types**: standard tables and supertables
723 724


725
### SUM
726

727
```sql
G
Ganlin Zhao 已提交
728
SUM(expr)
729
```
730

731 732 733
**Description**: The sum of a specific column in a table or STable

**Return value type**: DOUBLE or BIGINT
734

735
**Applicable data types**: Numeric
736

737
**Applicable table types**: standard tables and supertables
738 739


740
### HYPERLOGLOG
741

742
```sql
G
Ganlin Zhao 已提交
743
HYPERLOGLOG(expr)
744
```
745

746 747 748 749 750
**Description**:
  The cardinal number of a specific column is returned by using hyperloglog algorithm. The benefit of using hyperloglog algorithm is that the memory usage is under control when the data volume is huge.
  However, when the data volume is very small, the result may be not accurate, it's recommented to use `select count(data) from (select unique(col) as data from table)` in this case.

**Return value type**: Integer
751

752
**Applicable data types**: Numeric
753

754
**Applicable table types**: standard tables and supertables
755 756


757
### HISTOGRAM
758

759
```sql
G
Ganlin Zhao 已提交
760
HISTOGRAM(expr,bin_type, bin_description, normalized)
761
```
762

763
**Description**:Returns count of data points in user-specified ranges.
764

765
**Return value type** If normalized is set to 1, a DOUBLE is returned; otherwise a BIGINT is returned
766

767
**Applicable data types**: Numeric
768

769
**Applicable table types**: table, STable
770

771
**Explanations**:
G
Ganlin Zhao 已提交
772
- bin_type: parameter to indicate the bucket type, valid inputs are: "user_input", "linear_bin", "log_bin"。
G
Ganlin Zhao 已提交
773 774
- 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]":
775
       User specified bin values.
G
Ganlin Zhao 已提交
776

777 778 779
    - "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].
G
Ganlin Zhao 已提交
780

781 782 783 784
    - "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 "linear_bin" descriptor generates a set of bins: [-inf, 1.0, 2.0, 4.0, 8.0, 16.0, +inf].
- normalized: setting to 1/0 to turn on/off result normalization. Valid values are 0 or 1.
785 786


G
Ganlin Zhao 已提交
787
### PERCENTILE
788

789
```sql
G
Ganlin Zhao 已提交
790
PERCENTILE(expr, p)
791
```
792

G
Ganlin Zhao 已提交
793
**Description**: The value whose rank in a specific column matches the specified percentage. If such a value matching the specified percentage doesn't exist in the column, an interpolation value will be returned.
794

795
**Return value type**: DOUBLE
796

797
**Applicable column types**: Numeric
798

799
**Applicable table types**: table only
800

G
Ganlin Zhao 已提交
801
**More explanations**: _p_ is in range [0,100], when _p_ is 0, the result is same as using function MIN; when _p_ is 100, the result is same as function MAX.
802 803


804 805 806
## Selection Functions

Selection functions return one or more results depending. You can specify the timestamp column, tbname pseudocolumn, or tag columns to show which rows contain the selected value.
807

808
### BOTTOM
809

810
```sql
G
Ganlin Zhao 已提交
811
BOTTOM(expr, k)
812 813
```

814
**Description**: The least _k_ values of a specific column in a table or STable. If a value has multiple occurrences in the column but counting all of them in will exceed the upper limit _k_, then a part of them will be returned randomly.
815

816
**Return value type**:Same as the data type of the column being operated upon
817

818
**Applicable data types**: Numeric
819

820
**Applicable table types**: standard tables and supertables
821

822
**More explanation**:
823

824 825 826
- _k_ must be in range [1,100]
- The timestamp associated with the selected values are returned too
- Can't be used with `FILL`
827

828
### FIRST
829

830
```sql
G
Ganlin Zhao 已提交
831
FIRST(expr)
832 833
```

834
**Description**: The first non-null value of a specific column in a table or STable
835

836
**Return value type**:Same as the data type of the column being operated upon
837

838
**Applicable data types**: Numeric
839

840
**Applicable table types**: standard tables and supertables
841

842
**More explanation**:
843

844 845 846
- FIRST(\*) can be used to get the first non-null value of all columns
- NULL will be returned if all the values of the specified column are all NULL
- A result will NOT be returned if all the columns in the result set are all NULL
847

848
### INTERP
849

850
```sql
G
Ganlin Zhao 已提交
851
INTERP(expr)
852 853
```

854
**Description**: The value that matches the specified timestamp range is returned, if existing; or an interpolation value is returned.
855

856
**Return value type**: Same as the column being operated upon
857

858
**Applicable data types**: Numeric
859

860
**Applicable table types**: standard tables and supertables
861

862
**More explanations**
863

864 865
- `INTERP` is used to get the value that matches the specified time slice from a column. If no such value exists an interpolation value will be returned based on `FILL` parameter.
- The input data of `INTERP` is the value of the specified column and a `where` clause can be used to filter the original data. If no `where` condition is specified then all original data is the input.
G
Ganlin Zhao 已提交
866 867 868
- The output time range of `INTERP` is specified by `RANGE(timestamp1,timestamp2)` parameter, with timestamp1<=timestamp2. timestamp1 is the starting point of the output time range and must be specified. timestamp2 is the ending point of the output time range and must be specified.
- The number of rows in the result set of `INTERP` is determined by the parameter `EVERY`. Starting from timestamp1, one interpolation is performed for every time interval specified `EVERY` parameter.
- Interpolation is performed based on `FILL` parameter.
G
Ganlin Zhao 已提交
869
- `INTERP` can only be used to interpolate in single timeline. So it must be used with `partition by tbname` when it's used on a STable.
G
Ganlin Zhao 已提交
870
- Pseudo column `_irowts` can be used along with `INTERP`to return the timestamps associated with interpolation points(support after version 3.0.1.4).
871

872
### LAST
873

874
```sql
G
Ganlin Zhao 已提交
875
LAST(expr)
876 877
```

878
**Description**: The last non-NULL value of a specific column in a table or STable
879

880
**Return value type**:Same as the data type of the column being operated upon
881

882
**Applicable data types**: Numeric
883

884
**Applicable table types**: standard tables and supertables
885

886
**More explanation**:
887

888 889 890
- LAST(\*) can be used to get the last non-NULL value of all columns
- If the values of a column in the result set are all NULL, NULL is returned for that column; if all columns in the result are all NULL, no result will be returned.
- When it's used on a STable, if there are multiple values with the timestamp in the result set, one of them will be returned randomly and it's not guaranteed that the same value is returned if the same query is run multiple times.
891

892

893
### LAST_ROW
894

895
```sql
G
Ganlin Zhao 已提交
896
LAST_ROW(expr)
897 898
```

899
**Description**: The last row of a table or STable
900

901
**Return value type**:Same as the data type of the column being operated upon
902

903
**Applicable data types**: Numeric
904

905
**Applicable table types**: standard tables and supertables
906 907 908

**More explanations**:

909 910
- When it's used on a STable, if there are multiple values with the timestamp in the result set, one of them will be returned randomly and it's not guaranteed that the same value is returned if the same query is run multiple times.
- Can't be used with `INTERVAL`.
911

912
### MAX
913

914
```sql
G
Ganlin Zhao 已提交
915
MAX(expr)
916 917
```

918 919 920
**Description**: The maximum value of a specific column of a table or STable

**Return value type**:Same as the data type of the column being operated upon
921

G
Ganlin Zhao 已提交
922
**Applicable data types**: Numeric
923

924
**Applicable table types**: standard tables and supertables
925 926


927
### MIN
928

929
```sql
G
Ganlin Zhao 已提交
930
MIN(expr)
931
```
932

933 934 935
**Description**: The minimum value of a specific column in a table or STable

**Return value type**:Same as the data type of the column being operated upon
936

G
Ganlin Zhao 已提交
937
**Applicable data types**: Numeric
938

939
**Applicable table types**: standard tables and supertables
940 941


G
Ganlin Zhao 已提交
942
### MODE
943

944
```sql
G
Ganlin Zhao 已提交
945
MODE(expr)
946
```
947

G
Ganlin Zhao 已提交
948
**Description**:The value which has the highest frequency of occurrence. NULL is returned if there are multiple values which have highest frequency of occurrence.
949

950
**Return value type**: Same as the input data
951

952 953 954
**Applicable data types**: Numeric

**Applicable table types**: standard tables and supertables
955 956


G
Ganlin Zhao 已提交
957 958 959
### SAMPLE

```sql
G
Ganlin Zhao 已提交
960
SAMPLE(expr, k)
G
Ganlin Zhao 已提交
961 962 963 964
```

**Description**: _k_ sampling values of a specific column. The applicable range of _k_ is [1,1000].

965
**Return value type**: Same as the column being operated plus the associated timestamp
G
Ganlin Zhao 已提交
966

967
**Applicable data types**: Any data type except for tags of STable
G
Ganlin Zhao 已提交
968

969
**Applicable nested query**: Inner query and Outer query
G
Ganlin Zhao 已提交
970

971
**Applicable table types**: standard tables and supertables
G
Ganlin Zhao 已提交
972

G
Ganlin Zhao 已提交
973
**More explanations**:
974 975 976

This function cannot be used in expression calculation.
- Must be used with `PARTITION BY tbname` when it's used on a STable to force the result on each single timeline
G
Ganlin Zhao 已提交
977

978

979
### TAIL
980

981
```sql
G
Ganlin Zhao 已提交
982
TAIL(expr, k, offset_val)
983 984
```

985
**Description**: The next _k_ rows are returned after skipping the last `offset_val` rows, NULL values are not ignored. `offset_val` is optional parameter. When it's not specified, the last _k_ rows are returned. When `offset_val` is used, the effect is same as `order by ts desc LIMIT k OFFSET offset_val`.
986

987 988 989
**Parameter value range**: k: [1,100] offset_val: [0,100]

**Return value type**:Same as the data type of the column being operated upon
990

991 992 993
**Applicable data types**: Any data type except for timestamp, i.e. the primary key

**Applicable table types**: standard tables and supertables
994 995


996
### TOP
997

998
```sql
G
Ganlin Zhao 已提交
999
TOP(expr, k)
1000 1001
```

1002
**Description**: The greatest _k_ values of a specific column in a table or STable. If a value has multiple occurrences in the column but counting all of them in will exceed the upper limit _k_, then a part of them will be returned randomly.
1003

1004
**Return value type**:Same as the data type of the column being operated upon
1005

1006
**Applicable data types**: Numeric
1007

1008
**Applicable table types**: standard tables and supertables
1009

1010
**More explanation**:
1011

1012 1013 1014
- _k_ must be in range [1,100]
- The timestamp associated with the selected values are returned too
- Can't be used with `FILL`
1015

1016
### UNIQUE
1017

1018
```sql
G
Ganlin Zhao 已提交
1019
UNIQUE(expr)
1020 1021
```

1022
**Description**: The values that occur the first time in the specified column. The effect is similar to `distinct` keyword, but it can also be used to match tags or timestamp. The first occurrence of a timestamp or tag is used.
1023

1024
**Return value type**:Same as the data type of the column being operated upon
1025

1026
**Applicable column types**: Any data types except for timestamp
1027

1028
**Applicable table types**: table, STable
1029 1030


1031
## Time-Series Extensions
1032

1033
TDengine includes extensions to standard SQL that are intended specifically for time-series use cases. The functions enabled by these extensions require complex queries to implement in general-purpose databases. By offering them as built-in extensions, TDengine reduces user workload.
1034

1035
### CSUM
1036

1037
```sql
G
Ganlin Zhao 已提交
1038
CSUM(expr)
1039 1040
```

1041
**Description**: The cumulative sum of each row for a specific column. The number of output rows is same as that of the input rows.
1042

1043
**Return value type**: Long integer for integers; Double for floating points. uint64_t for unsigned integers
1044

1045
**Applicable data types**: Numeric
1046

1047
**Nested query**: It can be used in both the outer query and inner query in a nested query.
1048

1049 1050
**Applicable table types**: standard tables and supertables

G
Ganlin Zhao 已提交
1051 1052
**More explanations**:

1053
- Arithmetic operation can't be performed on the result of `csum` function
G
Ganlin Zhao 已提交
1054
- Can only be used with aggregate functions This function can be used with supertables and standard tables.
1055
- Must be used with `PARTITION BY tbname` when it's used on a STable to force the result on each single timeline
1056 1057


1058
### DERIVATIVE
1059

1060
```sql
G
Ganlin Zhao 已提交
1061 1062 1063 1064 1065 1066
DERIVATIVE(expr, time_inerval, ignore_negative)

ignore_negative: {
    0
  | 1
}
1067 1068
```

1069
**Description**: The derivative of a specific column. The time rage can be specified by parameter `time_interval`, the minimum allowed time range is 1 second (1s); the value of `ignore_negative` can be 0 or 1, 1 means negative values are ignored.
1070

1071
**Return value type**: DOUBLE
1072

1073
**Applicable data types**: Numeric
1074

1075
**Applicable table types**: standard tables and supertables
1076

G
Ganlin Zhao 已提交
1077 1078
**More explanation**:

1079
- It can be used together with `PARTITION BY tbname` against a STable.
1080
- It can be used together with a selected column. For example: select \_rowts, DERIVATIVE() from。
1081

1082
### DIFF
1083

1084
```sql
G
Ganlin Zhao 已提交
1085 1086 1087 1088 1089 1090
DIFF(expr [, ignore_negative])

ignore_negative: {
    0
  | 1
}
1091 1092
```

1093
**Description**: The different of each row with its previous row for a specific column. `ignore_negative` can be specified as 0 or 1, the default value is 1 if it's not specified. `1` means negative values are ignored.
1094

1095
**Return value type**:Same as the data type of the column being operated upon
1096

1097
**Applicable data types**: Numeric
1098

1099
**Applicable table types**: standard tables and supertables
1100

G
Ganlin Zhao 已提交
1101
**More explanation**:
1102 1103 1104

- The number of result rows is the number of rows subtracted by one, no output for the first row
- It can be used together with a selected column. For example: select \_rowts, DIFF() from。
1105 1106


1107
### IRATE
1108

1109
```sql
G
Ganlin Zhao 已提交
1110
IRATE(expr)
1111 1112
```

1113
**Description**: instantaneous rate on a specific column. The last two samples in the specified time range are used to calculate instantaneous rate. If the last sample value is smaller, then only the last sample value is used instead of the difference between the last two sample values.
1114

1115
**Return value type**: DOUBLE
1116

1117
**Applicable data types**: Numeric
1118

1119
**Applicable table types**: standard tables and supertables
1120 1121


1122
### MAVG
1123

1124
```sql
G
Ganlin Zhao 已提交
1125
MAVG(expr, k)
1126 1127
```

1128
**Description**: The moving average of continuous _k_ values of a specific column. If the number of input rows is less than _k_, nothing is returned. The applicable range of _k_ is [1,1000].
1129

1130
**Return value type**: DOUBLE
1131

1132
**Applicable data types**: Numeric
1133

1134
**Nested query**: It can be used in both the outer query and inner query in a nested query.
1135

1136
**Applicable table types**: standard tables and supertables
1137

G
Ganlin Zhao 已提交
1138 1139 1140
**More explanations**:

- Arithmetic operation can't be performed on the result of `MAVG`.
1141 1142
- Can only be used with data columns, can't be used with tags. - Can't be used with aggregate functions.
- Must be used with `PARTITION BY tbname` when it's used on a STable to force the result on each single timeline
1143 1144 1145 1146


### STATECOUNT

1147
```sql
G
Ganlin Zhao 已提交
1148
STATECOUNT(expr, oper, val)
1149 1150
```

1151
**Description**: The number of continuous rows satisfying the specified conditions for a specific column. The result is shown as an extra column for each row. If the specified condition is evaluated as true, the number is increased by 1; otherwise the number is reset to -1. If the input value is NULL, then the corresponding row is skipped.
1152 1153 1154

**Applicable parameter values**:

S
Sean Ely 已提交
1155
- oper : Can be one of `'LT'` (lower than), `'GT'` (greater than), `'LE'` (lower than or equal to), `'GE'` (greater than or equal to), `'NE'` (not equal to), `'EQ'` (equal to), the value is case insensitive, the value must be in quotes.
1156
- val : Numeric types
1157

1158
**Return value type**: Integer
1159

1160
**Applicable data types**: Numeric
1161

1162
**Applicable nested query**: Outer query only
1163

1164
**Applicable table types**: standard tables and supertables
1165 1166 1167

**More explanations**:

1168 1169 1170
- Must be used together with `PARTITION BY tbname` when it's used on a STable to force the result into each single timeline]
- Can't be used with window operation, like interval/state_window/session_window

1171 1172 1173

### STATEDURATION

1174
```sql
G
Ganlin Zhao 已提交
1175
STATEDURATION(expr, oper, val, unit)
1176 1177
```

1178
**Description**: The length of time range in which all rows satisfy the specified condition for a specific column. The result is shown as an extra column for each row. The length for the first row that satisfies the condition is 0. Next, if the condition is evaluated as true for a row, the time interval between current row and its previous row is added up to the time range; otherwise the time range length is reset to -1. If the value of the column is NULL, the corresponding row is skipped.
1179 1180 1181

**Applicable parameter values**:

S
Sean Ely 已提交
1182
- oper : Can be one of `'LT'` (lower than), `'GT'` (greater than), `'LE'` (lower than or equal to), `'GE'` (greater than or equal to), `'NE'` (not equal to), `'EQ'` (equal to), the value is case insensitive, the value must be in quotes.
1183 1184
- val : Numeric types
- unit: The unit of time interval. Enter one of the following options: 1b (nanoseconds), 1u (microseconds), 1a (milliseconds), 1s (seconds), 1m (minutes), 1h (hours), 1d (days), or 1w (weeks) If you do not enter a unit of time, the precision of the current database is used by default.
1185

1186
**Return value type**: Integer
1187

1188
**Applicable data types**: Numeric
1189

1190
**Applicable nested query**: Outer query only
1191

1192
**Applicable table types**: standard tables and supertables
1193 1194 1195

**More explanations**:

1196 1197 1198
- Must be used together with `PARTITION BY tbname` when it's used on a STable to force the result into each single timeline]
- Can't be used with window operation, like interval/state_window/session_window

1199

1200
### TWA
1201

1202
```sql
G
Ganlin Zhao 已提交
1203
TWA(expr)
1204 1205
```

1206
**Description**: Time weighted average on a specific column within a time range
1207

1208
**Return value type**: DOUBLE
1209

1210
**Applicable data types**: Numeric
1211

1212
**Applicable table types**: standard tables and supertables
1213

1214
- Must be used together with `PARTITION BY tbname` to force the result into each single timeline.
1215 1216


1217
## System Information Functions
1218

1219
### DATABASE
1220

1221
```sql
1222
SELECT DATABASE();
1223 1224
```

1225 1226
**Description**: The current database. If no database is specified upon logging in and no database is specified with `USE` after login, NULL will be returned by `select database()`.

1227

1228
### CLIENT_VERSION
1229

1230
```sql
1231
SELECT CLIENT_VERSION();
1232 1233
```

1234
**Description**: The client version.
1235

1236
### SERVER_VERSION
1237

1238
```sql
1239
SELECT SERVER_VERSION();
1240 1241
```

1242
**Description**: The server version.
1243

1244
### SERVER_STATUS
1245

1246
```sql
S
Sean Ely 已提交
1247
SELECT SERVER_STATUS();
1248 1249
```

1250
**Description**: The server status.