help.csv 166.9 KB
Newer Older
1
# Copyright 2004-2018 H2 Group. Multiple-Licensed under the MPL 2.0,
2
# and the EPL 1.0 (http://h2database.com/html/license.html).
Thomas Mueller's avatar
Thomas Mueller committed
3 4 5
# Initial Developer: H2 Group
"SECTION","TOPIC","SYNTAX","TEXT","EXAMPLE"
"Commands (DML)","SELECT","
6
SELECT [ TOP term [ PERCENT ] [ WITH TIES ] ]
7
[ DISTINCT [ ON ( expression [,...] ) ] | ALL ]
8
selectExpression [,...]
9 10
FROM tableExpression [,...] [ WHERE expression ]
[ GROUP BY expression [,...] ] [ HAVING expression ]
11
[ WINDOW { { windowName AS windowSpecification } [,...] } ]
12 13
[ { UNION [ ALL ] | MINUS | EXCEPT | INTERSECT } select ]
[ ORDER BY order [,...] ]
14 15
[ LIMIT expression [ OFFSET expression ] [ SAMPLE_SIZE rowCountInt ] ]
[ [ OFFSET expression { ROW | ROWS } ]
16
    [ FETCH { FIRST | NEXT } [ expression [ PERCENT ] ] { ROW | ROWS }
17
        { ONLY | WITH TIES } ] [ SAMPLE_SIZE rowCountInt ] ]
18
[ FOR UPDATE ]
Thomas Mueller's avatar
Thomas Mueller committed
19 20
","
Selects data from a table or multiple tables.
21
GROUP BY groups the the result by the given expression(s).
22
HAVING filters rows after grouping.
23 24
ORDER BY sorts the result by the given column(s) or expression(s).
UNION combines the result of this query with the results of another query.
Thomas Mueller's avatar
Thomas Mueller committed
25

26 27 28
Number of rows in output can be limited either with standard OFFSET / FETCH,
with non-standard LIMIT / OFFSET, or with non-standard TOP clauses.
Different clauses cannot be used together.
29
FETCH FIRST/NEXT, LIMIT or TOP limits the number of rows returned by the query (no limit if null or smaller than zero).
30 31 32 33 34 35
If PERCENT is specified number of rows is specified as a percent of the total number of rows
and should be an integer value between 0 and 100 inclusive.
WITH TIES can be used only together with ORDER BY and means that all additional rows that have the same sorting position
as the last row will be also returned.
OFFSET specifies how many rows to skip.
Please note that queries with high offset values can be slow.
36
SAMPLE_SIZE limits the number of rows read for aggregate queries.
37

Owner's avatar
Owner committed
38
Multiple set operators (UNION, INTERSECT, MINUS, EXCEPT) are evaluated
39 40 41
from left to right. For compatibility with other databases and future versions
of H2 please use parentheses.

42 43 44 45
If FOR UPDATE is specified, the tables or rows are locked for writing.
This clause is not allowed in DISTINCT queries and in queries with non-window aggregates, GROUP BY, or HAVING clauses.
When using default MVStore engine only the selected rows are locked as in an UPDATE statement.
With PageStore engine the whole tables are locked.
Thomas Mueller's avatar
Thomas Mueller committed
46 47
","
SELECT * FROM TEST;
48 49 50 51
SELECT * FROM TEST ORDER BY NAME;
SELECT ID, COUNT(*) FROM TEST GROUP BY ID;
SELECT NAME, COUNT(*) FROM TEST GROUP BY NAME HAVING COUNT(*) > 2;
SELECT 'ID' COL, MAX(ID) AS MAX FROM TEST UNION SELECT 'NAME', MAX(NAME) FROM TEST;
52 53
SELECT * FROM TEST OFFSET 1000 ROWS FETCH FIRST 1000 ROWS ONLY;
SELECT A, B FROM TEST ORDER BY A FETCH FIRST 10 ROWS WITH TIES;
Thomas Mueller's avatar
Thomas Mueller committed
54 55 56
SELECT * FROM (SELECT ID, COUNT(*) FROM TEST
    GROUP BY ID UNION SELECT NULL, COUNT(*) FROM TEST)
    ORDER BY 1 NULLS LAST;
57 58
SELECT DISTINCT C1, C2 FROM TEST;
SELECT DISTINCT ON(C1) C1, C2 FROM TEST ORDER BY C1;
Thomas Mueller's avatar
Thomas Mueller committed
59 60 61
"

"Commands (DML)","INSERT","
62
INSERT INTO tableName insertColumnsAndSource
Thomas Mueller's avatar
Thomas Mueller committed
63 64
","
Inserts a new row / new rows into a table.
65 66 67 68

When using DIRECT, then the results from the query are directly applied in the target table without any intermediate step.

When using SORTED, b-tree pages are split at the insertion point. This can improve performance and reduce disk usage.
Thomas Mueller's avatar
Thomas Mueller committed
69 70 71 72 73
","
INSERT INTO TEST VALUES(1, 'Hello')
"

"Commands (DML)","UPDATE","
74
UPDATE tableName [ [ AS ] newTableAlias ] SET setClauseList
75
[ WHERE expression ] [ ORDER BY order [,...] ] [ LIMIT expression ]
Thomas Mueller's avatar
Thomas Mueller committed
76 77
","
Updates data in a table.
78
ORDER BY is supported for MySQL compatibility, but it is ignored.
Thomas Mueller's avatar
Thomas Mueller committed
79
","
80 81
UPDATE TEST SET NAME='Hi' WHERE ID=1;
UPDATE PERSON P SET NAME=(SELECT A.NAME FROM ADDRESS A WHERE A.ID=P.ID);
Thomas Mueller's avatar
Thomas Mueller committed
82 83 84
"

"Commands (DML)","DELETE","
85
DELETE [ TOP term ] FROM tableName [ WHERE expression ] [ LIMIT term ]
Thomas Mueller's avatar
Thomas Mueller committed
86 87
","
Deletes rows form a table.
88
If TOP or LIMIT is specified, at most the specified number of rows are deleted (no limit if null or smaller than zero).
Thomas Mueller's avatar
Thomas Mueller committed
89 90 91 92 93 94 95
","
DELETE FROM TEST WHERE ID=2
"

"Commands (DML)","BACKUP","
BACKUP TO fileNameString
","
Thomas Mueller's avatar
Thomas Mueller committed
96 97
Backs up the database files to a .zip file. Objects are not locked, but
the backup is transactionally consistent because the transaction log is also copied.
Thomas Mueller's avatar
Thomas Mueller committed
98
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
99 100 101 102 103 104 105
","
BACKUP TO 'backup.zip'
"

"Commands (DML)","CALL","
CALL expression
","
Thomas Mueller's avatar
Thomas Mueller committed
106 107 108
Calculates a simple expression. This statement returns a result set with one row,
except if the called function returns a result set itself.
If the called function returns an array, then each element in this array is returned as a column.
Thomas Mueller's avatar
Thomas Mueller committed
109 110 111 112 113
","
CALL 15*25
"

"Commands (DML)","EXPLAIN","
114 115
EXPLAIN { [ PLAN FOR ] | ANALYZE }
{ select | insert | update | delete | merge }
Thomas Mueller's avatar
Thomas Mueller committed
116 117
","
Shows the execution plan for a statement.
118 119
When using EXPLAIN ANALYZE, the statement is actually executed, and the query plan
will include the actual row scan count for each table.
Thomas Mueller's avatar
Thomas Mueller committed
120 121 122 123 124
","
EXPLAIN SELECT * FROM TEST WHERE ID=1
"

"Commands (DML)","MERGE","
125 126
MERGE INTO tableName [ ( columnName [,...] ) ]
[ KEY ( columnName [,...] ) ]
127
{ VALUES { ( { DEFAULT | expression } [,...] ) } [,...] | select }
Thomas Mueller's avatar
Thomas Mueller committed
128 129 130
","
Updates existing rows, and insert rows that don't exist. If no key column is
specified, the primary key columns are used to find the row. If more than one
131
row per new row is affected, an exception is thrown.
Thomas Mueller's avatar
Thomas Mueller committed
132 133 134 135
","
MERGE INTO TEST KEY(ID) VALUES(2, 'World')
"

Owner's avatar
Owner committed
136
"Commands (DML)","MERGE USING","
137 138
MERGE INTO targetTableName [ [AS] targetAlias]
USING { ( select ) | sourceTableName }[ [AS] sourceAlias ]
139
ON expression
140 141 142 143 144 145 146 147
mergeWhenClause [,...]
","
Updates or deletes existing rows, and insert rows that don't exist.

The ON clause specifies the matching column expression.
Different rows from a source table may not match with the same target row,
but one source row may be matched with multiple target rows.

148
If statement doesn't need a source table a DUAL table can be substituted.
Owner's avatar
Owner committed
149
","
150
MERGE INTO TARGET_TABLE AS T USING SOURCE_TABLE AS S
151
    ON T.ID = S.ID
152 153 154 155
    WHEN MATCHED AND T.COL2 <> 'FINAL' THEN
        UPDATE SET T.COL1 = S.COL1
    WHEN MATCHED AND T.COL2 = 'FINAL' THEN
        DELETE
156
    WHEN NOT MATCHED THEN
157
        INSERT (ID, COL1, COL2) VALUES(S.ID, S.COL1, S.COL2)
158
MERGE INTO TARGET_TABLE AS T USING (SELECT * FROM SOURCE_TABLE) AS S
159
    ON T.ID = S.ID
160 161 162 163
    WHEN MATCHED AND T.COL2 <> 'FINAL' THEN
        UPDATE SET T.COL1 = S.COL1
    WHEN MATCHED AND T.COL2 = 'FINAL' THEN
        DELETE
164
    WHEN NOT MATCHED THEN
165
        INSERT VALUES (S.ID, S.COL1, S.COL2)
166
MERGE INTO TARGET_TABLE USING DUAL ON ID = 1
167
    WHEN NOT MATCHED THEN INSERT VALUES (1, 'Test')
168
    WHEN MATCHED THEN UPDATE SET NAME = 'Test'
Owner's avatar
Owner committed
169 170
"

Thomas Mueller's avatar
Thomas Mueller committed
171
"Commands (DML)","RUNSCRIPT","
172 173
RUNSCRIPT FROM fileNameString scriptCompressionEncryption
[ CHARSET charsetString ]
Thomas Mueller's avatar
Thomas Mueller committed
174 175 176 177 178 179
","
Runs a SQL script from a file. The script is a text file containing SQL
statements; each statement must end with ';'. This command can be used to
restore a database from a backup. The password must be in single quotes; it is
case sensitive and can contain spaces.

180
Instead of a file name, an URL may be used.
181
To read a stream from the classpath, use the prefix 'classpath:'.
182
See the Pluggable File System section on the Advanced page.
183

184
The compression algorithm must match the one used when creating the script.
Thomas Mueller's avatar
Thomas Mueller committed
185 186 187
Instead of a file, an URL may be used.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
188
","
189
RUNSCRIPT FROM 'backup.sql'
190
RUNSCRIPT FROM 'classpath:/com/acme/test.sql'
Thomas Mueller's avatar
Thomas Mueller committed
191 192 193
"

"Commands (DML)","SCRIPT","
194 195
SCRIPT [ SIMPLE ] [ NODATA ] [ NOPASSWORDS ] [ NOSETTINGS ]
[ DROP ] [ BLOCKSIZE blockSizeInt ]
196
[ TO fileNameString scriptCompressionEncryption
197
    [ CHARSET charsetString ] ]
198 199
[ TABLE tableName [, ...] ]
[ SCHEMA schemaName [, ...] ]
Thomas Mueller's avatar
Thomas Mueller committed
200
","
201 202 203 204 205 206 207
Creates a SQL script from the database.

SIMPLE does not use multi-row insert statements.
NODATA will not emit INSERT statements.
If the DROP option is specified, drop statements are created for tables, views,
and sequences. If the block size is set, CLOB and BLOB values larger than this
size are split into separate blocks.
Thomas Mueller's avatar
Thomas Mueller committed
208 209
BLOCKSIZE is used when writing out LOB data, and specifies the point at the
values transition from being inserted as inline values, to be inserted using
210
out-of-line commands.
Thomas Mueller's avatar
Thomas Mueller committed
211
NOSETTINGS turns off dumping the database settings (the SET XXX commands)
212

213
If no 'TO fileName' clause is specified, the
Thomas Mueller's avatar
Thomas Mueller committed
214 215 216 217
script is returned as a result set. This command can be used to create a backup
of the database. For long term storage, it is more portable than copying the
database files.

218
If a 'TO fileName' clause is specified, then the whole
Thomas Mueller's avatar
Thomas Mueller committed
219
script (including insert statements) is written to this file, and a result set
220
without the insert statements is returned.
Thomas Mueller's avatar
Thomas Mueller committed
221

Thomas Mueller's avatar
Thomas Mueller committed
222 223 224
The password must be in single quotes; it is case sensitive and can contain spaces.

This command locks objects while it is running.
Thomas Mueller's avatar
Thomas Mueller committed
225
Admin rights are required to execute this command.
226

227
When using the TABLE or SCHEMA option, only the selected table(s) / schema(s) are included.
Thomas Mueller's avatar
Thomas Mueller committed
228 229 230 231 232
","
SCRIPT NODATA
"

"Commands (DML)","SHOW","
233 234
SHOW { SCHEMAS | TABLES [ FROM schemaName ] |
    COLUMNS FROM tableName [ FROM schemaName ] }
Thomas Mueller's avatar
Thomas Mueller committed
235 236 237 238 239 240
","
Lists the schemas, tables, or the columns of a table.
","
SHOW TABLES
"

241
"Commands (DML)","WITH","
242 243
WITH [ RECURSIVE ] { name [( columnName [,...] )] AS ( select ) [,...] }
{ select | insert | update | merge | delete | createTable }
244
","
245
Can be used to create a recursive or non-recursive query (common table expression).
246
For recursive queries the first select has to be a UNION.
247
One or more common table entries can be referred to by name.
248
Column name declarations are now optional - the column names will be inferred from the named select queries.
249
The final action in a WITH statement can be a select, insert, update, merge, delete or create table.
250
","
251
WITH RECURSIVE cte(n) AS (
252 253 254
        SELECT 1
    UNION ALL
        SELECT n + 1
255
        FROM cte
256 257
        WHERE n < 100
)
258 259 260 261
SELECT sum(n) FROM cte;

Example 2:
WITH cte1 AS (
262
        SELECT 1 AS FIRST_COLUMN
263 264
), cte2 AS (
        SELECT FIRST_COLUMN+1 AS FIRST_COLUMN FROM cte1
265
)
266
SELECT sum(FIRST_COLUMN) FROM cte2;
267 268
"

Thomas Mueller's avatar
Thomas Mueller committed
269
"Commands (DDL)","ALTER INDEX RENAME","
270
ALTER INDEX [ IF EXISTS ] indexName RENAME TO newIndexName
Thomas Mueller's avatar
Thomas Mueller committed
271
","
Thomas Mueller's avatar
Thomas Mueller committed
272
Renames an index.
Thomas Mueller's avatar
Thomas Mueller committed
273
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
274 275 276 277
","
ALTER INDEX IDXNAME RENAME TO IDX_TEST_NAME
"

278
"Commands (DDL)","ALTER SCHEMA RENAME","
279
ALTER SCHEMA [ IF EXISTS ] schema RENAME TO newSchemaName
280 281
","
Renames a schema.
Thomas Mueller's avatar
Thomas Mueller committed
282
This command commits an open transaction in this connection.
283 284 285 286
","
ALTER SCHEMA TEST RENAME TO PRODUCTION
"

Thomas Mueller's avatar
Thomas Mueller committed
287
"Commands (DDL)","ALTER SEQUENCE","
288 289 290
ALTER SEQUENCE [ IF EXISTS ] sequenceName
[ RESTART WITH long ]
[ INCREMENT BY long ]
291 292
[ MINVALUE long | NOMINVALUE | NO MINVALUE ]
[ MAXVALUE long | NOMAXVALUE | NO MAXVALUE ]
293 294
[ CYCLE long | NOCYCLE | NO CYCLE ]
[ CACHE long | NOCACHE | NO CACHE ]
Thomas Mueller's avatar
Thomas Mueller committed
295
","
296
Changes the parameters of a sequence.
Thomas Mueller's avatar
Thomas Mueller committed
297
This command does not commit the current transaction; however the new value is used by other
Thomas Mueller's avatar
Thomas Mueller committed
298 299 300 301 302 303
transactions immediately, and rolling back this command has no effect.
","
ALTER SEQUENCE SEQ_ID RESTART WITH 1000
"

"Commands (DDL)","ALTER TABLE ADD","
304
ALTER TABLE [ IF EXISTS ] tableName ADD [ COLUMN ]
305 306
{ [ IF NOT EXISTS ] columnName columnDefinition
    | ( { columnName columnDefinition | constraint } [,...] ) }
307
[ { { BEFORE | AFTER } columnName } | FIRST ]
Thomas Mueller's avatar
Thomas Mueller committed
308
","
Thomas Mueller's avatar
Thomas Mueller committed
309
Adds a new column to a table.
Thomas Mueller's avatar
Thomas Mueller committed
310
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
311 312 313 314 315
","
ALTER TABLE TEST ADD CREATEDATE TIMESTAMP
"

"Commands (DDL)","ALTER TABLE ADD CONSTRAINT","
316
ALTER TABLE [ IF EXISTS ] tableName ADD constraint [ CHECK | NOCHECK ]
Thomas Mueller's avatar
Thomas Mueller committed
317 318 319
","
Adds a constraint to a table. If NOCHECK is specified, existing rows are not
checked for consistency (the default is to check consistency for existing rows).
Thomas Mueller's avatar
Thomas Mueller committed
320
The required indexes are automatically created if they don't exist yet.
Thomas Mueller's avatar
Thomas Mueller committed
321
It is not possible to disable checking for unique constraints.
Thomas Mueller's avatar
Thomas Mueller committed
322
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
323 324 325 326
","
ALTER TABLE TEST ADD CONSTRAINT NAME_UNIQUE UNIQUE(NAME)
"

327
"Commands (DDL)","ALTER TABLE RENAME CONSTRAINT","
328 329
ALTER TABLE [ IF EXISTS ] tableName RENAME oldConstraintName
TO newConstraintName
330 331 332 333 334 335 336
","
Renames a constraint.
This command commits an open transaction in this connection.
","
ALTER TABLE TEST RENAME CONSTRAINT FOO TO BAR
"

337
"Commands (DDL)","ALTER TABLE ALTER COLUMN","
338
ALTER TABLE [ IF EXISTS ] tableName ALTER COLUMN columnName
339
{ { columnDefinition }
340 341 342 343
    | { RENAME TO name }
    | { RESTART WITH long }
    | { SELECTIVITY int }
    | { SET DEFAULT expression }
344
    | { SET ON UPDATE expression }
345
    | { SET NULL }
346
    | { SET NOT NULL }
347 348
    | { SET { VISIBLE | INVISIBLE } }
    | { DROP { DEFAULT | ON UPDATE } } }
Thomas Mueller's avatar
Thomas Mueller committed
349
","
350 351
Changes the data type of a column, rename a column,
change the identity value, or change the selectivity.
Thomas Mueller's avatar
Thomas Mueller committed
352

353
Changing the data type fails if the data can not be converted.
Thomas Mueller's avatar
Thomas Mueller committed
354

355 356 357
RESTART changes the next value of an auto increment column.
The column must already be an auto increment column.
For RESTART, the same transactional rules as for ALTER SEQUENCE apply.
Thomas Mueller's avatar
Thomas Mueller committed
358

359 360 361 362
SELECTIVITY sets the selectivity (1-100) for a column.
Setting the selectivity to 0 means the default value.
Selectivity is used by the cost based optimizer to calculate the estimated cost of an index.
Selectivity 100 means values are unique, 10 means every distinct value appears 10 times on average.
Thomas Mueller's avatar
Thomas Mueller committed
363

364
SET DEFAULT changes the default value of a column.
Thomas Mueller's avatar
Thomas Mueller committed
365

366 367
SET ON UPDATE changes the value that is set on update if value for this column is not specified in update statement.

368
SET NULL sets a column to allow NULL. The row may not be part of a primary key.
Thomas Mueller's avatar
Thomas Mueller committed
369
Single column indexes on this column are dropped.
370 371 372

SET NOT NULL sets a column to not allow NULL. Rows may not contains NULL in this column.

373 374 375
SET INVISIBLE makes the column hidden, i.e. it will not appear in SELECT * results.
SET VISIBLE has the reverse effect.

376 377 378 379
DROP DEFAULT removes the default value of a column.

DROP ON UPDATE removes the value that is set on update of a column.

Thomas Mueller's avatar
Thomas Mueller committed
380
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
381
","
382 383 384 385 386 387 388
ALTER TABLE TEST ALTER COLUMN NAME CLOB;
ALTER TABLE TEST ALTER COLUMN NAME RENAME TO TEXT;
ALTER TABLE TEST ALTER COLUMN ID RESTART WITH 10000;
ALTER TABLE TEST ALTER COLUMN NAME SELECTIVITY 100;
ALTER TABLE TEST ALTER COLUMN NAME SET DEFAULT '';
ALTER TABLE TEST ALTER COLUMN NAME SET NOT NULL;
ALTER TABLE TEST ALTER COLUMN NAME SET NULL;
389 390
ALTER TABLE TEST ALTER COLUMN NAME SET VISIBLE;
ALTER TABLE TEST ALTER COLUMN NAME SET INVISIBLE;
Thomas Mueller's avatar
Thomas Mueller committed
391 392 393
"

"Commands (DDL)","ALTER TABLE DROP COLUMN","
394
ALTER TABLE [ IF EXISTS ] tableName DROP COLUMN [ IF EXISTS ]
395
columnName [,...] | ( columnName [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
396
","
397
Removes column(s) from a table.
Thomas Mueller's avatar
Thomas Mueller committed
398
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
399 400
","
ALTER TABLE TEST DROP COLUMN NAME
401
ALTER TABLE TEST DROP COLUMN NAME1, NAME2
402
ALTER TABLE TEST DROP COLUMN (NAME1, NAME2)
Thomas Mueller's avatar
Thomas Mueller committed
403 404 405
"

"Commands (DDL)","ALTER TABLE DROP CONSTRAINT","
406 407
ALTER TABLE [ IF EXISTS ] tableName DROP
{ CONSTRAINT [ IF EXISTS ] constraintName | PRIMARY KEY }
Thomas Mueller's avatar
Thomas Mueller committed
408 409
","
Removes a constraint or a primary key from a table.
Thomas Mueller's avatar
Thomas Mueller committed
410
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
411 412 413 414 415
","
ALTER TABLE TEST DROP CONSTRAINT UNIQUE_NAME
"

"Commands (DDL)","ALTER TABLE SET","
416
ALTER TABLE [ IF EXISTS ] tableName SET REFERENTIAL_INTEGRITY
417
{ FALSE | TRUE } [ CHECK | NOCHECK ]
Thomas Mueller's avatar
Thomas Mueller committed
418 419 420 421 422 423
","
Disables or enables referential integrity checking for a table. This command can
be used inside a transaction. Enabling referential integrity does not check
existing data, except if CHECK is specified. Use SET REFERENTIAL_INTEGRITY to
disable it for all tables; the global flag and the flag for each table are
independent.
424

Thomas Mueller's avatar
Thomas Mueller committed
425
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
426 427 428 429 430
","
ALTER TABLE TEST SET REFERENTIAL_INTEGRITY FALSE
"

"Commands (DDL)","ALTER TABLE RENAME","
431
ALTER TABLE [ IF EXISTS ] tableName RENAME TO newName
Thomas Mueller's avatar
Thomas Mueller committed
432
","
Thomas Mueller's avatar
Thomas Mueller committed
433
Renames a table.
Thomas Mueller's avatar
Thomas Mueller committed
434
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
435 436 437 438 439
","
ALTER TABLE TEST RENAME TO MY_DATA
"

"Commands (DDL)","ALTER USER ADMIN","
440
ALTER USER userName ADMIN { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
441
","
Thomas Mueller's avatar
Thomas Mueller committed
442 443 444 445
Switches the admin flag of a user on or off.

Only unquoted or uppercase user names are allowed.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
446
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
447 448 449 450 451 452 453
","
ALTER USER TOM ADMIN TRUE
"

"Commands (DDL)","ALTER USER RENAME","
ALTER USER userName RENAME TO newUserName
","
Thomas Mueller's avatar
Thomas Mueller committed
454 455 456 457
Renames a user.
After renaming a user, the password becomes invalid and needs to be changed as well.

Only unquoted or uppercase user names are allowed.
Thomas Mueller's avatar
Thomas Mueller committed
458
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
459
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
460 461 462 463 464
","
ALTER USER TOM RENAME TO THOMAS
"

"Commands (DDL)","ALTER USER SET PASSWORD","
465
ALTER USER userName SET { PASSWORD string | SALT bytes HASH bytes }
Thomas Mueller's avatar
Thomas Mueller committed
466
","
Thomas Mueller's avatar
Thomas Mueller committed
467 468 469 470 471 472
Changes the password of a user.
Only unquoted or uppercase user names are allowed.
The password must be enclosed in single quotes. It is case sensitive
and can contain spaces. The salt and hash values are hex strings.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
473
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
474 475 476 477
","
ALTER USER SA SET PASSWORD 'rioyxlgt'
"

478
"Commands (DDL)","ALTER VIEW RECOMPILE","
479
ALTER VIEW [ IF EXISTS ] viewName RECOMPILE
Thomas Mueller's avatar
Thomas Mueller committed
480 481
","
Recompiles a view after the underlying tables have been changed or created.
Thomas Mueller's avatar
Thomas Mueller committed
482
This command is used for views created using CREATE FORCE VIEW.
Thomas Mueller's avatar
Thomas Mueller committed
483
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
484 485 486 487
","
ALTER VIEW ADDRESS_VIEW RECOMPILE
"

488 489 490 491 492 493 494 495 496
"Commands (DDL)","ALTER VIEW RENAME","
ALTER VIEW [ IF EXISTS ] viewName RENAME TO newName
","
Renames a view.
This command commits an open transaction in this connection.
","
ALTER VIEW TEST RENAME TO MY_VIEW
"

Thomas Mueller's avatar
Thomas Mueller committed
497
"Commands (DDL)","ANALYZE","
498
ANALYZE [ TABLE tableName ] [ SAMPLE_SIZE rowCountInt ]
Thomas Mueller's avatar
Thomas Mueller committed
499
","
500 501 502
Updates the selectivity statistics of tables.
If no table name is given, all tables are analyzed.
The selectivity is used by the
Thomas Mueller's avatar
Thomas Mueller committed
503 504 505 506 507
cost based optimizer to select the best index for a given query. If no sample
size is set, up to 10000 rows per table are read. The value 0 means all rows are
read. The selectivity can be set manually using ALTER TABLE ALTER COLUMN
SELECTIVITY. Manual values are overwritten by this statement. The selectivity is
available in the INFORMATION_SCHEMA.COLUMNS table.
508

Thomas Mueller's avatar
Thomas Mueller committed
509
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
510 511 512 513 514
","
ANALYZE SAMPLE_SIZE 1000
"

"Commands (DDL)","COMMENT","
515 516 517 518 519
COMMENT ON
{ { COLUMN [ schemaName. ] tableName.columnName }
    | { { TABLE | VIEW | CONSTANT | CONSTRAINT | ALIAS | INDEX | ROLE
    | SCHEMA | SEQUENCE | TRIGGER | USER | DOMAIN } [ schemaName. ] objectName } }
IS expression
Thomas Mueller's avatar
Thomas Mueller committed
520
","
Thomas Mueller's avatar
Thomas Mueller committed
521 522 523
Sets the comment of a database object. Use NULL to remove the comment.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
524
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
525 526 527 528 529
","
COMMENT ON TABLE TEST IS 'Table used for testing'
"

"Commands (DDL)","CREATE AGGREGATE","
530
CREATE AGGREGATE [ IF NOT EXISTS ] newAggregateName FOR className
Thomas Mueller's avatar
Thomas Mueller committed
531 532 533
","
Creates a new user-defined aggregate function. The method name must be the full
qualified class name. The class must implement the interface
534
""org.h2.api.Aggregate"" or ""org.h2.api.AggregateFunction"".
Thomas Mueller's avatar
Thomas Mueller committed
535 536

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
537
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
538
","
539
CREATE AGGREGATE SIMPLE_MEDIAN FOR ""com.acme.db.Median""
Thomas Mueller's avatar
Thomas Mueller committed
540 541 542
"

"Commands (DDL)","CREATE ALIAS","
Thomas Mueller's avatar
Thomas Mueller committed
543
CREATE ALIAS [ IF NOT EXISTS ] newFunctionAliasName [ DETERMINISTIC ]
Thomas Mueller's avatar
Thomas Mueller committed
544
[ NOBUFFER ] { FOR classAndMethodName | AS sourceCodeString }
Thomas Mueller's avatar
Thomas Mueller committed
545
","
546 547 548 549 550 551
Creates a new function alias. If this is a ResultSet returning function,
by default the return value is cached in a local temporary file.

NOBUFFER - disables caching of ResultSet return value to temporary file.

DETERMINISTIC - Deterministic functions must always return the same value for the same parameters.
552 553 554

The method name must be the full qualified class and method name,
and may optionally include the parameter classes as in
555
""java.lang.Integer.parseInt(java.lang.String, int)"". The class and the method
556
must both be public, and the method must be static. The class must be available
557
in the classpath of the database engine (when using the server mode,
558
it must be in the classpath of the server).
Thomas Mueller's avatar
Thomas Mueller committed
559

560 561
When defining a function alias with source code, the Sun ""javac"" is compiler
is used if the file ""tools.jar"" is in the classpath. If not, ""javac"" is run as a separate process.
562 563
Only the source code is stored in the database; the class is compiled each time
the database is re-opened. Source code is usually passed
564 565
as dollar quoted text to avoid escaping problems. If import statements are used,
then the tag @CODE must be added before the method.
566

567
If the method throws an SQLException, it is directly re-thrown to the calling application;
Thomas Mueller's avatar
Thomas Mueller committed
568 569
all other exceptions are first converted to a SQLException.

570
If the first parameter of the Java function is a ""java.sql.Connection"", then a
Thomas Mueller's avatar
Thomas Mueller committed
571 572 573
connection to the database is provided. This connection must not be closed.
If the class contains multiple methods with the given name but different
parameter count, all methods are mapped.
574

Thomas Mueller's avatar
Thomas Mueller committed
575
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
576
This command commits an open transaction in this connection.
577 578

If you have the Groovy jar in your classpath, it is also possible to write methods using Groovy.
Thomas Mueller's avatar
Thomas Mueller committed
579 580 581 582 583
","
CREATE ALIAS MY_SQRT FOR ""java.lang.Math.sqrt"";
CREATE ALIAS GET_SYSTEM_PROPERTY FOR ""java.lang.System.getProperty"";
CALL GET_SYSTEM_PROPERTY('java.class.path');
CALL GET_SYSTEM_PROPERTY('com.acme.test', 'true');
584 585
CREATE ALIAS REVERSE AS $$ String reverse(String s) { return new StringBuilder(s).reverse().toString(); } $$;
CALL REVERSE('Test');
586 587 588 589 590
CREATE ALIAS tr AS $$@groovy.transform.CompileStatic
    static String tr(String str, String sourceSet, String replacementSet){
        return str.tr(sourceSet, replacementSet);
    }
$$
Thomas Mueller's avatar
Thomas Mueller committed
591 592 593
"

"Commands (DDL)","CREATE CONSTANT","
594
CREATE CONSTANT [ IF NOT EXISTS ] newConstantName VALUE expression
Thomas Mueller's avatar
Thomas Mueller committed
595
","
Thomas Mueller's avatar
Thomas Mueller committed
596
Creates a new constant.
Thomas Mueller's avatar
Thomas Mueller committed
597
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
598 599 600 601 602
","
CREATE CONSTANT ONE VALUE 1
"

"Commands (DDL)","CREATE DOMAIN","
603 604 605
CREATE DOMAIN [ IF NOT EXISTS ] newDomainName AS dataType
[ DEFAULT expression ] [ [ NOT ] NULL ] [ SELECTIVITY selectivity ]
[ CHECK condition ]
Thomas Mueller's avatar
Thomas Mueller committed
606 607
","
Creates a new data type (domain). The check condition must evaluate to true or
Thomas Mueller's avatar
Thomas Mueller committed
608
to NULL (to prevent NULL, use ""NOT NULL""). In the condition, the term VALUE refers
Thomas Mueller's avatar
Thomas Mueller committed
609
to the value being tested.
610

Thomas Mueller's avatar
Thomas Mueller committed
611 612
Domains are usable within the whole database. They can not be created in a specific schema.

Thomas Mueller's avatar
Thomas Mueller committed
613
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
614 615 616 617 618
","
CREATE DOMAIN EMAIL AS VARCHAR(255) CHECK (POSITION('@', VALUE) > 1)
"

"Commands (DDL)","CREATE INDEX","
619
CREATE
Thomas Mueller's avatar
Thomas Mueller committed
620
{ [ UNIQUE ] [ HASH | SPATIAL] INDEX [ [ IF NOT EXISTS ] newIndexName ]
621 622
    | PRIMARY KEY [ HASH ] }
ON tableName ( indexColumn [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
623
","
Thomas Mueller's avatar
Thomas Mueller committed
624
Creates a new index.
Thomas Mueller's avatar
Thomas Mueller committed
625
This command commits an open transaction in this connection.
626

Thomas Mueller's avatar
Thomas Mueller committed
627
Hash indexes are meant for in-memory databases and memory tables (CREATE MEMORY TABLE).
628 629
For other tables, or if the index contains multiple columns, the HASH keyword is ignored.
Hash indexes can only test for equality, and do not support range queries (similar to a hash table).
Thomas Mueller's avatar
Thomas Mueller committed
630
Non-unique keys are supported.
631
Spatial indexes are supported only on Geometry columns.
Thomas Mueller's avatar
Thomas Mueller committed
632 633 634 635 636
","
CREATE INDEX IDXNAME ON TEST(NAME)
"

"Commands (DDL)","CREATE LINKED TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
637
CREATE [ FORCE ] [ [ GLOBAL | LOCAL ] TEMPORARY ]
Thomas Mueller's avatar
Thomas Mueller committed
638
LINKED TABLE [ IF NOT EXISTS ]
639 640
name ( driverString, urlString, userString, passwordString,
[ originalSchemaString, ] originalTableString ) [ EMIT UPDATES | READONLY ]
Thomas Mueller's avatar
Thomas Mueller committed
641 642 643 644 645
","
Creates a table link to an external table. The driver name may be empty if the
driver is already loaded. If the schema name is not set, only one table with
that name may exist in the target database.

646 647 648
FORCE - Create the LINKED TABLE even if the remote database/table does not exist.

EMIT UPDATES - Usually, for update statements, the old rows are deleted first and then the new
Thomas Mueller's avatar
Thomas Mueller committed
649 650
rows are inserted. It is possible to emit update statements (except on
rollback), however in this case multi-row unique key updates may not always
651
work. Linked tables to the same database share one connection.
652

653 654
READONLY - is set, the remote table may not be updated. This is enforced by H2.

Thomas Mueller's avatar
Thomas Mueller committed
655 656 657
If the connection to the source database is lost, the connection is re-opened
(this is a workaround for MySQL that disconnects after 8 hours of inactivity by default).

658
If a query is used instead of the original table name, the table is read only.
659
Queries must be enclosed in parenthesis: ""(SELECT * FROM ORDERS)"".
Thomas Mueller's avatar
Thomas Mueller committed
660 661

To use JNDI to get the connection, the driver class must be a
662 663
javax.naming.Context (for example ""javax.naming.InitialContext""), and the URL must
be the resource name (for example ""java:comp/env/jdbc/Test"").
664

Thomas Mueller's avatar
Thomas Mueller committed
665
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
666
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
667
","
668 669
CREATE LINKED TABLE LINK('org.h2.Driver', 'jdbc:h2:test2',
    'sa', 'sa', 'TEST');
Thomas Mueller's avatar
Thomas Mueller committed
670 671 672
CREATE LINKED TABLE LINK('', 'jdbc:h2:test2', 'sa', 'sa',
    '(SELECT * FROM TEST WHERE ID>0)');
CREATE LINKED TABLE LINK('javax.naming.InitialContext',
673 674
    'java:comp/env/jdbc/Test', NULL, NULL,
    '(SELECT * FROM TEST WHERE ID>0)');
Thomas Mueller's avatar
Thomas Mueller committed
675 676 677
"

"Commands (DDL)","CREATE ROLE","
678
CREATE ROLE [ IF NOT EXISTS ] newRoleName
Thomas Mueller's avatar
Thomas Mueller committed
679
","
Thomas Mueller's avatar
Thomas Mueller committed
680
Creates a new role.
Thomas Mueller's avatar
Thomas Mueller committed
681
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
682 683 684 685 686
","
CREATE ROLE READONLY
"

"Commands (DDL)","CREATE SCHEMA","
687 688
CREATE SCHEMA [ IF NOT EXISTS ] name
[ AUTHORIZATION ownerUserName ]
689
[ WITH tableEngineParamName [,...] ]
Thomas Mueller's avatar
Thomas Mueller committed
690 691 692
","
Creates a new schema. If no owner is specified, the current user is used. The
user that executes the command must have admin rights, as well as the owner.
Thomas Mueller's avatar
Thomas Mueller committed
693
Specifying the owner currently has no effect.
694 695
Optional table engine parameters are used when CREATE TABLE command
is run on this schema without having its engine params set.
696

Thomas Mueller's avatar
Thomas Mueller committed
697
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
698 699 700 701 702
","
CREATE SCHEMA TEST_SCHEMA AUTHORIZATION SA
"

"Commands (DDL)","CREATE SEQUENCE","
703
CREATE SEQUENCE [ IF NOT EXISTS ] newSequenceName
704
sequenceOptions
Thomas Mueller's avatar
Thomas Mueller committed
705
","
Thomas Mueller's avatar
Thomas Mueller committed
706 707 708
Creates a new sequence.
The data type of a sequence is BIGINT.
Used values are never re-used, even when the transaction is rolled back.
Thomas Mueller's avatar
Thomas Mueller committed
709 710 711 712 713

The cache is the number of pre-allocated numbers.
If the system crashes without closing the database, at most this many numbers are lost.
The default cache size is 32.
To disable caching, use the cache size 1 or lower.
Thomas Mueller's avatar
Thomas Mueller committed
714

Thomas Mueller's avatar
Thomas Mueller committed
715
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
716 717 718 719 720
","
CREATE SEQUENCE SEQ_ID
"

"Commands (DDL)","CREATE TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
721 722
CREATE [ CACHED | MEMORY ] [ TEMP | [ GLOBAL | LOCAL ] TEMPORARY ]
TABLE [ IF NOT EXISTS ] name
723
[ ( { columnName columnDefinition | constraint } [,...] ) ]
724 725
[ ENGINE tableEngineName ]
[ WITH tableEngineParamName [,...] ]
726
[ NOT PERSISTENT ] [ TRANSACTIONAL ]
727
[ AS select [ WITH [ NO ] DATA ] ]","
Thomas Mueller's avatar
Thomas Mueller committed
728 729
Creates a new table.

Thomas Mueller's avatar
Thomas Mueller committed
730 731 732 733
Cached tables (the default for regular tables) are persistent,
and the number of rows is not limited by the main memory.
Memory tables (the default for temporary tables) are persistent,
but the index data is kept in main memory,
Thomas Mueller's avatar
Thomas Mueller committed
734
that means memory tables should not get too large.
735

Thomas Mueller's avatar
Thomas Mueller committed
736 737 738 739 740
Temporary tables are deleted when closing or opening a database.
Temporary tables can be global (accessible by all connections)
or local (only accessible by the current connection).
The default for temporary tables is global.
Indexes of temporary tables are kept fully in main memory,
741
unless the temporary table is created using CREATE CACHED TABLE.
Thomas Mueller's avatar
Thomas Mueller committed
742

743
The ENGINE option is only required when custom table implementations are used.
744
The table engine class must implement the interface ""org.h2.api.TableEngine"".
745
Any table engine parameters are passed down in the tableEngineParams field of the CreateTableData object.
746

747 748 749
Either ENGINE, or WITH (table engine params), or both may be specified. If ENGINE is not specified
in CREATE TABLE, then the engine specified by DEFAULT_TABLE_ENGINE option of database params is used.

750
Tables with the NOT PERSISTENT modifier are kept fully in memory, and all
751
rows are lost when the database is closed.
Thomas Mueller's avatar
Thomas Mueller committed
752

753 754
The column definition is optional if a query is specified.
In that case the column list of the query is used.
755
If the query is specified its results are inserted into created table unless WITH NO DATA is specified.
756

Thomas Mueller's avatar
Thomas Mueller committed
757 758
This command commits an open transaction, except when using
TRANSACTIONAL (only supported for temporary tables).
Thomas Mueller's avatar
Thomas Mueller committed
759 760 761 762 763
","
CREATE TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR(255))
"

"Commands (DDL)","CREATE TRIGGER","
764 765 766 767 768 769
CREATE TRIGGER [ IF NOT EXISTS ] newTriggerName
{ BEFORE | AFTER | INSTEAD OF }
{ INSERT | UPDATE | DELETE | SELECT | ROLLBACK }
[,...] ON tableName [ FOR EACH ROW ]
[ QUEUE int ] [ NOWAIT ]
{ CALL triggeredClassName | AS sourceCodeString }
Thomas Mueller's avatar
Thomas Mueller committed
770
","
Thomas Mueller's avatar
Thomas Mueller committed
771 772 773 774 775
Creates a new trigger.
The trigger class must be public and implement ""org.h2.api.Trigger"".
Inner classes are not supported.
The class must be available in the classpath of the database engine
(when using the server mode, it must be in the classpath of the server).
776

777 778
The sourceCodeString must define a single method with no parameters that returns ""org.h2.api.Trigger"".
See CREATE ALIAS for requirements regarding the compilation.
779 780 781
Alternatively, javax.script.ScriptEngineManager can be used to create an instance of ""org.h2.api.Trigger"".
Currently javascript (included in every JRE) and ruby (with JRuby) are supported.
In that case the source must begin respectively with ""//javascript"" or ""#ruby"".
782

783
BEFORE triggers are called after data conversion is made, default values are set,
784
null and length constraint checks have been made;
785
but before other constraints have been checked.
Thomas Mueller's avatar
Thomas Mueller committed
786
If there are multiple triggers, the order in which they are called is undefined.
787

Thomas Mueller's avatar
Thomas Mueller committed
788
ROLLBACK can be specified in combination with INSERT, UPDATE, and DELETE.
789
Only row based AFTER trigger can be called on ROLLBACK.
790
Exceptions that occur within such triggers are ignored.
791 792
As the operations that occur within a trigger are part of the transaction,
ROLLBACK triggers are only required if an operation communicates outside of the database.
793

794
INSTEAD OF triggers are implicitly row based and behave like BEFORE triggers.
795
Only the first such trigger is called. Such triggers on views are supported.
796
They can be used to make views updatable.
797

Thomas Mueller's avatar
Thomas Mueller committed
798 799
A BEFORE SELECT trigger is fired just before the database engine tries to read from the table.
The trigger can be used to update a table on demand.
800 801
The trigger is called with both 'old' and 'new' set to null.

802 803 804 805
The MERGE statement will call both INSERT and UPDATE triggers.
Not supported are SELECT triggers with the option FOR EACH ROW,
and AFTER SELECT triggers.

Thomas Mueller's avatar
Thomas Mueller committed
806 807
Committing or rolling back a transaction within a trigger is not allowed, except for SELECT triggers.

Thomas Mueller's avatar
Thomas Mueller committed
808 809 810
By default a trigger is called once for each statement, without the old and new rows.
FOR EACH ROW triggers are called once for each inserted, updated, or deleted row.

811 812
QUEUE is implemented for syntax compatibility with HSQL and has no effect.

Thomas Mueller's avatar
Thomas Mueller committed
813 814
The trigger need to be created in the same schema as the table.
The schema name does not need to be specified when creating the trigger.
815

Thomas Mueller's avatar
Thomas Mueller committed
816
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
817
","
818
CREATE TRIGGER TRIG_INS BEFORE INSERT ON TEST FOR EACH ROW CALL ""MyTrigger"";
Thomas Mueller's avatar
Thomas Mueller committed
819
CREATE TRIGGER TRIG_SRC BEFORE INSERT ON TEST AS $$org.h2.api.Trigger create() { return new MyTrigger(""constructorParam""); } $$;
820 821
CREATE TRIGGER TRIG_JS BEFORE INSERT ON TEST AS $$//javascript\nreturn new Packages.MyTrigger(""constructorParam""); $$;
CREATE TRIGGER TRIG_RUBY BEFORE INSERT ON TEST AS $$#ruby\nJava::MyPackage::MyTrigger.new(""constructorParam"") $$;
Thomas Mueller's avatar
Thomas Mueller committed
822 823
"
"Commands (DDL)","CREATE USER","
824 825
CREATE USER [ IF NOT EXISTS ] newUserName
{ PASSWORD string | SALT bytes HASH bytes } [ ADMIN ]
Thomas Mueller's avatar
Thomas Mueller committed
826
","
Thomas Mueller's avatar
Thomas Mueller committed
827 828 829
Creates a new user. For compatibility, only unquoted or uppercase user names are allowed.
The password must be in single quotes. It is case sensitive and can contain spaces.
The salt and hash values are hex strings.
830

Thomas Mueller's avatar
Thomas Mueller committed
831
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
832
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
833 834 835 836 837
","
CREATE USER GUEST PASSWORD 'abc'
"

"Commands (DDL)","CREATE VIEW","
Thomas Mueller's avatar
Thomas Mueller committed
838
CREATE [ OR REPLACE ] [ FORCE ] VIEW [ IF NOT EXISTS ] newViewName
839
[ ( columnName [,...] ) ] AS select
Thomas Mueller's avatar
Thomas Mueller committed
840 841
","
Creates a new view. If the force option is used, then the view is created even
Thomas Mueller's avatar
Thomas Mueller committed
842
if the underlying table(s) don't exist.
843

Thomas Mueller's avatar
Thomas Mueller committed
844 845 846 847 848
If the OR REPLACE clause is used an existing view will be replaced, and any
dependent views will not need to be recreated. If dependent views will become
invalid as a result of the change an error will be generated, but this error
can be ignored if the FORCE clause is also used.

849 850
Views are not updatable except when using 'instead of' triggers.

Thomas Mueller's avatar
Thomas Mueller committed
851
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
852
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
853 854 855 856 857
","
CREATE VIEW TEST_VIEW AS SELECT * FROM TEST WHERE ID < 100
"

"Commands (DDL)","DROP AGGREGATE","
858
DROP AGGREGATE [ IF EXISTS ] aggregateName
Thomas Mueller's avatar
Thomas Mueller committed
859
","
Thomas Mueller's avatar
Thomas Mueller committed
860 861 862
Drops an existing user-defined aggregate function.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
863
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
864
","
865
DROP AGGREGATE SIMPLE_MEDIAN
Thomas Mueller's avatar
Thomas Mueller committed
866 867 868
"

"Commands (DDL)","DROP ALIAS","
869
DROP ALIAS [ IF EXISTS ] existingFunctionAliasName
Thomas Mueller's avatar
Thomas Mueller committed
870
","
Thomas Mueller's avatar
Thomas Mueller committed
871 872 873
Drops an existing function alias.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
874
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
875
","
Thomas Mueller's avatar
Thomas Mueller committed
876
DROP ALIAS MY_SQRT
Thomas Mueller's avatar
Thomas Mueller committed
877 878 879
"

"Commands (DDL)","DROP ALL OBJECTS","
880
DROP ALL OBJECTS [ DELETE FILES ]
Thomas Mueller's avatar
Thomas Mueller committed
881 882 883 884 885
","
Drops all existing views, tables, sequences, schemas, function aliases, roles,
user-defined aggregate functions, domains, and users (except the current user).
If DELETE FILES is specified, the database files will be removed when the last
user disconnects from the database. Warning: this command can not be rolled
Thomas Mueller's avatar
Thomas Mueller committed
886 887 888
back.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
889 890 891 892 893
","
DROP ALL OBJECTS
"

"Commands (DDL)","DROP CONSTANT","
894
DROP CONSTANT [ IF EXISTS ] constantName
Thomas Mueller's avatar
Thomas Mueller committed
895
","
Thomas Mueller's avatar
Thomas Mueller committed
896
Drops a constant.
Thomas Mueller's avatar
Thomas Mueller committed
897
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
898 899 900 901 902
","
DROP CONSTANT ONE
"

"Commands (DDL)","DROP DOMAIN","
903
DROP DOMAIN [ IF EXISTS ] domainName [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
904
","
Thomas Mueller's avatar
Thomas Mueller committed
905
Drops a data type (domain).
906 907
The command will fail if it is referenced by a column (the default).
Column descriptors are replaced with original definition of specified domain if the CASCADE clause is used.
Thomas Mueller's avatar
Thomas Mueller committed
908
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
909 910 911 912 913
","
DROP DOMAIN EMAIL
"

"Commands (DDL)","DROP INDEX","
914
DROP INDEX [ IF EXISTS ] indexName
Thomas Mueller's avatar
Thomas Mueller committed
915
","
Thomas Mueller's avatar
Thomas Mueller committed
916
Drops an index.
Thomas Mueller's avatar
Thomas Mueller committed
917
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
918 919 920 921 922
","
DROP INDEX IF EXISTS IDXNAME
"

"Commands (DDL)","DROP ROLE","
923
DROP ROLE [ IF EXISTS ] roleName
Thomas Mueller's avatar
Thomas Mueller committed
924
","
Thomas Mueller's avatar
Thomas Mueller committed
925
Drops a role.
Thomas Mueller's avatar
Thomas Mueller committed
926
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
927 928 929 930 931
","
DROP ROLE READONLY
"

"Commands (DDL)","DROP SCHEMA","
932
DROP SCHEMA [ IF EXISTS ] schemaName [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
933
","
Thomas Mueller's avatar
Thomas Mueller committed
934
Drops a schema.
935 936
The command will fail if objects in this schema exist and the RESTRICT clause is used (the default).
All objects in this schema are dropped as well if the CASCADE clause is used.
Thomas Mueller's avatar
Thomas Mueller committed
937
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
938 939 940 941 942
","
DROP SCHEMA TEST_SCHEMA
"

"Commands (DDL)","DROP SEQUENCE","
943
DROP SEQUENCE [ IF EXISTS ] sequenceName
Thomas Mueller's avatar
Thomas Mueller committed
944
","
Thomas Mueller's avatar
Thomas Mueller committed
945
Drops a sequence.
Thomas Mueller's avatar
Thomas Mueller committed
946
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
947 948 949 950 951
","
DROP SEQUENCE SEQ_ID
"

"Commands (DDL)","DROP TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
952
DROP TABLE [ IF EXISTS ] tableName [,...] [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
953
","
Thomas Mueller's avatar
Thomas Mueller committed
954
Drops an existing table, or a list of tables.
955 956
The command will fail if dependent objects exist and the RESTRICT clause is used (the default).
All dependent views and constraints are dropped as well if the CASCADE clause is used.
Thomas Mueller's avatar
Thomas Mueller committed
957
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
958 959 960 961 962
","
DROP TABLE TEST
"

"Commands (DDL)","DROP TRIGGER","
963
DROP TRIGGER [ IF EXISTS ] triggerName
Thomas Mueller's avatar
Thomas Mueller committed
964
","
Thomas Mueller's avatar
Thomas Mueller committed
965
Drops an existing trigger.
Thomas Mueller's avatar
Thomas Mueller committed
966
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
967 968 969 970 971
","
DROP TRIGGER TRIG_INS
"

"Commands (DDL)","DROP USER","
972
DROP USER [ IF EXISTS ] userName
Thomas Mueller's avatar
Thomas Mueller committed
973
","
Thomas Mueller's avatar
Thomas Mueller committed
974 975
Drops a user. The current user cannot be dropped.
For compatibility, only unquoted or uppercase user names are allowed.
976

Thomas Mueller's avatar
Thomas Mueller committed
977
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
978
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
979 980 981 982 983
","
DROP USER TOM
"

"Commands (DDL)","DROP VIEW","
984
DROP VIEW [ IF EXISTS ] viewName [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
985
","
Thomas Mueller's avatar
Thomas Mueller committed
986 987 988
Drops an existing view.
All dependent views are dropped as well if the CASCADE clause is used (the default).
The command will fail if dependent views exist and the RESTRICT clause is used.
Thomas Mueller's avatar
Thomas Mueller committed
989
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
990 991 992 993 994
","
DROP VIEW TEST_VIEW
"

"Commands (DDL)","TRUNCATE TABLE","
995
TRUNCATE TABLE tableName [ [ CONTINUE | RESTART ] IDENTITY ]
Thomas Mueller's avatar
Thomas Mueller committed
996
","
997 998 999 1000 1001
Removes all rows from a table.
Unlike DELETE FROM without where clause, this command can not be rolled back.
This command is faster than DELETE without where clause.
Only regular data tables without foreign key constraints can be truncated
(except if referential integrity is disabled for this database or for this table).
1002
Linked tables can't be truncated.
1003
If RESTART IDENTITY is specified next values for auto-incremented columns are restarted.
Thomas Mueller's avatar
Thomas Mueller committed
1004

Thomas Mueller's avatar
Thomas Mueller committed
1005
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1006 1007 1008 1009 1010 1011 1012
","
TRUNCATE TABLE TEST
"

"Commands (Other)","CHECKPOINT","
CHECKPOINT
","
Thomas Mueller's avatar
Thomas Mueller committed
1013
Flushes the data to disk.
Thomas Mueller's avatar
Thomas Mueller committed
1014 1015

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1016 1017 1018 1019 1020 1021 1022
","
CHECKPOINT
"

"Commands (Other)","CHECKPOINT SYNC","
CHECKPOINT SYNC
","
Thomas Mueller's avatar
Thomas Mueller committed
1023
Flushes the data to disk and and forces all system buffers be written
Thomas Mueller's avatar
Thomas Mueller committed
1024 1025 1026
to the underlying device.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1027 1028 1029 1030 1031
","
CHECKPOINT SYNC
"

"Commands (Other)","COMMIT","
1032
COMMIT [ WORK ]
Thomas Mueller's avatar
Thomas Mueller committed
1033 1034 1035 1036 1037 1038 1039 1040 1041
","
Commits a transaction.
","
COMMIT
"

"Commands (Other)","COMMIT TRANSACTION","
COMMIT TRANSACTION transactionName
","
Thomas Mueller's avatar
Thomas Mueller committed
1042 1043 1044 1045
Sets the resolution of an in-doubt transaction to 'commit'.

Admin rights are required to execute this command.
This command is part of the 2-phase-commit protocol.
Thomas Mueller's avatar
Thomas Mueller committed
1046 1047 1048 1049 1050
","
COMMIT TRANSACTION XID_TEST
"

"Commands (Other)","GRANT RIGHT","
1051
GRANT { SELECT | INSERT | UPDATE | DELETE | ALL } [,...] ON
1052 1053
{ { SCHEMA schemaName } | { tableName [,...] } }
TO { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1054
","
Thomas Mueller's avatar
Thomas Mueller committed
1055 1056 1057
Grants rights for a table to a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1058
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1059 1060 1061 1062
","
GRANT SELECT ON TEST TO READONLY
"

1063 1064 1065 1066 1067 1068
"Commands (Other)","GRANT ALTER ANY SCHEMA","
GRANT ALTER ANY SCHEMA TO userName
","
Grant schema altering rights to a user.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1069
This command commits an open transaction in this connection.
1070 1071 1072 1073
","
GRANT ALTER ANY SCHEMA TO Bob
"

Thomas Mueller's avatar
Thomas Mueller committed
1074
"Commands (Other)","GRANT ROLE","
1075
GRANT roleName TO { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1076
","
Thomas Mueller's avatar
Thomas Mueller committed
1077 1078 1079
Grants a role to a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1080
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1081 1082 1083 1084 1085
","
GRANT READONLY TO PUBLIC
"

"Commands (Other)","HELP","
1086
HELP [ anything [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
1087 1088 1089 1090 1091 1092 1093 1094 1095
","
Displays the help pages of SQL commands or keywords.
","
HELP SELECT
"

"Commands (Other)","PREPARE COMMIT","
PREPARE COMMIT newTransactionName
","
Thomas Mueller's avatar
Thomas Mueller committed
1096 1097
Prepares committing a transaction.
This command is part of the 2-phase-commit protocol.
Thomas Mueller's avatar
Thomas Mueller committed
1098 1099 1100 1101 1102
","
PREPARE COMMIT XID_TEST
"

"Commands (Other)","REVOKE RIGHT","
1103
REVOKE { SELECT | INSERT | UPDATE | DELETE | ALL } [,...] ON
1104 1105
{ { SCHEMA schemaName } | { tableName [,...] } }
FROM { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1106
","
Thomas Mueller's avatar
Thomas Mueller committed
1107 1108 1109
Removes rights for a table from a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1110
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1111 1112 1113 1114 1115
","
REVOKE SELECT ON TEST FROM READONLY
"

"Commands (Other)","REVOKE ROLE","
1116
REVOKE roleName FROM { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1117
","
Thomas Mueller's avatar
Thomas Mueller committed
1118 1119 1120
Removes a role from a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1121
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1122 1123 1124 1125 1126
","
REVOKE READONLY FROM TOM
"

"Commands (Other)","ROLLBACK","
1127
ROLLBACK [ TO SAVEPOINT savepointName ]
Thomas Mueller's avatar
Thomas Mueller committed
1128 1129 1130 1131 1132 1133 1134 1135 1136 1137
","
Rolls back a transaction. If a savepoint name is used, the transaction is only
rolled back to the specified savepoint.
","
ROLLBACK
"

"Commands (Other)","ROLLBACK TRANSACTION","
ROLLBACK TRANSACTION transactionName
","
Thomas Mueller's avatar
Thomas Mueller committed
1138 1139 1140 1141
Sets the resolution of an in-doubt transaction to 'rollback'.

Admin rights are required to execute this command.
This command is part of the 2-phase-commit protocol.
Thomas Mueller's avatar
Thomas Mueller committed
1142 1143 1144 1145 1146 1147 1148
","
ROLLBACK TRANSACTION XID_TEST
"

"Commands (Other)","SAVEPOINT","
SAVEPOINT savepointName
","
Thomas Mueller's avatar
Thomas Mueller committed
1149 1150
Create a new savepoint. See also ROLLBACK.
Savepoints are only valid until the transaction is committed or rolled back.
Thomas Mueller's avatar
Thomas Mueller committed
1151 1152 1153 1154 1155
","
SAVEPOINT HALF_DONE
"

"Commands (Other)","SET @","
1156
SET @variableName [ = ] expression
Thomas Mueller's avatar
Thomas Mueller committed
1157
","
Thomas Mueller's avatar
Thomas Mueller committed
1158
Updates a user-defined variable.
Thomas Mueller's avatar
Thomas Mueller committed
1159
Variables are not persisted and session scoped, that means only visible from within the session in which they are defined.
Thomas Mueller's avatar
Thomas Mueller committed
1160
This command does not commit a transaction, and rollback does not affect it.
Thomas Mueller's avatar
Thomas Mueller committed
1161 1162 1163 1164 1165
","
SET @TOTAL=0
"

"Commands (Other)","SET ALLOW_LITERALS","
1166
SET ALLOW_LITERALS { NONE | ALL | NUMBERS }
Thomas Mueller's avatar
Thomas Mueller committed
1167 1168 1169 1170 1171 1172 1173 1174 1175 1176
","
This setting can help solve the SQL injection problem. By default, text and
number literals are allowed in SQL statements. However, this enables SQL
injection if the application dynamically builds SQL statements. SQL injection is
not possible if user data is set using parameters ('?').

NONE means literals of any kind are not allowed, only parameters and constants
are allowed. NUMBERS mean only numerical and boolean literals are allowed. ALL
means all literals are allowed (default).

Thomas Mueller's avatar
Thomas Mueller committed
1177 1178
See also CREATE CONSTANT.

Thomas Mueller's avatar
Thomas Mueller committed
1179
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1180
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1181
This setting is persistent.
1182
This setting can be appended to the database URL: ""jdbc:h2:test;ALLOW_LITERALS=NONE""
Thomas Mueller's avatar
Thomas Mueller committed
1183 1184 1185 1186 1187
","
SET ALLOW_LITERALS NONE
"

"Commands (Other)","SET AUTOCOMMIT","
1188
SET AUTOCOMMIT { TRUE | ON | FALSE | OFF }
Thomas Mueller's avatar
Thomas Mueller committed
1189 1190
","
Switches auto commit on or off.
1191
This setting can be appended to the database URL: ""jdbc:h2:test;AUTOCOMMIT=OFF"" -
1192
however this will not work as expected when using a connection pool
1193 1194
(the connection pool manager will re-enable autocommit when returning
the connection to the pool, so autocommit will only be disabled the first
1195
time the connection is used.
Thomas Mueller's avatar
Thomas Mueller committed
1196 1197 1198 1199 1200 1201 1202
","
SET AUTOCOMMIT OFF
"

"Commands (Other)","SET CACHE_SIZE","
SET CACHE_SIZE int
","
1203
Sets the size of the cache in KB (each KB being 1024 bytes) for the current database.
1204 1205
The default is 65536 per available GB of RAM, i.e. 64 MB per GB.
The value is rounded to the next higher power of two.
Thomas Mueller's avatar
Thomas Mueller committed
1206 1207
Depending on the virtual machine, the actual memory required may be higher.

Thomas Mueller's avatar
Thomas Mueller committed
1208
This setting is persistent and affects all connections as there is only one cache per database.
Thomas Mueller's avatar
Thomas Mueller committed
1209
Using a very small value (specially 0) will reduce performance a lot.
Thomas Mueller's avatar
Thomas Mueller committed
1210 1211
This setting only affects the database engine (the server in a client/server environment;
in embedded mode, the database engine is in the same process as the application).
Thomas Mueller's avatar
Thomas Mueller committed
1212
It has no effect for in-memory databases.
1213

Thomas Mueller's avatar
Thomas Mueller committed
1214
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1215
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1216
This setting is persistent.
1217
This setting can be appended to the database URL: ""jdbc:h2:test;CACHE_SIZE=8192""
Thomas Mueller's avatar
Thomas Mueller committed
1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229
","
SET CACHE_SIZE 8192
"

"Commands (Other)","SET CLUSTER","
SET CLUSTER serverListString
","
This command should not be used directly by an application, the statement is
executed automatically by the system. The behavior may change in future
releases. Sets the cluster server list. An empty string switches off the cluster
mode. Switching on the cluster mode requires admin rights, but any user can
switch it off (this is automatically done when the client detects the other
Thomas Mueller's avatar
Thomas Mueller committed
1230 1231
server is not responding).

Thomas Mueller's avatar
Thomas Mueller committed
1232
This command is effective immediately, but does not commit an open transaction.
Thomas Mueller's avatar
Thomas Mueller committed
1233 1234 1235 1236
","
SET CLUSTER ''
"

1237 1238 1239 1240
"Commands (Other)","SET BINARY_COLLATION","
SET BINARY_COLLATION
{ UNSIGNED | SIGNED } ] }
","
Thomas Mueller's avatar
Thomas Mueller committed
1241 1242
Sets the collation used for comparing BINARY columns, the default is SIGNED
for version 1.3 and older, and UNSIGNED for version 1.4 and newer.
1243 1244 1245
This command can only be executed if there are no tables defined.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1246
This command commits an open transaction in this connection.
1247 1248 1249 1250 1251
This setting is persistent.
","
SET BINARY_COLLATION SIGNED
"

1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264
"Commands (Other)","SET BUILTIN_ALIAS_OVERRIDE","
SET BUILTIN_ALIAS_OVERRIDE
{ TRUE | FALSE } ] }
","
Allows the overriding of the builtin system date/time functions
for unit testing purposes.

Admin rights are required to execute this command.
This command commits an open transaction in this connection.
","
SET BUILTIN_ALIAS_OVERRIDE TRUE
"

Thomas Mueller's avatar
Thomas Mueller committed
1265
"Commands (Other)","SET COLLATION","
1266
SET [ DATABASE ] COLLATION
1267 1268
{ OFF | collationName
    [ STRENGTH { PRIMARY | SECONDARY | TERTIARY | IDENTICAL } ] }
Thomas Mueller's avatar
Thomas Mueller committed
1269
","
Thomas Mueller's avatar
Thomas Mueller committed
1270 1271
Sets the collation used for comparing strings.
This command can only be executed if there are no tables defined.
Thomas Mueller's avatar
Thomas Mueller committed
1272 1273
See ""java.text.Collator"" for details about the supported collations and the STRENGTH
(PRIMARY is usually case- and umlaut-insensitive; SECONDARY is case-insensitive but umlaut-sensitive;
Thomas Mueller's avatar
Thomas Mueller committed
1274
TERTIARY is both case- and umlaut-sensitive; IDENTICAL is sensitive to all differences and only affects ordering).
Thomas Mueller's avatar
Thomas Mueller committed
1275

1276 1277 1278 1279 1280
The ICU4J collator is used if it is in the classpath.
It is also used if the collation name starts with ICU4J_
(in that case, the ICU4J must be in the classpath, otherwise an exception is thrown).
The default collator is used if the collation name starts with DEFAULT_
(even if ICU4J is in the classpath).
1281 1282
The charset collator is used if the collation name starts with CHARSET_ (e.g. CHARSET_CP500). This collator sorts
strings according to the binary representation in the given charset.
1283

Thomas Mueller's avatar
Thomas Mueller committed
1284
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1285
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1286
This setting is persistent.
1287
This setting can be appended to the database URL: ""jdbc:h2:test;COLLATION='ENGLISH'""
Thomas Mueller's avatar
Thomas Mueller committed
1288 1289
","
SET COLLATION ENGLISH
1290
SET COLLATION CHARSET_CP500
Thomas Mueller's avatar
Thomas Mueller committed
1291 1292 1293
"

"Commands (Other)","SET COMPRESS_LOB","
1294
SET COMPRESS_LOB { NO | LZF | DEFLATE }
Thomas Mueller's avatar
Thomas Mueller committed
1295
","
Thomas Mueller's avatar
Thomas Mueller committed
1296 1297 1298 1299
This feature is only available for the PageStore storage engine.
For the MVStore engine (the default for H2 version 1.4.x),
append "";COMPRESS=TRUE"" to the database URL instead.

Thomas Mueller's avatar
Thomas Mueller committed
1300 1301
Sets the compression algorithm for BLOB and CLOB data. Compression is usually
slower, but needs less disk space. LZF is faster but uses more space.
Thomas Mueller's avatar
Thomas Mueller committed
1302

Thomas Mueller's avatar
Thomas Mueller committed
1303
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1304
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1305
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1306 1307 1308 1309 1310 1311 1312 1313
","
SET COMPRESS_LOB LZF
"

"Commands (Other)","SET DATABASE_EVENT_LISTENER","
SET DATABASE_EVENT_LISTENER classNameString
","
Sets the event listener class. An empty string ('') means no listener should be
Thomas Mueller's avatar
Thomas Mueller committed
1314 1315 1316 1317
used. This setting is not persistent.

Admin rights are required to execute this command, except if it is set when
opening the database (in this case it is reset just after opening the database).
1318
This setting can be appended to the database URL: ""jdbc:h2:test;DATABASE_EVENT_LISTENER='sample.MyListener'""
Thomas Mueller's avatar
Thomas Mueller committed
1319 1320 1321 1322 1323 1324 1325
","
SET DATABASE_EVENT_LISTENER 'sample.MyListener'
"

"Commands (Other)","SET DB_CLOSE_DELAY","
SET DB_CLOSE_DELAY int
","
Thomas Mueller's avatar
Thomas Mueller committed
1326 1327
Sets the delay for closing a database if all connections are closed.
The value -1 means the database is never closed until the close delay is set to some other value or SHUTDOWN is called.
Thomas Mueller's avatar
Thomas Mueller committed
1328 1329 1330 1331
The value 0 means no delay (default; the database is closed if the last connection to it is closed).
Values 1 and larger mean the number of seconds the database is left open after closing the last connection.

If the application exits normally or System.exit is called, the database is closed immediately, even if a delay is set.
Thomas Mueller's avatar
Thomas Mueller committed
1332

Thomas Mueller's avatar
Thomas Mueller committed
1333
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1334
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1335
This setting is persistent.
1336
This setting can be appended to the database URL: ""jdbc:h2:test;DB_CLOSE_DELAY=-1""
Thomas Mueller's avatar
Thomas Mueller committed
1337 1338 1339 1340 1341 1342 1343 1344
","
SET DB_CLOSE_DELAY -1
"

"Commands (Other)","SET DEFAULT_LOCK_TIMEOUT","
SET DEFAULT LOCK_TIMEOUT int
","
Sets the default lock timeout (in milliseconds) in this database that is used
Thomas Mueller's avatar
Thomas Mueller committed
1345 1346
for the new sessions. The default value for this setting is 1000 (one second).

Thomas Mueller's avatar
Thomas Mueller committed
1347
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1348
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1349
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1350 1351 1352 1353 1354
","
SET DEFAULT_LOCK_TIMEOUT 5000
"

"Commands (Other)","SET DEFAULT_TABLE_TYPE","
1355
SET DEFAULT_TABLE_TYPE { MEMORY | CACHED }
Thomas Mueller's avatar
Thomas Mueller committed
1356 1357 1358
","
Sets the default table storage type that is used when creating new tables.
Memory tables are kept fully in the main memory (including indexes), however
Thomas Mueller's avatar
Thomas Mueller committed
1359
the data is still stored in the database file. The size of memory tables is
Thomas Mueller's avatar
Thomas Mueller committed
1360
limited by the memory. The default is CACHED.
Thomas Mueller's avatar
Thomas Mueller committed
1361

Thomas Mueller's avatar
Thomas Mueller committed
1362
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1363
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1364
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1365
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1366 1367 1368 1369 1370
","
SET DEFAULT_TABLE_TYPE MEMORY
"

"Commands (Other)","SET EXCLUSIVE","
Thomas Mueller's avatar
Thomas Mueller committed
1371
SET EXCLUSIVE { 0 | 1 | 2 }
Thomas Mueller's avatar
Thomas Mueller committed
1372
","
Thomas Mueller's avatar
Thomas Mueller committed
1373 1374 1375 1376 1377 1378 1379 1380 1381 1382
Switched the database to exclusive mode (1, 2) and back to normal mode (0).

In exclusive mode, new connections are rejected, and operations by
other connections are paused until the exclusive mode is disabled.
When using the value 1, existing connections stay open.
When using the value 2, all existing connections are closed
(and current transactions are rolled back) except the connection
that executes SET EXCLUSIVE.
Only the connection that set the exclusive mode can disable it.
When the connection is closed, it is automatically disabled.
Thomas Mueller's avatar
Thomas Mueller committed
1383 1384

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1385
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1386
","
Thomas Mueller's avatar
Thomas Mueller committed
1387
SET EXCLUSIVE 1
Thomas Mueller's avatar
Thomas Mueller committed
1388 1389 1390
"

"Commands (Other)","SET IGNORECASE","
1391
SET IGNORECASE { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
1392 1393 1394 1395 1396
","
If IGNORECASE is enabled, text columns in newly created tables will be
case-insensitive. Already existing tables are not affected. The effect of
case-insensitive columns is similar to using a collation with strength PRIMARY.
Case-insensitive columns are compared faster than when using a collation.
Thomas Mueller's avatar
Thomas Mueller committed
1397
String literals and parameters are however still considered case sensitive even if this option is set.
Thomas Mueller's avatar
Thomas Mueller committed
1398

Thomas Mueller's avatar
Thomas Mueller committed
1399
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1400
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1401
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1402
This setting can be appended to the database URL: ""jdbc:h2:test;IGNORECASE=TRUE""
Thomas Mueller's avatar
Thomas Mueller committed
1403 1404 1405 1406
","
SET IGNORECASE TRUE
"

1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418
"Commands (Other)","SET JAVA_OBJECT_SERIALIZER","
SET JAVA_OBJECT_SERIALIZER
{ null | className }
","
Sets the object used to serialize and deserialize java objects being stored in column of type OTHER.
The serializer class must be public and implement ""org.h2.api.JavaObjectSerializer"".
Inner classes are not supported.
The class must be available in the classpath of the database engine
(when using the server mode, it must be both in the classpath of the server and the client).
This command can only be executed if there are no tables defined.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1419
This command commits an open transaction in this connection.
1420 1421 1422 1423 1424 1425 1426
This setting is persistent.
This setting can be appended to the database URL: ""jdbc:h2:test;JAVA_OBJECT_SERIALIZER='com.acme.SerializerClassName'""
","
SET JAVA_OBJECT_SERIALIZER 'com.acme.SerializerClassName'
"


1427 1428 1429 1430 1431 1432 1433 1434 1435 1436 1437 1438 1439 1440 1441 1442 1443
"Commands (Other)","SET LAZY_QUERY_EXECUTION","
SET LAZY_QUERY_EXECUTION int
","
Sets the lazy query execution mode. The values 0, 1 are supported.

If true, then large results are retrieved in chunks.

Note that not all queries support this feature, queries which do not are processed normally.

Admin rights are required to execute this command, as it affects all connections.
This command commits an open transaction in this connection.
This setting is not persistent.
This setting can be appended to the database URL: ""jdbc:h2:test;LAZY_QUERY_EXECUTION=1""
","
SET LAZY_QUERY_EXECUTION 1
"

1444
"Commands (Other)","SET LOG","
1445
SET LOG int
1446 1447 1448 1449
","
Sets the transaction log mode. The values 0, 1, and 2 are supported, the default is 2.
This setting affects all connections.

1450
LOG 0 means the transaction log is disabled completely. It is the fastest mode,
1451 1452 1453 1454
but also the most dangerous: if the process is killed while the database is open in this mode,
the data might be lost. It must only be used if this is not a problem, for example when
initially loading a database, or when running tests.

1455 1456
LOG 1 means the transaction log is enabled, but FileDescriptor.sync is disabled.
This setting is about half as fast as with LOG 0. This setting is useful if no protection
1457 1458
against power failure is required, but the data must be protected against killing the process.

1459 1460
LOG 2 (the default) means the transaction log is enabled, and FileDescriptor.sync is called
for each checkpoint. This setting is about half as fast as LOG 1. Depending on the
1461 1462
file system, this will also protect against power failure in the majority if cases.

Thomas Mueller's avatar
Thomas Mueller committed
1463
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1464
This command commits an open transaction in this connection.
1465
This setting is not persistent.
1466
This setting can be appended to the database URL: ""jdbc:h2:test;LOG=0""
1467 1468 1469 1470
","
SET LOG 1
"

Thomas Mueller's avatar
Thomas Mueller committed
1471 1472 1473 1474
"Commands (Other)","SET LOCK_MODE","
SET LOCK_MODE int
","
Sets the lock mode. The values 0, 1, 2, and 3 are supported. The default is 3
1475
(READ_COMMITTED). This setting affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1476 1477 1478 1479 1480 1481 1482 1483 1484 1485 1486 1487 1488

The value 0 means no locking (should only be used for testing; also known as
READ_UNCOMMITTED). Please note that using SET LOCK_MODE 0 while at the same time
using multiple connections may result in inconsistent transactions.

The value 1 means table level locking (also known as SERIALIZABLE).

The value 2 means table level locking with garbage collection (if the
application does not close all connections).

The value 3 means table level locking, but read locks are released immediately
(default; also known as READ_COMMITTED).

Thomas Mueller's avatar
Thomas Mueller committed
1489
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1490
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1491
This setting is persistent.
1492
This setting can be appended to the database URL: ""jdbc:h2:test;LOCK_MODE=3""
Thomas Mueller's avatar
Thomas Mueller committed
1493 1494 1495 1496 1497 1498 1499 1500
","
SET LOCK_MODE 1
"

"Commands (Other)","SET LOCK_TIMEOUT","
SET LOCK_TIMEOUT int
","
Sets the lock timeout (in milliseconds) for the current session. The default
Thomas Mueller's avatar
Thomas Mueller committed
1501 1502 1503
value for this setting is 1000 (one second).

This command does not commit a transaction, and rollback does not affect it.
1504
This setting can be appended to the database URL: ""jdbc:h2:test;LOCK_TIMEOUT=10000""
Thomas Mueller's avatar
Thomas Mueller committed
1505 1506 1507 1508 1509 1510 1511
","
SET LOCK_TIMEOUT 1000
"

"Commands (Other)","SET MAX_LENGTH_INPLACE_LOB","
SET MAX_LENGTH_INPLACE_LOB int
","
Thomas Mueller's avatar
Thomas Mueller committed
1512
Sets the maximum size of an in-place LOB object.
1513

1514
This is the maximum length of an LOB that is stored with the record itself,
1515 1516
and the default value is 128.

Thomas Mueller's avatar
Thomas Mueller committed
1517
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1518
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1519
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1520 1521 1522 1523 1524 1525 1526
","
SET MAX_LENGTH_INPLACE_LOB 128
"

"Commands (Other)","SET MAX_LOG_SIZE","
SET MAX_LOG_SIZE int
","
Thomas Mueller's avatar
Thomas Mueller committed
1527 1528
Sets the maximum size of the transaction log, in megabytes.
If the log is larger, and if there is no open transaction, the transaction log is truncated.
noelgrandin's avatar
noelgrandin committed
1529
If there is an open transaction, the transaction log will continue to grow however.
Thomas Mueller's avatar
Thomas Mueller committed
1530
The default max size is 16 MB.
Thomas Mueller's avatar
Thomas Mueller committed
1531
This setting has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1532

Thomas Mueller's avatar
Thomas Mueller committed
1533
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1534
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1535
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1536 1537 1538 1539 1540 1541 1542 1543
","
SET MAX_LOG_SIZE 2
"

"Commands (Other)","SET MAX_MEMORY_ROWS","
SET MAX_MEMORY_ROWS int
","
The maximum number of rows in a result set that are kept in-memory. If more rows
1544
are read, then the rows are buffered to disk.
1545
The default is 40000 per GB of available RAM.
Thomas Mueller's avatar
Thomas Mueller committed
1546

Thomas Mueller's avatar
Thomas Mueller committed
1547
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1548
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1549
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1550
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1551 1552 1553 1554 1555 1556 1557
","
SET MAX_MEMORY_ROWS 1000
"

"Commands (Other)","SET MAX_MEMORY_UNDO","
SET MAX_MEMORY_UNDO int
","
1558
The maximum number of undo records per a session that are kept in-memory.
Thomas Mueller's avatar
Thomas Mueller committed
1559 1560
If a transaction is larger, the records are buffered to disk.
The default value is 50000.
Thomas Mueller's avatar
Thomas Mueller committed
1561
Changes to tables without a primary key can not be buffered to disk.
Thomas Mueller's avatar
Thomas Mueller committed
1562 1563
This setting is not supported when using multi-version concurrency.

Thomas Mueller's avatar
Thomas Mueller committed
1564
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1565
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1566
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1567
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1568 1569 1570 1571 1572 1573 1574 1575 1576
","
SET MAX_MEMORY_UNDO 1000
"

"Commands (Other)","SET MAX_OPERATION_MEMORY","
SET MAX_OPERATION_MEMORY int
","
Sets the maximum memory used for large operations (delete and insert), in bytes.
Operations that use more memory are buffered to disk, slowing down the
Thomas Mueller's avatar
Thomas Mueller committed
1577 1578 1579
operation. The default max size is 100000. 0 means no limit.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1580
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1581
It has no effect for in-memory databases.
1582
This setting can be appended to the database URL: ""jdbc:h2:test;MAX_OPERATION_MEMORY=10000""
Thomas Mueller's avatar
Thomas Mueller committed
1583 1584 1585 1586 1587
","
SET MAX_OPERATION_MEMORY 0
"

"Commands (Other)","SET MODE","
1588
SET MODE { REGULAR | DB2 | DERBY | HSQLDB | MSSQLSERVER | MYSQL | ORACLE | POSTGRESQL }
Thomas Mueller's avatar
Thomas Mueller committed
1589 1590
","
Changes to another database compatibility mode. For details, see Compatibility
Thomas Mueller's avatar
Thomas Mueller committed
1591 1592 1593
Modes in the feature section.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1594
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1595
This command commits an open transaction in this connection.
1596
This setting can be appended to the database URL: ""jdbc:h2:test;MODE=MYSQL""
Thomas Mueller's avatar
Thomas Mueller committed
1597 1598 1599 1600 1601
","
SET MODE HSQLDB
"

"Commands (Other)","SET MULTI_THREADED","
1602
SET MULTI_THREADED { 0 | 1 }
Thomas Mueller's avatar
Thomas Mueller committed
1603
","
1604 1605 1606
Enabled (1) or disabled (0) multi-threading inside the database engine.
MULTI_THREADED is enabled by default with default MVStore storage engine.
MULTI_THREADED is disabled by default when using PageStore storage engine, enabling this with PageStore is experimental only.
Thomas Mueller's avatar
Thomas Mueller committed
1607 1608 1609 1610

This is a global setting, which means it is not possible to open multiple databases with different modes at the same time in the same virtual machine.
This setting is not persistent, however the value is kept until the virtual machine exits or it is changed.

Thomas Mueller's avatar
Thomas Mueller committed
1611
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1612
This command commits an open transaction in this connection.
1613
This setting can be appended to the database URL: ""jdbc:h2:test;MULTI_THREADED=1""
Thomas Mueller's avatar
Thomas Mueller committed
1614 1615 1616 1617 1618
","
SET MULTI_THREADED 1
"

"Commands (Other)","SET OPTIMIZE_REUSE_RESULTS","
1619
SET OPTIMIZE_REUSE_RESULTS { 0 | 1 }
Thomas Mueller's avatar
Thomas Mueller committed
1620 1621 1622
","
Enabled (1) or disabled (0) the result reuse optimization. If enabled,
subqueries and views used as subqueries are only re-run if the data in one of
Thomas Mueller's avatar
Thomas Mueller committed
1623 1624
the tables was changed. This option is enabled by default.

Thomas Mueller's avatar
Thomas Mueller committed
1625
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1626
This command commits an open transaction in this connection.
1627
This setting can be appended to the database URL: ""jdbc:h2:test;OPTIMIZE_REUSE_RESULTS=0""
Thomas Mueller's avatar
Thomas Mueller committed
1628 1629 1630 1631 1632 1633 1634 1635 1636
","
SET OPTIMIZE_REUSE_RESULTS 0
"

"Commands (Other)","SET PASSWORD","
SET PASSWORD string
","
Changes the password of the current user. The password must be in single quotes.
It is case sensitive and can contain spaces.
Thomas Mueller's avatar
Thomas Mueller committed
1637

Thomas Mueller's avatar
Thomas Mueller committed
1638
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1639 1640 1641 1642
","
SET PASSWORD 'abcstzri!.5'
"

1643 1644 1645 1646 1647 1648 1649
"Commands (Other)","SET QUERY_STATISTICS","
SET QUERY_STATISTICS { TRUE | FALSE }
","
Disabled or enables query statistics gathering for the whole database.
The statistics are reflected in the INFORMATION_SCHEMA.QUERY_STATISTICS meta-table.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1650
This command commits an open transaction in this connection.
1651 1652 1653 1654 1655
Admin rights are required to execute this command, as it affects all connections.
","
SET QUERY_STATISTICS FALSE
"

1656 1657 1658 1659 1660 1661 1662 1663 1664 1665 1666 1667 1668
"Commands (Other)","SET QUERY_STATISTICS_MAX_ENTRIES","
SET QUERY_STATISTICS int
","
Set the maximum number of entries in query statistics meta-table.
Default value is 100.

This setting is not persistent.
This command commits an open transaction in this connection.
Admin rights are required to execute this command, as it affects all connections.
","
SET QUERY_STATISTICS_MAX_ENTRIES 500
"

Thomas Mueller's avatar
Thomas Mueller committed
1669 1670 1671 1672 1673
"Commands (Other)","SET QUERY_TIMEOUT","
SET QUERY_TIMEOUT int
","
Set the query timeout of the current session to the given value. The timeout is
in milliseconds. All kinds of statements will throw an exception if they take
Thomas Mueller's avatar
Thomas Mueller committed
1674 1675 1676
longer than the given value. The default timeout is 0, meaning no timeout.

This command does not commit a transaction, and rollback does not affect it.
Thomas Mueller's avatar
Thomas Mueller committed
1677 1678 1679 1680 1681
","
SET QUERY_TIMEOUT 10000
"

"Commands (Other)","SET REFERENTIAL_INTEGRITY","
1682
SET REFERENTIAL_INTEGRITY { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
1683 1684 1685
","
Disabled or enables referential integrity checking for the whole database.
Enabling it does not check existing data. Use ALTER TABLE SET to disable it only
Thomas Mueller's avatar
Thomas Mueller committed
1686 1687 1688
for one table.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1689
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1690
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1691 1692 1693 1694
","
SET REFERENTIAL_INTEGRITY FALSE
"

1695 1696 1697 1698 1699 1700
"Commands (Other)","SET RETENTION_TIME","
SET RETENTION_TIME int
","
This property is only used when using the MVStore storage engine.
How long to retain old, persisted data, in milliseconds.
The default is 45000 (45 seconds), 0 means overwrite data as early as possible.
1701 1702 1703
It is assumed that a file system and hard disk will flush all write buffers within this time.
Using a lower value might be dangerous, unless the file system and hard disk flush the buffers earlier.
To manually flush the buffers, use CHECKPOINT SYNC,
1704 1705 1706 1707
however please note that according to various tests this does not always work as expected
depending on the operating system and hardware.

Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1708
This command commits an open transaction in this connection.
1709 1710 1711 1712 1713 1714
This setting is persistent.
This setting can be appended to the database URL: ""jdbc:h2:test;RETENTION_TIME=0""
","
SET RETENTION_TIME 0
"

Thomas Mueller's avatar
Thomas Mueller committed
1715 1716 1717 1718 1719
"Commands (Other)","SET SALT HASH","
SET SALT bytes HASH bytes
","
Sets the password salt and hash for the current user. The password must be in
single quotes. It is case sensitive and can contain spaces.
Thomas Mueller's avatar
Thomas Mueller committed
1720

Thomas Mueller's avatar
Thomas Mueller committed
1721
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1722 1723 1724 1725 1726 1727 1728 1729 1730
","
SET SALT '00' HASH '1122'
"

"Commands (Other)","SET SCHEMA","
SET SCHEMA schemaName
","
Changes the default schema of the current connection. The default schema is used
in statements where no schema is set explicitly. The default schema for new
Thomas Mueller's avatar
Thomas Mueller committed
1731 1732 1733
connections is PUBLIC.

This command does not commit a transaction, and rollback does not affect it.
1734
This setting can be appended to the database URL: ""jdbc:h2:test;SCHEMA=ABC""
Thomas Mueller's avatar
Thomas Mueller committed
1735 1736 1737 1738 1739 1740 1741 1742 1743
","
SET SCHEMA INFORMATION_SCHEMA
"

"Commands (Other)","SET SCHEMA_SEARCH_PATH","
SET SCHEMA_SEARCH_PATH schemaName [,...]
","
Changes the schema search path of the current connection. The default schema is
used in statements where no schema is set explicitly. The default schema for new
Thomas Mueller's avatar
Thomas Mueller committed
1744 1745 1746
connections is PUBLIC.

This command does not commit a transaction, and rollback does not affect it.
1747
This setting can be appended to the database URL: ""jdbc:h2:test;SCHEMA_SEARCH_PATH=ABC,DEF""
Thomas Mueller's avatar
Thomas Mueller committed
1748 1749 1750 1751 1752 1753 1754 1755 1756
","
SET SCHEMA_SEARCH_PATH INFORMATION_SCHEMA, PUBLIC
"

"Commands (Other)","SET THROTTLE","
SET THROTTLE int
","
Sets the throttle for the current connection. The value is the number of
milliseconds delay after each 50 ms. The default value is 0 (throttling
Thomas Mueller's avatar
Thomas Mueller committed
1757 1758 1759
disabled).

This command does not commit a transaction, and rollback does not affect it.
1760
This setting can be appended to the database URL: ""jdbc:h2:test;THROTTLE=50""
Thomas Mueller's avatar
Thomas Mueller committed
1761 1762 1763 1764 1765
","
SET THROTTLE 200
"

"Commands (Other)","SET TRACE_LEVEL","
1766
SET { TRACE_LEVEL_FILE | TRACE_LEVEL_SYSTEM_OUT } int
Thomas Mueller's avatar
Thomas Mueller committed
1767 1768 1769
","
Sets the trace level for file the file or system out stream. Levels are: 0=off,
1=error, 2=info, 3=debug. The default level is 1 for file and 0 for system out.
1770
To use SLF4J, append "";TRACE_LEVEL_FILE=4"" to the database URL when opening the database.
Thomas Mueller's avatar
Thomas Mueller committed
1771

Thomas Mueller's avatar
Thomas Mueller committed
1772
This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1773
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1774
This command does not commit a transaction, and rollback does not affect it.
1775
This setting can be appended to the database URL: ""jdbc:h2:test;TRACE_LEVEL_SYSTEM_OUT=3""
Thomas Mueller's avatar
Thomas Mueller committed
1776 1777 1778 1779 1780 1781 1782 1783 1784 1785 1786
","
SET TRACE_LEVEL_SYSTEM_OUT 3
"

"Commands (Other)","SET TRACE_MAX_FILE_SIZE","
SET TRACE_MAX_FILE_SIZE int
","
Sets the maximum trace file size. If the file exceeds the limit, the file is
renamed to .old and a new file is created. If another .old file exists, it is
deleted. The default max size is 16 MB.

Thomas Mueller's avatar
Thomas Mueller committed
1787
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1788
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1789
This command commits an open transaction in this connection.
1790
This setting can be appended to the database URL: ""jdbc:h2:test;TRACE_MAX_FILE_SIZE=3""
Thomas Mueller's avatar
Thomas Mueller committed
1791 1792 1793 1794 1795 1796 1797 1798 1799 1800
","
SET TRACE_MAX_FILE_SIZE 10
"

"Commands (Other)","SET UNDO_LOG","
SET UNDO_LOG int
","
Enables (1) or disables (0) the per session undo log. The undo log is enabled by
default. When disabled, transactions can not be rolled back. This setting should
only be used for bulk operations that don't need to be atomic.
Thomas Mueller's avatar
Thomas Mueller committed
1801

Thomas Mueller's avatar
Thomas Mueller committed
1802
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1803 1804 1805 1806 1807 1808 1809 1810
","
SET UNDO_LOG 0
"

"Commands (Other)","SET WRITE_DELAY","
SET WRITE_DELAY int
","
Set the maximum delay between a commit and flushing the log, in milliseconds.
Thomas Mueller's avatar
Thomas Mueller committed
1811 1812
This setting is persistent. The default is 500 ms.

Thomas Mueller's avatar
Thomas Mueller committed
1813
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1814
This command commits an open transaction in this connection.
1815
This setting can be appended to the database URL: ""jdbc:h2:test;WRITE_DELAY=0""
Thomas Mueller's avatar
Thomas Mueller committed
1816 1817 1818 1819 1820
","
SET WRITE_DELAY 2000
"

"Commands (Other)","SHUTDOWN","
1821
SHUTDOWN [ IMMEDIATELY | COMPACT | DEFRAG ]
Thomas Mueller's avatar
Thomas Mueller committed
1822
","
1823 1824
This statement closes all open connections to the database and closes the
database. This command is usually not required, as the database is
Thomas Mueller's avatar
Thomas Mueller committed
1825
closed automatically when the last connection to it is closed.
Thomas Mueller's avatar
Thomas Mueller committed
1826

1827 1828
If no option is used, then the database is closed normally.
All connections are closed, open transactions are rolled back.
Thomas Mueller's avatar
Thomas Mueller committed
1829 1830 1831

SHUTDOWN COMPACT fully compacts the database (re-creating the database may further reduce the database size).
If the database is closed normally (using SHUTDOWN or by closing all connections), then the database is also compacted,
1832
but only for at most the time defined by the database setting ""h2.maxCompactTime"" in milliseconds (see there).
Thomas Mueller's avatar
Thomas Mueller committed
1833 1834

SHUTDOWN IMMEDIATELY closes the database files without any cleanup and without compacting.
Thomas Mueller's avatar
Thomas Mueller committed
1835

1836
SHUTDOWN DEFRAG re-orders the pages when closing the database so that table scans are faster. In case of MVStore it is currently equivalent to COMPACT.
1837

Thomas Mueller's avatar
Thomas Mueller committed
1838
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1839
","
1840
SHUTDOWN COMPACT
Thomas Mueller's avatar
Thomas Mueller committed
1841 1842
"

1843 1844 1845 1846 1847 1848 1849 1850 1851 1852 1853 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 1880 1881 1882 1883 1884 1885 1886 1887 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 1930 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 1974
"Datetime fields","Datetime field","
yearField | monthField | dayOfMonthField
    | hourField | minuteField | secondField
    | millisecondField | microsecondField | nanosecondField
    | timezoneHourField | timezoneMinuteField
    | dayOfWeekField | isoDayOfWeekField
    | weekOfYearField | isoWeekOfYearField
    | quarterField | dayOfYearField | epochField
","
Fields for EXTRACT, DATEADD, and DATEDIFF functions.
","
YEAR
"

"Datetime fields","Year field","
YEAR | YYYY | YY | SQL_TSI_YEAR
","
Year.
","
YEAR
"

"Datetime fields","Month field","
MONTH | MM | M | SQL_TSI_MONTH
","
Month (1-12).
","
MONTH
"

"Datetime fields","Day of month field","
DAY | DD | D | SQL_TSI_DAY
","
Day of month (1-31).
","
DAY
"

"Datetime fields","Hour field","
HOUR | HH | SQL_TSI_HOUR
","
Hour (0-23).
","
HOUR
"

"Datetime fields","Minute field","
MINUTE | MI | N | SQL_TSI_MINUTE
","
Minute (0-59).
","
MINUTE
"

"Datetime fields","Second field","
SECOND | SS | S | SQL_TSI_SECOND
","
Second (0-59).
","
SECOND
"

"Datetime fields","Millisecond field","
MILLISECOND | MS
","
Millisecond (0-999).
","
MILLISECOND
"

"Datetime fields","Microsecond field","
MICROSECOND | MCS
","
Microsecond (0-999999).
","
MICROSECOND
"

"Datetime fields","Nanosecond field","
NANOSECOND | NS
","
Nanosecond (0-999999999).
","
NANOSECOND
"

"Datetime fields","Timezone hour field","
TIMEZONE_HOUR
","
Timezone hour (from -18 to +18).
","
TIMEZONE_HOUR
"

"Datetime fields","Timezone minute field","
TIMEZONE_MINUTE
","
Timezone minute (from -59 to +59).
","
TIMEZONE_MINUTE
"

"Datetime fields","Day of week field","
DAY_OF_WEEK | DAYOFWEEK | DOW
","
Day of week (1-7). Sunday is 1.
","
DAY_OF_WEEK
"

"Datetime fields","ISO day of week field","
ISO_DAY_OF_WEEK
","
ISO day of week (1-7). Monday is 1.
","
ISO_DAY_OF_WEEK
"

"Datetime fields","Week of year field","
WEEK | WW | W | SQL_TSI_WEEK
","
Week of year (1-53).
EXTRACT function uses local rules to get number of week in year.
DATEDIFF function uses Sunday as a first day of week.
","
WEEK
"

"Datetime fields","ISO week of year field","
ISO_WEEK
","
ISO week of year (1-53).
1975 1976
ISO definition is used when first week of year should have at least four days
and week is started with Monday.
1977 1978 1979 1980 1981 1982 1983 1984 1985 1986 1987 1988 1989 1990 1991 1992 1993 1994 1995 1996 1997 1998 1999 2000 2001 2002 2003 2004 2005 2006 2007
","
ISO_WEEK
"

"Datetime fields","Quarter field","
QUARTER
","
Quarter (1-4).
","
QUARTER
"

"Datetime fields","Day of year field","
DAYOFYEAR | DAY_OF_YEAR | DOY | DY
","
Day of year (1-366).
","
DAYOFYEAR
"

"Datetime fields","Epoch field","
EPOCH
","
For TIMESTAMP values number of seconds since 1970-01-01 00:00:00 in local time zone.
For TIMESTAMP WITH TIME ZONE values number of seconds since 1970-01-01 00:00:00 in UTC time zone.
For DATE values number of seconds since 1970-01-01.
For TIME values number of seconds since midnight.
","
EPOCH
"

2008 2009
"Other Grammar","Alias","
name
Thomas Mueller's avatar
Thomas Mueller committed
2010
","
2011
An alias is a name that is only valid in the context of the statement.
Thomas Mueller's avatar
Thomas Mueller committed
2012
","
2013
A
Thomas Mueller's avatar
Thomas Mueller committed
2014 2015
"

2016 2017
"Other Grammar","And Condition","
condition [ { AND condition } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2018
","
2019
Value or condition.
Thomas Mueller's avatar
Thomas Mueller committed
2020
","
2021
ID=1 AND NAME='Hi'
Thomas Mueller's avatar
Thomas Mueller committed
2022 2023
"

2024
"Other Grammar","Array","
2025 2026
ARRAY '[' [ expression, [,...] ] ']'
    | ( [ expression, [ expression [,...] ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
2027
","
2028 2029 2030 2031 2032 2033 2034 2035
An array of values.

The array can be declared with standard ARRAY[] syntax or with H2 syntax.

With standard syntax trailing comma is not allowed.

With H2 syntax an empty array is '()'. Trailing comma is ignored.
An array with one element must contain a trailing comma to be parsed as an array.
Thomas Mueller's avatar
Thomas Mueller committed
2036
","
2037 2038 2039
ARRAY[1, 2]
ARRAY[1]
ARRAY[]
2040
(1, 2)
2041 2042
(1, )
()
Thomas Mueller's avatar
Thomas Mueller committed
2043 2044
"

2045 2046
"Other Grammar","Boolean","
TRUE | FALSE
2047
","
2048
A boolean value.
2049
","
2050
TRUE
2051 2052
"

2053 2054
"Other Grammar","Bytes","
X'hex'
Thomas Mueller's avatar
Thomas Mueller committed
2055
","
2056
A binary value. The hex value is not case sensitive.
Thomas Mueller's avatar
Thomas Mueller committed
2057
","
2058
X'01FF'
Thomas Mueller's avatar
Thomas Mueller committed
2059 2060
"

2061 2062 2063
"Other Grammar","Case","
CASE expression { WHEN expression THEN expression } [...]
[ ELSE expression ] END
Thomas Mueller's avatar
Thomas Mueller committed
2064
","
2065 2066
Returns the first expression where the value is equal to the test expression. If
no else part is specified, return NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2067
","
2068
CASE CNT WHEN 0 THEN 'No' WHEN 1 THEN 'One' ELSE 'Some' END
Thomas Mueller's avatar
Thomas Mueller committed
2069 2070
"

2071 2072 2073
"Other Grammar","Case When","
CASE { WHEN expression THEN expression} [...]
[ ELSE expression ] END
Thomas Mueller's avatar
Thomas Mueller committed
2074
","
2075 2076
Returns the first expression where the condition is true. If no else part is
specified, return NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2077
","
2078 2079 2080 2081
CASE WHEN CNT<10 THEN 'Low' ELSE 'High' END
"

"Other Grammar","Cipher","
2082
AES
2083
","
2084
Only the algorithm AES (""AES-128"") is supported currently.
2085 2086
","
AES
Thomas Mueller's avatar
Thomas Mueller committed
2087 2088
"

2089
"Other Grammar","Column Definition","
2090
dataType [ VISIBLE | INVISIBLE ]
2091 2092 2093
[ { DEFAULT expression
    | AS computedColumnExpression
    | GENERATED {ALWAYS | BY DEFAULT} AS IDENTITY [(sequenceOptions)]} ]
2094
[ ON UPDATE expression ] [ [ NOT ] NULL ]
2095
[ { AUTO_INCREMENT | IDENTITY } [ ( startInt [, incrementInt ] ) ] ]
Thomas Mueller's avatar
Thomas Mueller committed
2096 2097
[ SELECTIVITY selectivity ] [ COMMENT expression ]
[ PRIMARY KEY [ HASH ] | UNIQUE ] [ CHECK condition ]
2098 2099
","
Default expressions are used if no explicit value was used when adding a row.
Thomas Mueller's avatar
Thomas Mueller committed
2100
The computed column expression is evaluated and assigned whenever the row changes.
2101 2102 2103
On update column expression is used if row is updated,
at least one column have a new value that is different from its previous value
and value for this column is not set explicitly in update statement.
2104

2105 2106 2107 2108 2109
Identity, auto-increment, or generated as identity columns are columns with a sequence as the default.
The column declared as the identity columns with IDENTITY data type or with IDENTITY () clause
is implicitly the primary key column of this table.
AUTO_INCREMENT and GENERATED clauses do not create the primary key constraint.
GENERATED ALWAYS is accepted by treated in the same way as GENERATED BY DEFAULT.
Thomas Mueller's avatar
Thomas Mueller committed
2110

2111 2112 2113
The invisible column will not be displayed as a result of SELECT * query.
Otherwise, it works as normal column.

Thomas Mueller's avatar
Thomas Mueller committed
2114 2115
The options PRIMARY KEY, UNIQUE, and CHECK are not supported for ALTER statements.

Thomas Mueller's avatar
Thomas Mueller committed
2116 2117
Check constraints can reference columns of the table,
and they can reference objects that exist while the statement is executed.
Thomas Mueller's avatar
Thomas Mueller committed
2118 2119
Conditions are only checked when a row is added or modified
in the table where the constraint exists.
2120

2121
","
Thomas Mueller's avatar
Thomas Mueller committed
2122 2123 2124
CREATE TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR(255) DEFAULT '');
CREATE TABLE TEST(ID BIGINT IDENTITY);
CREATE TABLE TEST(QUANTITY INT, PRICE DECIMAL, AMOUNT DECIMAL AS QUANTITY*PRICE);
2125 2126
"

2127 2128
"Other Grammar","Comments","
-- anythingUntilEndOfLine | // anythingUntilEndOfLine | /* anythingUntilEndComment */
Thomas Mueller's avatar
Thomas Mueller committed
2129
","
2130 2131 2132
Comments can be used anywhere in a command and are ignored by the database. Line
comments end with a newline. Block comments cannot be nested, but can be
multiple lines long.
Thomas Mueller's avatar
Thomas Mueller committed
2133
","
2134
// This is a comment
Thomas Mueller's avatar
Thomas Mueller committed
2135 2136
"

2137
"Other Grammar","Compare","
2138
<> | <= | >= | = | < | > | != | &&
Thomas Mueller's avatar
Thomas Mueller committed
2139
","
2140
Comparison operator. The operator != is the same as <>.
2141
The operator ""&&"" means overlapping; it can only be used with geometry types.
Thomas Mueller's avatar
Thomas Mueller committed
2142
","
2143
<>
Thomas Mueller's avatar
Thomas Mueller committed
2144 2145 2146
"

"Other Grammar","Condition","
2147
operand [ conditionRightHandSide ] | NOT condition | EXISTS ( select )
Thomas Mueller's avatar
Thomas Mueller committed
2148 2149 2150 2151 2152 2153 2154
","
Boolean value or condition.
","
ID<>2
"

"Other Grammar","Condition Right Hand Side","
2155
compare { { ALL ( select ) } | operand }
2156
    | IS [ NOT ] NULL
2157
    | IS [ NOT ] [ DISTINCT FROM ] operand
2158 2159
    | BETWEEN operand AND operand
    | IN ( { select | expression [,...] } )
2160
    | [ NOT ] [ LIKE | ILIKE ] operand [ ESCAPE string ]
2161
    | [ NOT ] REGEXP operand
Thomas Mueller's avatar
Thomas Mueller committed
2162
","
Thomas Mueller's avatar
Thomas Mueller committed
2163
The right hand side of a condition.
2164

Thomas Mueller's avatar
Thomas Mueller committed
2165
The conditions ""IS [ NOT ]"" and ""IS [ NOT ] DISTINCT FROM"" are null-safe, meaning
2166 2167
NULL is considered the same as NULL, and the condition never evaluates to NULL.

Thomas Mueller's avatar
Thomas Mueller committed
2168 2169 2170 2171 2172
When comparing with LIKE, the wildcards characters are ""_"" (any one character)
and ""%"" (any characters). The database uses an index when comparing with LIKE
except if the operand starts with a wildcard. To search for the characters ""%"" and
""_"", the characters need to be escaped. The default escape character is "" \ "" (backslash).
To select no escape character, use ""ESCAPE ''"" (empty string).
2173 2174 2175
At most one escape character is allowed.
Each character that follows the escape character in the pattern needs to match exactly.
Patterns that end with an escape character are invalid and the expression returns NULL.
2176

2177 2178
ILIKE does a case-insensitive compare.

Thomas Mueller's avatar
Thomas Mueller committed
2179
When comparing with REGEXP, regular expression matching is used.
2180
See Java ""Matcher.find"" for details.
Thomas Mueller's avatar
Thomas Mueller committed
2181 2182 2183 2184
","
LIKE 'Jo%'
"

2185
"Other Grammar","Constraint","
Thomas Mueller's avatar
Thomas Mueller committed
2186 2187 2188 2189 2190
[ constraintNameDefinition ]
{ CHECK expression
    | UNIQUE ( columnName [,...] )
    | referentialConstraint
    | PRIMARY KEY [ HASH ] ( columnName [,...] ) }
Thomas Mueller's avatar
Thomas Mueller committed
2191
","
Thomas Mueller's avatar
Thomas Mueller committed
2192 2193
Defines a constraint.
The check condition must evaluate to TRUE, FALSE or NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2194
TRUE and NULL mean the operation is to be permitted,
Thomas Mueller's avatar
Thomas Mueller committed
2195 2196
and FALSE means the operation is to be rejected.
To prevent NULL in a column, use NOT NULL instead of a check constraint.
Thomas Mueller's avatar
Thomas Mueller committed
2197
","
2198
PRIMARY KEY(ID, NAME)
Thomas Mueller's avatar
Thomas Mueller committed
2199 2200
"

2201 2202
"Other Grammar","Constraint Name Definition","
CONSTRAINT [ IF NOT EXISTS ] newConstraintName
Thomas Mueller's avatar
Thomas Mueller committed
2203
","
2204
Defines a constraint name.
Thomas Mueller's avatar
Thomas Mueller committed
2205
","
2206
CONSTRAINT CONST_ID
Thomas Mueller's avatar
Thomas Mueller committed
2207 2208
"

2209 2210
"Other Grammar","Csv Options","
charsetString [, fieldSepString [, fieldDelimString [, escString [, nullString]]]]]
2211
    | optionString
Thomas Mueller's avatar
Thomas Mueller committed
2212
","
2213
Optional parameters for CSVREAD and CSVWRITE.
2214 2215
Instead of setting the options one by one, all options can be
combined into a space separated key-value pairs, as follows:
Thomas Mueller's avatar
Thomas Mueller committed
2216 2217
""STRINGDECODE('charset=UTF-8 escape=\"" fieldDelimiter=\"" fieldSeparator=, ' ||""
""'lineComment=# lineSeparator=\n null= rowSeparator=')"".
2218
The following options are supported:
2219

2220
""caseSensitiveColumnNames"" (true or false; disabled by default),
2221

Thomas Mueller's avatar
Thomas Mueller committed
2222
""charset"" (for example 'UTF-8'),
2223

Thomas Mueller's avatar
Thomas Mueller committed
2224
""escape"" (the character that escapes the field delimiter),
2225

Thomas Mueller's avatar
Thomas Mueller committed
2226
""fieldDelimiter"" (a double quote by default),
2227

thomasmueller's avatar
thomasmueller committed
2228
""fieldSeparator"" (a comma by default),
2229

2230
""lineComment"" (disabled by default),
2231

2232
""lineSeparator"" (the line separator used for writing; ignored for reading),
2233

Thomas Mueller's avatar
Thomas Mueller committed
2234 2235
""null"", Support reading existing CSV files that contain explicit ""null"" delimiters.
Note that an empty, unquoted values are also treated as null.
2236

2237
""preserveWhitespace"" (true or false; disabled by default),
2238

2239
""writeColumnHeader"" (true or false; enabled by default).
2240

Thomas Mueller's avatar
Thomas Mueller committed
2241
For a newline or other special character, use STRINGDECODE as in the example above.
Thomas Mueller's avatar
Thomas Mueller committed
2242
A space needs to be escaped with a backslash (""'\ '""), and
Thomas Mueller's avatar
Thomas Mueller committed
2243 2244 2245
a backslash needs to be escaped with another backslash (""'\\'"").
All other characters are not to be escaped, that means
newline and tab characters are written as such.
Thomas Mueller's avatar
Thomas Mueller committed
2246
","
2247
CALL CSVWRITE('test2.csv', 'SELECT * FROM TEST', 'charset=UTF-8 fieldSeparator=|');
Thomas Mueller's avatar
Thomas Mueller committed
2248 2249
"

2250 2251 2252
"Other Grammar","Data Type","
intType | booleanType | tinyintType | smallintType | bigintType | identityType
    | decimalType | doubleType | realType | dateType | timeType | timestampType
2253 2254
    | timestampWithTimeZoneType | binaryType | otherType | varcharType
    | varcharIgnorecaseType | charType | blobType | clobType | uuidType
2255
    | arrayType | enumType | intervalType
Thomas Mueller's avatar
Thomas Mueller committed
2256
","
2257
A data type definition.
Thomas Mueller's avatar
Thomas Mueller committed
2258
","
2259
INT
Thomas Mueller's avatar
Thomas Mueller committed
2260 2261
"

2262 2263
"Other Grammar","Date","
DATE 'yyyy-MM-dd'
Thomas Mueller's avatar
Thomas Mueller committed
2264
","
2265
A date literal. The limitations are the same as for the Java data type
2266
""java.sql.Date"", but for compatibility with other databases the suggested minimum
2267
and maximum years are 0001 and 9999.
Thomas Mueller's avatar
Thomas Mueller committed
2268
","
2269
DATE '2004-12-31'
Thomas Mueller's avatar
Thomas Mueller committed
2270 2271
"

2272
"Other Grammar","Decimal","
2273 2274
[ + | - ] { { number [ . number ] } | { . number } }
[ E [ + | - ] expNumber [...] ] ]
2275
","
Thomas Mueller's avatar
Thomas Mueller committed
2276 2277 2278 2279 2280 2281
A decimal number with fixed precision and scale.
Internally, ""java.lang.BigDecimal"" is used.
To ensure the floating point representation is used, use CAST(X AS DOUBLE).
There are some special decimal values: to represent positive infinity, use ""POWER(0, -1)"";
for negative infinity, use ""(-POWER(0, -1))""; for -0.0, use ""(-CAST(0 AS DOUBLE))"";
for ""NaN"" (not a number), use ""SQRT(-1)"".
2282
","
Thomas Mueller's avatar
Thomas Mueller committed
2283 2284 2285
SELECT -1600.05
SELECT CAST(0 AS DOUBLE)
SELECT -1.4e-10
2286 2287
"

2288 2289
"Other Grammar","Digit","
0-9
Thomas Mueller's avatar
Thomas Mueller committed
2290
","
2291
A digit.
Thomas Mueller's avatar
Thomas Mueller committed
2292
","
2293
0
Thomas Mueller's avatar
Thomas Mueller committed
2294 2295
"

2296 2297
"Other Grammar","Dollar Quoted String","
$$anythingExceptTwoDollarSigns$$
Thomas Mueller's avatar
Thomas Mueller committed
2298
","
2299 2300 2301
A string starts and ends with two dollar signs. Two dollar signs are not allowed
within the text. A whitespace is required before the first set of dollar signs.
No escaping is required within the text.
Thomas Mueller's avatar
Thomas Mueller committed
2302
","
2303
$$John's car$$
Thomas Mueller's avatar
Thomas Mueller committed
2304 2305
"

2306 2307
"Other Grammar","Expression","
andCondition [ { OR andCondition } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2308
","
2309
Value or condition.
Thomas Mueller's avatar
Thomas Mueller committed
2310
","
2311
ID=1 OR NAME='Hi'
Thomas Mueller's avatar
Thomas Mueller committed
2312 2313
"

2314
"Other Grammar","Factor","
2315
term [ { { * | / | % } term } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2316
","
2317
A value or a numeric factor.
Thomas Mueller's avatar
Thomas Mueller committed
2318
","
2319
ID * 10
Thomas Mueller's avatar
Thomas Mueller committed
2320 2321
"

2322 2323
"Other Grammar","Hex","
{ { digit | a-f | A-F } { digit | a-f | A-F } } [...]
Thomas Mueller's avatar
Thomas Mueller committed
2324
","
2325 2326
The hexadecimal representation of a number or of bytes. Two characters are one
byte.
Thomas Mueller's avatar
Thomas Mueller committed
2327
","
2328
cafe
Thomas Mueller's avatar
Thomas Mueller committed
2329 2330
"

2331 2332
"Other Grammar","Hex Number","
[ + | - ] 0x hex
Thomas Mueller's avatar
Thomas Mueller committed
2333
","
2334
A number written in hexadecimal notation.
Thomas Mueller's avatar
Thomas Mueller committed
2335
","
2336
0xff
Thomas Mueller's avatar
Thomas Mueller committed
2337 2338
"

2339 2340
"Other Grammar","Index Column","
columnName [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
Thomas Mueller's avatar
Thomas Mueller committed
2341
","
2342 2343 2344
Indexes this column in ascending or descending order. Usually it is not required
to specify the order; however doing so will speed up large queries that order
the column in the same way.
Thomas Mueller's avatar
Thomas Mueller committed
2345
","
2346
NAME
Thomas Mueller's avatar
Thomas Mueller committed
2347 2348
"

2349 2350 2351 2352 2353 2354 2355 2356 2357 2358 2359
"Other Grammar","Insert columns and source","
{ [ ( columnName [,...] ) ]
    { VALUES { ( { DEFAULT | expression } [,...] ) } [,...]
        | [ DIRECT ] [ SORTED ] select } } |
    { SET { columnName = { DEFAULT | expression } } [,...] }
","
Names of columns and their values for INSERT statement.
","
(ID, NAME) VALUES (1, 'Test')
"

Thomas Mueller's avatar
Thomas Mueller committed
2360
"Other Grammar","Int","
2361
[ + | - ] number
Thomas Mueller's avatar
Thomas Mueller committed
2362 2363 2364 2365 2366 2367 2368
","
The maximum integer number is 2147483647, the minimum is -2147483648.
","
10
"

"Other Grammar","Long","
2369
[ + | - ] number
Thomas Mueller's avatar
Thomas Mueller committed
2370 2371 2372 2373 2374 2375
","
Long numbers are between -9223372036854775808 and 9223372036854775807.
","
100000
"

2376 2377 2378 2379 2380 2381 2382 2383 2384
"Other Grammar","Merge when clause","
mergeWhenMatchedClause|mergeWhenNotMatchedClause
","
WHEN MATCHED or WHEN NOT MATCHED clause for MERGE USING command.
","
WHEN MATCHED THEN DELETE
"

"Other Grammar","Merge when matched clause","
2385 2386 2387
WHEN MATCHED [ AND expression ] THEN
UPDATE SET setClauseList
    | DELETE
2388
    | {UPDATE SET setClauseList [ WHERE expression ] DELETE [ WHERE expression ]}
2389 2390 2391 2392
","
WHEN MATCHED clause for MERGE USING command.

If both UPDATE and DELETE are specified, DELETE can delete only rows that were updated,
2393
WHERE condition in DELETE clause can be used to specify which updated rows should be deleted.
2394 2395 2396 2397 2398 2399 2400
This condition checks values in updated row.
","
WHEN MATCHED THEN UPDATE SET VALUE = S.VALUE
WHEN MATCHED THEN DELETE
"

"Other Grammar","Merge when not matched clause","
2401
WHEN NOT MATCHED [ AND expression ] THEN INSERT insertColumnsAndSource
2402 2403 2404 2405 2406 2407
","
WHEN NOT MATCHED clause for MERGE USING command.
","
WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (S.ID, S.NAME)
"

2408
"Other Grammar","Name","
2409
{ { A-Z|_ } [ { A-Z|_|0-9 } [...] ] } | quotedName
Thomas Mueller's avatar
Thomas Mueller committed
2410
","
2411
Names are not case sensitive. There is no maximum name length.
Thomas Mueller's avatar
Thomas Mueller committed
2412
","
2413
TEST
Thomas Mueller's avatar
Thomas Mueller committed
2414 2415
"

2416 2417
"Other Grammar","Null","
NULL
Thomas Mueller's avatar
Thomas Mueller committed
2418
","
2419
NULL is a value without data type and means 'unknown value'.
Thomas Mueller's avatar
Thomas Mueller committed
2420
","
2421
NULL
Thomas Mueller's avatar
Thomas Mueller committed
2422 2423
"

2424 2425 2426 2427 2428 2429 2430 2431
"Other Grammar","Number","
digit [...]
","
The maximum length of the number depends on the data type used.
","
100
"

Thomas Mueller's avatar
Thomas Mueller committed
2432
"Other Grammar","Numeric","
Thomas Mueller's avatar
Thomas Mueller committed
2433
decimal | int | long | hexNumber
Thomas Mueller's avatar
Thomas Mueller committed
2434
","
Thomas Mueller's avatar
Thomas Mueller committed
2435
The data type of a numeric value is always the lowest possible for the given value.
Thomas Mueller's avatar
Thomas Mueller committed
2436 2437 2438 2439 2440 2441 2442
If the number contains a dot this is decimal; otherwise it is int, long, or decimal (depending on the value).
","
SELECT -1600.05
SELECT CAST(0 AS DOUBLE)
SELECT -1.4e-10
"

2443 2444
"Other Grammar","Operand","
summand [ { || summand } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2445
","
2446
A value or a concatenation of values.
Thomas Mueller's avatar
Thomas Mueller committed
2447
In the default mode, the result is NULL if either parameter is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2448
","
2449
'Hi' || ' Eva'
Thomas Mueller's avatar
Thomas Mueller committed
2450 2451
"

2452 2453
"Other Grammar","Order","
{ int | expression } [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
Thomas Mueller's avatar
Thomas Mueller committed
2454
","
2455 2456 2457
Sorts the result by the given column number, or by an expression. If the
expression is a single parameter, then the value is interpreted as a column
number. Negative column numbers reverse the sort order.
Thomas Mueller's avatar
Thomas Mueller committed
2458
","
2459
NAME DESC NULLS LAST
Thomas Mueller's avatar
Thomas Mueller committed
2460 2461
"

2462 2463
"Other Grammar","Quoted Name","
""anythingExceptDoubleQuote""
Thomas Mueller's avatar
Thomas Mueller committed
2464
","
2465 2466 2467
Quoted names are case sensitive, and can contain spaces. There is no maximum
name length. Two double quotes can be used to create a single double quote
inside an identifier.
Thomas Mueller's avatar
Thomas Mueller committed
2468
","
2469
""FirstName""
Thomas Mueller's avatar
Thomas Mueller committed
2470 2471
"

2472 2473 2474
"Other Grammar","Referential Constraint","
FOREIGN KEY ( columnName [,...] )
REFERENCES [ refTableName ] [ ( refColumnName [,...] ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2475
[ ON DELETE referentialAction ] [ ON UPDATE referentialAction ]
Thomas Mueller's avatar
Thomas Mueller committed
2476
","
Thomas Mueller's avatar
Thomas Mueller committed
2477 2478 2479
Defines a referential constraint.
If the table name is not specified, then the same table is referenced.
RESTRICT is the default action.
Thomas Mueller's avatar
Thomas Mueller committed
2480 2481 2482
If the referenced columns are not specified, then the primary key columns are used.
The required indexes are automatically created if required.
Some tables may not be referenced, such as metadata tables.
Thomas Mueller's avatar
Thomas Mueller committed
2483
","
2484
FOREIGN KEY(ID) REFERENCES TEST(ID)
Thomas Mueller's avatar
Thomas Mueller committed
2485 2486
"

Thomas Mueller's avatar
Thomas Mueller committed
2487 2488 2489 2490 2491 2492 2493 2494 2495 2496 2497
"Other Grammar","Referential Action","
CASCADE | RESTRICT | NO ACTION | SET { DEFAULT | NULL }
","
The action CASCADE will cause conflicting rows in the referencing (child) table to be deleted or updated.
RESTRICT is the default action.
As this database does not support deferred checking, RESTRICT and NO ACTION will both throw an exception if the constraint is violated.
The action SET DEFAULT will set the column in the referencing (child) table to the default value, while SET NULL will set it to NULL.
","
FOREIGN KEY(ID) REFERENCES TEST(ID) ON UPDATE CASCADE
"

2498
"Other Grammar","Script Compression Encryption","
2499 2500
[ COMPRESSION { DEFLATE | LZF | ZIP | GZIP } ]
[ CIPHER cipher PASSWORD string ]
Thomas Mueller's avatar
Thomas Mueller committed
2501
","
2502 2503
The compression and encryption algorithm to use for script files.
When using encryption, only DEFLATE and LZF are supported.
Thomas Mueller's avatar
Thomas Mueller committed
2504 2505 2506 2507 2508
LZF is faster but uses more space.
","
COMPRESSION LZF
"

2509
"Other Grammar","Select Expression","
2510
wildcardExpression | expression [ [ AS ] columnAlias ]
Thomas Mueller's avatar
Thomas Mueller committed
2511
","
2512
An expression in a SELECT statement.
Thomas Mueller's avatar
Thomas Mueller committed
2513
","
2514
ID AS VALUE
Thomas Mueller's avatar
Thomas Mueller committed
2515 2516
"

2517 2518 2519 2520 2521 2522 2523 2524 2525 2526 2527 2528 2529
"Other Grammar","Sequence options","
[ START WITH long ]
[ INCREMENT BY long ]
[ MINVALUE long | NOMINVALUE | NO MINVALUE ]
[ MAXVALUE long | NOMAXVALUE | NO MAXVALUE ]
[ CYCLE long | NOCYCLE | NO CYCLE ]
[ CACHE long | NOCACHE | NO CACHE ]
","
Options of a sequence.
","
START WITH 1
"

2530
"Other Grammar","Set clause list","
2531 2532
{ { columnName = { DEFAULT | expression } } [,...] }
    | { ( columnName [,...] ) = ( select ) }
2533 2534 2535 2536 2537 2538
","
List of SET clauses.
","
NAME = 'Test', VALUE = 2
"

2539 2540
"Other Grammar","String","
'anythingExceptSingleQuote'
Thomas Mueller's avatar
Thomas Mueller committed
2541
","
2542 2543
A string starts and ends with a single quote. Two single quotes can be used to
create a single quote inside a string.
Thomas Mueller's avatar
Thomas Mueller committed
2544
","
2545
'John''s car'
Thomas Mueller's avatar
Thomas Mueller committed
2546 2547
"

2548 2549
"Other Grammar","Summand","
factor [ { { + | - } factor } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2550
","
Thomas Mueller's avatar
Thomas Mueller committed
2551
A value or a numeric sum.
Thomas Mueller's avatar
Thomas Mueller committed
2552

Thomas Mueller's avatar
Thomas Mueller committed
2553
Please note the text concatenation operator is ""||"".
Thomas Mueller's avatar
Thomas Mueller committed
2554
","
2555
ID + 20
Thomas Mueller's avatar
Thomas Mueller committed
2556 2557
"

2558
"Other Grammar","Table Expression","
2559 2560
{ [ schemaName. ] tableName | ( select ) | valuesExpression }
[ [ AS ] newTableAlias [ ( columnName [,...] ) ] ]
2561
[ USE INDEX ([ indexName [,...] ]) ]
2562 2563
[ { { LEFT | RIGHT } [ OUTER ] | [ INNER ] | CROSS | NATURAL }
    JOIN tableExpression [ ON expression ] ]
Thomas Mueller's avatar
Thomas Mueller committed
2564
","
2565 2566 2567
Joins a table. The join expression is not supported for cross and natural joins.
A natural join is an inner join, where the condition is automatically on the
columns with the same name.
Thomas Mueller's avatar
Thomas Mueller committed
2568
","
2569
TEST AS T LEFT JOIN TEST AS T1 ON T.ID = T1.ID
Thomas Mueller's avatar
Thomas Mueller committed
2570 2571
"

2572 2573 2574 2575 2576 2577 2578 2579 2580
"Other Grammar","Values Expression","
VALUES { ( expression [,...] ) } [,...]
","
A list of rows that can be used like a table.
The column list of the resulting table is C1, C2, and so on.
","
SELECT * FROM (VALUES(1, 'Hello'), (2, 'World')) AS V;
"

2581 2582 2583 2584 2585 2586 2587 2588 2589 2590
"Other Grammar","Wildcard expression","
{* | tableAlias.*} [EXCEPT ([tableAlias.]columnName, [,...])]
","
A wildcard expression in a SELECT statement.
A wildcard expression represents all visible columns. Some columns can be excluded with optional EXCEPT clause.
","
*
* EXCEPT (DATA)
"

2591 2592
"Other Grammar","Window name or specification","
windowName | windowSpecification
2593
","
2594
A window name or inline specification for a window function or aggregate.
2595

2596 2597 2598
Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
2599
W1
2600
(ORDER BY ID)
2601 2602 2603 2604 2605 2606 2607 2608
"

"Other Grammar","Window specification","
([existingWindowName]
[PARTITION BY expression [,...]] [ORDER BY order [,...]]
[windowFrame])
","
A window specification for a window, window function or aggregate.
2609 2610 2611 2612 2613 2614 2615 2616 2617 2618 2619 2620

If name of an existing window is specified its clauses are used by default.

Optional window partition clause separates rows into independent partitions.
Each partition is processed separately.
If this clause is not present there is one implicit partition with all rows.

Optional window order clause specifies order of rows in the partition.
If some rows have the same order position they are considered as a group of rows in optional window frame clause.

Optional window frame clause specifies which rows are processed by a window function,
see its documentation for a more details.
2621 2622 2623
","
()
(W1 ORDER BY ID)
2624 2625
(PARTITION BY CATEGORY)
(PARTITION BY CATEGORY ORDER BY NAME, ID)
2626 2627 2628 2629
(ORDER BY Y RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE TIES)
"

"Other Grammar","Window frame","
2630
ROWS|RANGE|GROUP
2631
{windowFramePreceding|BETWEEN windowFrameBound AND windowFrameBound}
2632 2633 2634
[EXCLUDE {CURRENT ROW|GROUP|TIES|NO OTHERS}]
","
A window frame clause.
2635
May be specified only for aggregates and FIRST_VALUE(), LAST_VALUE(), and NTH_VALUE() window functions.
2636 2637 2638 2639 2640 2641 2642 2643 2644 2645 2646 2647 2648 2649 2650 2651 2652 2653

If this clause is not specified for an aggregate or window function that supports this clause
the default window frame depends on window order clause.
If window order clause is also not specified
the default window frame contains all the rows in the partition.
If window order clause is specified
the default window frame contains all preceding rows and all rows from the current group.

Window frame unit determines how rows or groups of rows are selected and counted.
If ROWS is specified rows are not grouped in any way and relative numbers of rows are used in bounds.
If RANGE is specified rows are grouped according window order clause,
preceding and following values mean the difference between value in the current row and in the target rows,
and CURRENT ROW in bound specification means current group of rows.
If GROUPS is specified rows are grouped according window order clause,
preceding and following values means relative number of groups of rows,
and CURRENT ROW in bound specification means current group of rows.

If only window frame preceding clause is specified it is treated as
2654
BETWEEN windowFramePreceding AND CURRENT ROW.
2655 2656 2657 2658 2659 2660

Optional window frame exclusion clause specifies rows that should be excluded from the frame.
EXCLUDE CURRENT ROW excludes only the current row regardless the window frame unit.
EXCLUDE GROUP excludes the whole current group of rows, including the current row.
EXCLUDE TIES excludes the current group of rows, but not the current row.
EXCLUDE NO OTHERS is default and it does not exclude anything.
2661
","
2662
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE TIES
2663 2664
"

2665 2666 2667 2668 2669 2670 2671 2672 2673 2674 2675
"Other Grammar","Window frame preceding","
UNBOUNDED PRECEDING|value PRECEDING|CURRENT ROW
","
A window frame preceding clause.
If value is specified it should be non-negative value or parameter.
","
UNBOUNDED PRECEDING
1 PRECEDING
CURRENT ROW
"

2676 2677 2678
"Other Grammar","Window frame bound","
UNBOUNDED PRECEDING|value PRECEDING|CURRENT ROW
    |value FOLLOWING|UNBOUNDED FOLLOWING
2679
","
2680
A window frame bound clause.
2681 2682
If value is specified it should be non-negative value or parameter.
","
2683
UNBOUNDED PRECEDING
2684 2685 2686 2687 2688
UNBOUNDED FOLLOWING
1 FOLLOWING
CURRENT ROW
"

2689 2690 2691 2692 2693 2694 2695 2696 2697 2698 2699 2700
"Other Grammar","Term","
value
    | columnName
    | ?[ int ]
    | NEXT VALUE FOR sequenceName
    | function
    | { - | + } term
    | ( expression )
    | select
    | case
    | caseWhen
    | tableAlias.columnName
2701
    | userDefinedFunctionName
Thomas Mueller's avatar
Thomas Mueller committed
2702
","
2703
A value. Parameters can be indexed, for example ""?1"" meaning the first parameter.
Thomas Mueller's avatar
Thomas Mueller committed
2704
Each table has a pseudo-column named ""_ROWID_"" that contains the unique row identifier.
Thomas Mueller's avatar
Thomas Mueller committed
2705
","
2706 2707 2708 2709
'Hello'
"

"Other Grammar","Time","
2710
TIME [ WITHOUT TIME ZONE ] 'hh:mm:ss[.nnnnnnnnn]'
2711
","
2712
A time literal. A value is between 0:00:00 and 23:59:59.999999999
2713
and has nanosecond resolution.
2714 2715 2716 2717 2718
","
TIME '23:59:59'
"

"Other Grammar","Timestamp","
2719
TIMESTAMP [ WITHOUT TIME ZONE ] 'yyyy-MM-dd hh:mm:ss[.nnnnnnnnn]'
2720 2721
","
A timestamp literal. The limitations are the same as for the Java data type
2722
""java.sql.Timestamp"", but for compatibility with other databases the suggested
2723 2724 2725 2726 2727
minimum and maximum years are 0001 and 9999.
","
TIMESTAMP '2005-12-31 23:59:59'
"

2728
"Other Grammar","Timestamp with time zone","
2729
TIMESTAMP WITH TIME ZONE 'yyyy-MM-dd hh:mm:ss[.nnnnnnnnn]
2730 2731 2732 2733 2734 2735 2736 2737 2738 2739 2740
[Z | { - | + } timeZoneOffsetString | timeZoneNameString ]'
","
A timestamp with time zone literal.
If name of time zone is specified it will be converted to time zone offset.
","
TIMESTAMP WITH TIME ZONE '2005-12-31 23:59:59Z'
TIMESTAMP WITH TIME ZONE '2005-12-31 23:59:59-10:00'
TIMESTAMP WITH TIME ZONE '2005-12-31 23:59:59.123+05'
TIMESTAMP WITH TIME ZONE '2005-12-31 23:59:59.123456789 Europe/London'
"

2741 2742 2743 2744 2745 2746 2747 2748
"Other Grammar","Date and time","
date | time | timestamp | timestampWithTimeZone
","
A literal value of any date-time data type.
","
TIMESTAMP '1999-01-31 10:00:00'
"

2749 2750 2751 2752 2753 2754 2755 2756 2757 2758 2759 2760 2761 2762 2763 2764 2765 2766 2767 2768 2769 2770 2771 2772 2773 2774 2775 2776 2777 2778 2779 2780 2781 2782 2783 2784 2785 2786 2787 2788 2789 2790 2791 2792 2793 2794 2795 2796 2797 2798 2799 2800 2801 2802 2803 2804 2805 2806 2807 2808 2809
"Other Grammar","INTERVAL YEAR","
INTERVAL [-|+] '[-|+]yearInt' YEAR
","
An INTERVAL YEAR literal.
","
INTERVAL '10' YEAR
"

"Other Grammar","INTERVAL MONTH","
INTERVAL [-|+] '[-|+]monthInt' MONTH
","
An INTERVAL MONTH literal.
","
INTERVAL '10' MONTH
"

"Other Grammar","INTERVAL DAY","
INTERVAL [-|+] '[-|+]dayInt' DAY
","
An INTERVAL DAY literal.
","
INTERVAL '10' DAY
"

"Other Grammar","INTERVAL HOUR","
INTERVAL [-|+] '[-|+]hourInt' HOUR
","
An INTERVAL HOUR literal.
","
INTERVAL '10' HOUR
"

"Other Grammar","INTERVAL MINUTE","
INTERVAL [-|+] '[-|+]minuteInt' MINUTE
","
An INTERVAL MINUTE literal.
","
INTERVAL '10' MINUTE
"

"Other Grammar","INTERVAL SECOND","
INTERVAL [-|+] '[-|+]secondInt[.nnnnnnnnn]' SECOND
","
An INTERVAL SECOND literal.
","
INTERVAL '10.123' SECOND
"

"Other Grammar","INTERVAL YEAR TO MONTH","
INTERVAL [-|+] '[-|+]yearInt-monthInt' YEAR TO MONTH
","
An INTERVAL YEAR TO MONTH literal.
","
INTERVAL '1-6' YEAR TO MONTH
"

"Other Grammar","INTERVAL DAY TO HOUR","
INTERVAL [-|+] '[-|+]dayInt hoursInt' DAY TO HOUR
","
An INTERVAL DAY TO HOUR literal.
","
2810
INTERVAL '10 11' DAY TO HOUR
2811 2812 2813 2814 2815 2816 2817 2818 2819 2820 2821 2822 2823 2824 2825 2826 2827 2828 2829 2830 2831 2832 2833 2834 2835 2836 2837 2838 2839 2840 2841 2842 2843 2844 2845 2846 2847 2848 2849 2850 2851 2852 2853 2854
"

"Other Grammar","INTERVAL DAY TO MINUTE","
INTERVAL [-|+] '[-|+]dayInt hh:mm' DAY TO MINUTE
","
An INTERVAL DAY TO MINUTE literal.
","
INTERVAL '10 11:12' DAY TO MINUTE
"

"Other Grammar","INTERVAL DAY TO SECOND","
INTERVAL [-|+] '[-|+]dayInt hh:mm:ss[.nnnnnnnnn]' DAY TO SECOND
","
An INTERVAL DAY TO SECOND literal.
","
INTERVAL '10 11:12:13.123' DAY TO SECOND
"

"Other Grammar","INTERVAL HOUR TO MINUTE","
INTERVAL [-|+] '[-|+]hh:mm' HOUR TO MINUTE
","
An INTERVAL HOUR TO MINUTE literal.
","
INTERVAL '10:11' HOUR TO MINUTE
"

"Other Grammar","INTERVAL HOUR TO SECOND","
INTERVAL [-|+] '[-|+]hh:mm:ss[.nnnnnnnnn]' HOUR TO SECOND
","
An INTERVAL HOUR TO SECOND literal.
","
INTERVAL '10:11:12.123' HOUR TO SECOND
"

"Other Grammar","INTERVAL MINUTE TO SECOND","
INTERVAL [-|+] '[-|+]mm:ss[.nnnnnnnnn]' MINUTE TO SECOND
","
An INTERVAL MINUTE TO SECOND literal.
","
INTERVAL '11:12.123' MINUTE TO SECOND
"

"Other Grammar","Interval","
intervalYear | intervalMonth | intervalDay | intervalHour | intervalMinute
2855 2856 2857
    | intervalSecond | intervalYearToMonth | intervalDayToHour
    | intervalDayToMinute | intervalDayToSecond | intervalHourToMinute
    | intervalHourToSecond | intervalMinuteToSecond
2858 2859 2860 2861 2862 2863
","
An interval literal.
","
INTERVAL '1-2' YEAR TO MONTH
"

2864
"Other Grammar","Value","
2865
string | dollarQuotedString | numeric | dateAndTime | boolean | bytes
2866
    | interval | array | null
2867
","
Thomas Mueller's avatar
Thomas Mueller committed
2868
A literal value of any data type, or null.
2869 2870
","
10
Thomas Mueller's avatar
Thomas Mueller committed
2871 2872 2873 2874 2875 2876 2877
"

"Data Types","INT Type","
INT | INTEGER | MEDIUMINT | INT4 | SIGNED
","
Possible values: -2147483648 to 2147483647.

2878
Mapped to ""java.lang.Integer"".
Thomas Mueller's avatar
Thomas Mueller committed
2879 2880 2881 2882 2883 2884 2885 2886 2887
","
INT
"

"Data Types","BOOLEAN Type","
BOOLEAN | BIT | BOOL
","
Possible values: TRUE and FALSE.

2888
Mapped to ""java.lang.Boolean"".
Thomas Mueller's avatar
Thomas Mueller committed
2889 2890 2891 2892 2893 2894 2895 2896 2897
","
BOOLEAN
"

"Data Types","TINYINT Type","
TINYINT
","
Possible values are: -128 to 127.

2898
Mapped to ""java.lang.Byte"".
Thomas Mueller's avatar
Thomas Mueller committed
2899 2900 2901 2902 2903 2904 2905 2906 2907
","
TINYINT
"

"Data Types","SMALLINT Type","
SMALLINT | INT2 | YEAR
","
Possible values: -32768 to 32767.

2908
Mapped to ""java.lang.Short"".
Thomas Mueller's avatar
Thomas Mueller committed
2909 2910 2911 2912 2913 2914 2915 2916 2917
","
SMALLINT
"

"Data Types","BIGINT Type","
BIGINT | INT8
","
Possible values: -9223372036854775808 to 9223372036854775807.

2918
Mapped to ""java.lang.Long"".
Thomas Mueller's avatar
Thomas Mueller committed
2919 2920 2921 2922 2923 2924 2925 2926 2927 2928 2929
","
BIGINT
"

"Data Types","IDENTITY Type","
IDENTITY
","
Auto-Increment value. Possible values: -9223372036854775808 to
9223372036854775807. Used values are never re-used, even when the transaction is
rolled back.

2930
Mapped to ""java.lang.Long"".
Thomas Mueller's avatar
Thomas Mueller committed
2931 2932 2933 2934 2935
","
IDENTITY
"

"Data Types","DECIMAL Type","
2936
{ DECIMAL | NUMBER | DEC | NUMERIC } ( precisionInt [ , scaleInt ] )
Thomas Mueller's avatar
Thomas Mueller committed
2937 2938 2939 2940
","
Data type with fixed precision and scale. This data type is recommended for
storing currency values.

2941
Mapped to ""java.math.BigDecimal"".
Thomas Mueller's avatar
Thomas Mueller committed
2942 2943 2944 2945 2946
","
DECIMAL(20, 2)
"

"Data Types","DOUBLE Type","
2947
{ DOUBLE [ PRECISION ] | FLOAT [ ( precisionInt ) ] | FLOAT8 }
Thomas Mueller's avatar
Thomas Mueller committed
2948
","
Thomas Mueller's avatar
Thomas Mueller committed
2949
A floating point number. Should not be used to represent currency values, because
Thomas Mueller's avatar
Thomas Mueller committed
2950
of rounding problems.
2951
If precision value is specified for FLOAT type name, it should be from 25 to 53.
Thomas Mueller's avatar
Thomas Mueller committed
2952

2953
Mapped to ""java.lang.Double"".
Thomas Mueller's avatar
Thomas Mueller committed
2954 2955 2956 2957 2958
","
DOUBLE
"

"Data Types","REAL Type","
2959
{ REAL | FLOAT ( precisionInt ) | FLOAT4 }
Thomas Mueller's avatar
Thomas Mueller committed
2960
","
Thomas Mueller's avatar
Thomas Mueller committed
2961
A single precision floating point number. Should not be used to represent currency
Thomas Mueller's avatar
Thomas Mueller committed
2962
values, because of rounding problems.
2963
Precision value for FLOAT type name should be from 0 to 24.
Thomas Mueller's avatar
Thomas Mueller committed
2964

2965
Mapped to ""java.lang.Float"".
Thomas Mueller's avatar
Thomas Mueller committed
2966 2967 2968 2969 2970
","
REAL
"

"Data Types","TIME Type","
2971
TIME [ ( precisionInt ) ] [ WITHOUT TIME ZONE ]
Thomas Mueller's avatar
Thomas Mueller committed
2972
","
2973
The time data type. The format is hh:mm:ss[.nnnnnnnnn].
2974
If fractional seconds precision is specified it should be from 0 to 9, 0 is default.
Thomas Mueller's avatar
Thomas Mueller committed
2975

2976
Mapped to ""java.sql.Time"". When converted to a ""java.sql.Date"", the date is set to ""1970-01-01"".
2977
""java.time.LocalTime"" is also supported on Java 8 and later versions.
2978
Use ""java.time.LocalTime"" or ""String"" instead of ""java.sql.Time"" when non-zero precision is needed.
2979 2980
Cast from higher fractional seconds precision to lower fractional seconds precision performs round half up;
if result of rounding is higher than maximum supported value 23:59:59.999999999 it is saturated to 23:59:59.999999999.
Thomas Mueller's avatar
Thomas Mueller committed
2981 2982
","
TIME
2983
TIME(9)
Thomas Mueller's avatar
Thomas Mueller committed
2984 2985 2986 2987 2988
"

"Data Types","DATE Type","
DATE
","
Thomas Mueller's avatar
Thomas Mueller committed
2989
The date data type. The format is yyyy-MM-dd.
Thomas Mueller's avatar
Thomas Mueller committed
2990

2991
Mapped to ""java.sql.Date"", with the time set to ""00:00:00""
Thomas Mueller's avatar
Thomas Mueller committed
2992
(or to the next possible time if midnight doesn't exist for the given date and timezone due to a daylight saving change).
2993
""java.time.LocalDate"" is also supported on Java 8 and later versions.
Thomas Mueller's avatar
Thomas Mueller committed
2994 2995 2996 2997 2998
","
DATE
"

"Data Types","TIMESTAMP Type","
2999
{ TIMESTAMP [ ( precisionInt ) ] [ WITHOUT TIME ZONE ]
3000
    | DATETIME [ ( precisionInt ) ] | SMALLDATETIME }
Thomas Mueller's avatar
Thomas Mueller committed
3001
","
Thomas Mueller's avatar
Thomas Mueller committed
3002
The timestamp data type. The format is yyyy-MM-dd hh:mm:ss[.nnnnnnnnn].
3003
Stored internally as a BCD-encoded date, and nanoseconds since midnight.
3004
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3005
Fractional seconds precision of SMALLDATETIME is always 0 and cannot be specified.
Thomas Mueller's avatar
Thomas Mueller committed
3006

3007 3008
Mapped to ""java.sql.Timestamp"" (""java.util.Date"" may be used too).
""java.time.LocalDateTime"" is also supported on Java 8 and later versions.
3009
Cast from higher fractional seconds precision to lower fractional seconds precision performs round half up.
Thomas Mueller's avatar
Thomas Mueller committed
3010 3011
","
TIMESTAMP
3012
TIMESTAMP(9)
Thomas Mueller's avatar
Thomas Mueller committed
3013 3014
"

3015
"Data Types","TIMESTAMP WITH TIME ZONE Type","
3016
TIMESTAMP [ ( precisionInt ) ] WITH TIME ZONE
3017
","
3018
The timestamp with time zone data type.
3019
Stored internally as a BCD-encoded date, nanoseconds since midnight, and time zone offset in minutes.
3020
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3021

3022 3023 3024 3025 3026 3027 3028
Mapped to ""org.h2.api.TimestampWithTimeZone"".
""java.time.OffsetDateTime"" and ""java.time.Instant"" are also supported on Java 8 and later versions.

Values of this data type are compared by UTC values. It means that ""2010-01-01 10:00:00+01"" is greater than ""2010-01-01 11:00:00+03"".

Conversion to ""TIMESTAMP"" uses time zone offset to get UTC time and converts it to local time using the system time zone.
Conversion from ""TIMESTAMP"" does the same operations in reverse and sets time zone offset to offset of the system time zone.
3029
Cast from higher fractional seconds precision to lower fractional seconds precision performs round half up.
3030
","
3031
TIMESTAMP WITH TIME ZONE
3032
TIMESTAMP(9) WITH TIME ZONE
3033 3034
"

Thomas Mueller's avatar
Thomas Mueller committed
3035
"Data Types","BINARY Type","
3036 3037
{ BINARY | VARBINARY | BINARY VARYING
    | LONGVARBINARY | RAW | BYTEA }
3038
[ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3039
","
3040 3041 3042 3043 3044
Represents a byte array. For very long arrays, use BLOB.
The maximum size is 2 GB, but the whole object is kept in
memory when using this data type. The precision is a size constraint;
only the actual data is persisted. For large text data BLOB or CLOB
should be used.
Thomas Mueller's avatar
Thomas Mueller committed
3045 3046 3047 3048 3049 3050 3051 3052 3053

Mapped to byte[].
","
BINARY(1000)
"

"Data Types","OTHER Type","
OTHER
","
Thomas Mueller's avatar
Thomas Mueller committed
3054 3055 3056 3057 3058
This type allows storing serialized Java objects. Internally, a byte array is used.
Serialization and deserialization is done on the client side only.
Deserialization is only done when ""getObject"" is called.
Java operations cannot be executed inside the database engine for security reasons.
Use ""PreparedStatement.setObject"" to store values.
Thomas Mueller's avatar
Thomas Mueller committed
3059

3060
Mapped to ""java.lang.Object"" (or any subclass).
Thomas Mueller's avatar
Thomas Mueller committed
3061 3062 3063 3064 3065
","
OTHER
"

"Data Types","VARCHAR Type","
3066
{ VARCHAR | CHARACTER VARYING | LONGVARCHAR | VARCHAR2 | NVARCHAR
3067
    | NVARCHAR2 | VARCHAR_CASESENSITIVE} [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3068
","
Thomas Mueller's avatar
Thomas Mueller committed
3069
A Unicode String.
Thomas Mueller's avatar
Thomas Mueller committed
3070 3071 3072 3073 3074 3075 3076
Use two single quotes ('') to create a quote.

The maximum precision is ""Integer.MAX_VALUE"".
The precision is a size constraint; only the actual data is persisted.

The whole text is loaded into memory when using this data type.
For large text data CLOB should be used; see there for details.
Thomas Mueller's avatar
Thomas Mueller committed
3077

3078
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
3079 3080 3081 3082 3083
","
VARCHAR(255)
"

"Data Types","VARCHAR_IGNORECASE Type","
3084
VARCHAR_IGNORECASE [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3085
","
Thomas Mueller's avatar
Thomas Mueller committed
3086
Same as VARCHAR, but not case sensitive when comparing.
Thomas Mueller's avatar
Thomas Mueller committed
3087 3088 3089 3090 3091 3092 3093
Stored in mixed case.

The maximum precision is ""Integer.MAX_VALUE"".
The precision is a size constraint; only the actual data is persisted.

The whole text is loaded into memory when using this data type.
For large text data CLOB should be used; see there for details.
Thomas Mueller's avatar
Thomas Mueller committed
3094

3095
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
3096 3097 3098 3099 3100
","
VARCHAR_IGNORECASE
"

"Data Types","CHAR Type","
3101
{ CHAR | CHARACTER | NCHAR } [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3102
","
Thomas Mueller's avatar
Thomas Mueller committed
3103 3104 3105
A Unicode String.
This type is supported for compatibility with other databases and older applications.
The difference to VARCHAR is that trailing spaces are ignored and not persisted.
Thomas Mueller's avatar
Thomas Mueller committed
3106

Thomas Mueller's avatar
Thomas Mueller committed
3107 3108
The maximum precision is ""Integer.MAX_VALUE"".
The precision is a size constraint; only the actual data is persisted.
Thomas Mueller's avatar
Thomas Mueller committed
3109

Thomas Mueller's avatar
Thomas Mueller committed
3110
The whole text is kept in memory when using this data type.
Thomas Mueller's avatar
Thomas Mueller committed
3111
For large text data CLOB should be used; see there for details.
Thomas Mueller's avatar
Thomas Mueller committed
3112

3113
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
3114 3115 3116 3117 3118
","
CHAR(10)
"

"Data Types","BLOB Type","
3119 3120
{ BLOB | BINARY LARGE OBJECT
    | TINYBLOB | MEDIUMBLOB | LONGBLOB | IMAGE | OID }
3121
[ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3122 3123 3124
","
Like BINARY, but intended for very large values such as files or images. Unlike
when using BINARY, large objects are not kept fully in-memory. Use
3125
""PreparedStatement.setBinaryStream"" to store values. See also CLOB and
Thomas Mueller's avatar
Thomas Mueller committed
3126 3127
Advanced / Large Objects.

3128
Mapped to ""java.sql.Blob"" (""java.io.InputStream"" is also supported).
Thomas Mueller's avatar
Thomas Mueller committed
3129 3130 3131 3132 3133
","
BLOB
"

"Data Types","CLOB Type","
3134 3135
{ CLOB | CHARACTER LARGE OBJECT
    | TINYTEXT | TEXT | MEDIUMTEXT | LONGTEXT | NTEXT | NCLOB }
3136
[ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3137 3138 3139 3140 3141
","
CLOB is like VARCHAR, but intended for very large values. Unlike when using
VARCHAR, large CLOB objects are not kept fully in-memory; instead, they are streamed.
CLOB should be used for documents and texts with arbitrary size such as XML or
HTML documents, text files, or memo fields of unlimited size. Use
3142
""PreparedStatement.setCharacterStream"" to store values. See also Advanced / Large Objects.
Thomas Mueller's avatar
Thomas Mueller committed
3143 3144 3145 3146 3147

VARCHAR should be used for text with relatively short average size (for example
shorter than 200 characters). Short CLOB values are stored inline, but there is
an overhead compared to VARCHAR.

3148
Mapped to ""java.sql.Clob"" (""java.io.Reader"" is also supported).
Thomas Mueller's avatar
Thomas Mueller committed
3149 3150 3151 3152 3153 3154 3155
","
CLOB
"

"Data Types","UUID Type","
UUID
","
Thomas Mueller's avatar
Thomas Mueller committed
3156 3157 3158 3159
Universally unique identifier. This is a 128 bit value.
To store values, use ""PreparedStatement.setBytes"",
""setString"", or ""setObject(uuid)"" (where ""uuid"" is a ""java.util.UUID"").
""ResultSet.getObject"" will return a ""java.util.UUID"".
Thomas Mueller's avatar
Thomas Mueller committed
3160

Thomas Mueller's avatar
Thomas Mueller committed
3161 3162 3163 3164 3165
Please note that using an index on randomly generated data will
result on poor performance once there are millions of rows in a table.
The reason is that the cache behavior is very bad with randomly distributed data.
This is a problem for any database system.

Thomas Mueller's avatar
Thomas Mueller committed
3166
For details, see the documentation of ""java.util.UUID"".
Thomas Mueller's avatar
Thomas Mueller committed
3167 3168 3169 3170 3171 3172 3173
","
UUID
"

"Data Types","ARRAY Type","
ARRAY
","
Thomas Mueller's avatar
Thomas Mueller committed
3174
An array of values.
3175
Mapped to ""java.lang.Object[]"" (arrays of any non-primitive type are also supported).
Thomas Mueller's avatar
Thomas Mueller committed
3176 3177 3178 3179


Use a value list (1, 2) or ""PreparedStatement.setObject(.., new Object[] {..})"" to store values,
and ""ResultSet.getObject(..)"" or ""ResultSet.getArray(..)"" to retrieve the values.
Thomas Mueller's avatar
Thomas Mueller committed
3180 3181 3182 3183
","
ARRAY
"

3184 3185 3186 3187 3188 3189 3190 3191 3192 3193 3194 3195 3196 3197
"Data Types","ENUM Type","
{ ENUM (string [, ... ]) }
","
A type with enumerated values.
Mapped to ""java.lang.Integer"".

The first provided value is mapped to 0, the
second mapped to 1, and so on.

Duplicate and empty values are not permitted.
","

ENUM('clubs', 'diamonds', 'hearts', 'spades')
"
3198 3199
"Data Types","GEOMETRY Type","
GEOMETRY
3200 3201 3202 3203 3204 3205 3206 3207 3208
    [({ GEOMETRY |
    { POINT
    | LINESTRING
    | POLYGON
    | MULTIPOINT
    | MULTILINESTRING
    | MULTIPOLYGON
    | GEOMETRYCOLLECTION } [Z|M|ZM]}
    [, sridInt] )]
3209
","
3210
A spatial geometry type.
3211 3212 3213 3214 3215
If additional constraints are not specified this type accepts all supported types of geometries.
A constraint with required geometry type and dimension system can be set by specifying name of the type and
dimension system. A whitespace between them is optional.
2D dimension system does not have a name and assumed if only a geometry type name is specified.
POINT means 2D point, POINT Z or POINTZ means 3D point.
3216
GEOMETRY constraint means no restrictions on type or dimension system of geometry.
3217 3218 3219
A constraint with required spatial reference system identifier (SRID) can be set by specifying this identifier.

Mapped to ""org.locationtech.jts.geom.Geometry"" if JTS library is in classpath and to ""java.lang.String"" otherwise.
3220 3221
May be represented in textual format using the WKT (well-known text) or EWKT (extended well-known text) format.
Values are stored internally in EWKB (extended well-known binary) format.
3222 3223
Only a subset of EWKB and EWKT features is supported.
Supported objects are POINT, LINESTRING, POLYGON, MULTIPOINT, MULTILINESTRING, MULTIPOLYGON, and GEOMETRYCOLLECTION.
3224
Supported dimension systems are 2D (XY), Z (XYZ), M (XYM), and ZM (XYZM).
3225
SRID (spatial reference system identifier) is supported.
3226

3227
Use a quoted string containing a WKT/EWKT formatted string or ""PreparedStatement.setObject()"" to store values,
3228 3229
and ""ResultSet.getObject(..)"" or ""ResultSet.getString(..)"" to retrieve the values.
","
3230
GEOMETRY
3231 3232 3233
GEOMETRY(POINT)
GEOMETRY(POINT Z)
GEOMETRY(POINT Z, 4326)
3234
GEOMETRY(GEOMETRY, 4326)
3235 3236
"

3237
"Data Types","INTERVAL Type","
3238 3239 3240 3241 3242 3243 3244
intervalYearType | intervalMonthType | intervalDayType
    | intervalHourType| intervalMinuteType | intervalSecondType
    | intervalYearToMonthType | intervalDayToHourType
    | intervalDayToMinuteType | intervalDayToSecondType
    | intervalHourToMinuteType | intervalHourToSecondType
    | intervalMinuteToSecondType
","
3245 3246
Interval data type.
There are two classes of intervals. Year-month intervals can store years and months.
3247 3248 3249 3250 3251 3252 3253 3254 3255 3256
Day-time intervals can store days, hours, minutes, and seconds.
Year-month intervals are comparable only with another year-month intervals.
Day-time intervals are comparable only with another day-time intervals.

Mapped to ""org.h2.api.Interval"".
","
INTERVAL DAY TO SECOND
"

"Interval Data Types","INTERVAL YEAR Type","
3257 3258 3259 3260 3261 3262 3263 3264 3265 3266
INTERVAL YEAR [ ( precisionInt ) ]
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.

Mapped to ""org.h2.api.Interval"".
","
INTERVAL YEAR
"

3267
"Interval Data Types","INTERVAL MONTH Type","
3268 3269 3270 3271 3272 3273 3274 3275 3276 3277
INTERVAL MONTH [ ( precisionInt ) ]
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.

Mapped to ""org.h2.api.Interval"".
","
INTERVAL MONTH
"

3278
"Interval Data Types","INTERVAL DAY Type","
3279 3280 3281 3282 3283 3284 3285 3286 3287 3288 3289
INTERVAL DAY [ ( precisionInt ) ]
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL DAY
"

3290
"Interval Data Types","INTERVAL HOUR Type","
3291 3292 3293 3294 3295 3296 3297 3298 3299 3300 3301
INTERVAL HOUR [ ( precisionInt ) ]
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL HOUR
"

3302
"Interval Data Types","INTERVAL MINUTE Type","
3303 3304 3305 3306 3307 3308 3309 3310 3311 3312 3313
INTERVAL MINUTE [ ( precisionInt ) ]
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL MINUTE
"

3314
"Interval Data Types","INTERVAL SECOND Type","
3315
INTERVAL SECOND [ ( precisionInt [, fractionalPrecisionInt ] ) ]
3316 3317 3318
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.
3319
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3320 3321 3322 3323 3324 3325 3326

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL SECOND
"

3327
"Interval Data Types","INTERVAL YEAR TO MONTH Type","
3328 3329 3330
INTERVAL YEAR [ ( precisionInt ) ] TO MONTH
","
Interval data type.
3331
If leading field precision is specified it should be from 1 to 18, 2 is default.
3332 3333 3334 3335 3336 3337

Mapped to ""org.h2.api.Interval"".
","
INTERVAL YEAR TO MONTH
"

3338
"Interval Data Types","INTERVAL DAY TO HOUR Type","
3339 3340 3341
INTERVAL DAY [ ( precisionInt ) ] TO HOUR
","
Interval data type.
3342
If leading field precision is specified it should be from 1 to 18, 2 is default.
3343 3344 3345 3346 3347 3348 3349

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL DAY TO HOUR
"

3350
"Interval Data Types","INTERVAL DAY TO MINUTE Type","
3351 3352 3353
INTERVAL DAY [ ( precisionInt ) ] TO MINUTE
","
Interval data type.
3354
If leading field precision is specified it should be from 1 to 18, 2 is default.
3355 3356 3357 3358 3359 3360 3361

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL DAY TO MINUTE
"

3362
"Interval Data Types","INTERVAL DAY TO SECOND Type","
3363
INTERVAL DAY [ ( precisionInt ) ] TO SECOND [ ( fractionalPrecisionInt ) ]
3364 3365
","
Interval data type.
3366 3367
If leading field precision is specified it should be from 1 to 18, 2 is default.
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3368 3369 3370 3371 3372 3373 3374

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL DAY TO SECOND
"

3375
"Interval Data Types","INTERVAL HOUR TO MINUTE Type","
3376 3377 3378
INTERVAL HOUR [ ( precisionInt ) ] TO MINUTE
","
Interval data type.
3379
If leading field precision is specified it should be from 1 to 18, 2 is default.
3380 3381 3382 3383 3384 3385 3386

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL HOUR TO MINUTE
"

3387
"Interval Data Types","INTERVAL HOUR TO SECOND Type","
3388
INTERVAL HOUR [ ( precisionInt ) ] TO SECOND [ ( fractionalPrecisionInt ) ]
3389 3390
","
Interval data type.
3391 3392
If leading field precision is specified it should be from 1 to 18, 2 is default.
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3393 3394 3395 3396 3397 3398 3399

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL HOUR TO SECOND
"

3400
"Interval Data Types","INTERVAL MINUTE TO SECOND Type","
3401
INTERVAL MINUTE [ ( precisionInt ) ] TO SECOND [ ( fractionalPrecisionInt ) ]
3402 3403
","
Interval data type.
3404 3405
If leading field precision is specified it should be from 1 to 18, 2 is default.
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3406 3407 3408 3409 3410 3411 3412

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL MINUTE TO SECOND
"

Thomas Mueller's avatar
Thomas Mueller committed
3413
"Functions (Aggregate)","AVG","
3414
AVG ( [ DISTINCT ] { numeric } )
3415
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3416
","
3417 3418
The average (mean) value.
If no rows are selected, the result is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
3419
Aggregates are only allowed in select statements.
3420
The returned value is of the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
3421 3422 3423 3424
","
AVG(X)
"

3425
"Functions (Aggregate)","BIT_AND","
3426
BIT_AND(expression)
3427
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3428 3429 3430 3431 3432 3433 3434 3435 3436
","
The bitwise AND of all non-null values.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
BIT_AND(ID)
"

"Functions (Aggregate)","BIT_OR","
3437
BIT_OR(expression)
3438
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3439 3440 3441 3442 3443 3444 3445 3446
","
The bitwise OR of all non-null values.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
BIT_OR(ID)
"

3447 3448
"Functions (Aggregate)","EVERY","
{EVERY|BOOL_AND}(boolean)
3449
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3450
","
3451 3452 3453
Returns true if all expressions are true.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3454
","
3455
EVERY(ID>10)
Thomas Mueller's avatar
Thomas Mueller committed
3456 3457
"

3458 3459
"Functions (Aggregate)","ANY","
{ANY|SOME|BOOL_OR}(boolean)
3460
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3461
","
3462 3463 3464
Returns true if any expression is true.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3465
","
3466
ANY(NAME LIKE 'W%')
Thomas Mueller's avatar
Thomas Mueller committed
3467 3468 3469
"

"Functions (Aggregate)","COUNT","
3470
COUNT( { * | { [ DISTINCT ] expression } } )
3471
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3472
","
3473 3474 3475 3476
The count of all row, or of the non-null values.
This method returns a long.
If no rows are selected, the result is 0.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3477 3478 3479 3480 3481
","
COUNT(*)
"

"Functions (Aggregate)","GROUP_CONCAT","
3482 3483
GROUP_CONCAT ( [ DISTINCT ] string
[ ORDER BY { expression [ ASC | DESC ] } [,...] ]
3484
[ SEPARATOR expression ] )
3485
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3486
","
3487 3488 3489 3490 3491
Concatenates strings with a separator.
The default separator is a ',' (without space).
This method returns a string.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3492 3493 3494 3495
","
GROUP_CONCAT(NAME ORDER BY ID SEPARATOR ', ')
"

3496 3497 3498
"Functions (Aggregate)","ARRAY_AGG","
ARRAY_AGG ( [ DISTINCT ] string
[ ORDER BY { expression [ ASC | DESC ] } [,...] ] )
3499
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3500 3501 3502 3503 3504 3505 3506 3507 3508
","
Aggregate the value into an array.
This method returns an array.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
ARRAY_AGG(NAME ORDER BY ID)
"

Thomas Mueller's avatar
Thomas Mueller committed
3509
"Functions (Aggregate)","MAX","
3510
MAX(value)
3511
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3512
","
3513 3514 3515 3516
The highest value.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
The returned value is of the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
3517 3518 3519 3520 3521
","
MAX(NAME)
"

"Functions (Aggregate)","MIN","
3522
MIN(value)
3523
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3524
","
3525 3526 3527 3528
The lowest value.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
The returned value is of the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
3529 3530 3531 3532 3533
","
MIN(NAME)
"

"Functions (Aggregate)","SUM","
3534
SUM( [ DISTINCT ] { numeric } )
3535
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3536
","
3537 3538 3539
The sum of all values.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
3540
The data type of the returned value depends on the parameter data type like this:
Thomas Mueller's avatar
Thomas Mueller committed
3541
""BOOLEAN, TINYINT, SMALLINT, INT -> BIGINT, BIGINT -> DECIMAL, REAL -> DOUBLE""
Thomas Mueller's avatar
Thomas Mueller committed
3542 3543 3544 3545 3546
","
SUM(X)
"

"Functions (Aggregate)","SELECTIVITY","
3547
SELECTIVITY(value)
3548
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3549
","
3550 3551 3552 3553 3554
Estimates the selectivity (0-100) of a value.
The value is defined as (100 * distinctCount / rowCount).
The selectivity of 0 rows is 0 (unknown).
Up to 10000 values are kept in memory.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3555 3556 3557 3558 3559
","
SELECT SELECTIVITY(FIRSTNAME), SELECTIVITY(NAME) FROM TEST WHERE ROWNUM()<20000
"

"Functions (Aggregate)","STDDEV_POP","
3560
STDDEV_POP( [ DISTINCT ] numeric )
3561
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3562
","
3563 3564 3565
The population standard deviation.
This method returns a double.
If no rows are selected, the result is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
3566 3567 3568 3569 3570 3571
Aggregates are only allowed in select statements.
","
STDDEV_POP(X)
"

"Functions (Aggregate)","STDDEV_SAMP","
3572
STDDEV_SAMP( [ DISTINCT ] numeric )
3573
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3574
","
3575 3576 3577
The sample standard deviation.
This method returns a double.
If no rows are selected, the result is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
3578 3579 3580 3581 3582 3583
Aggregates are only allowed in select statements.
","
STDDEV(X)
"

"Functions (Aggregate)","VAR_POP","
3584
VAR_POP( [ DISTINCT ] numeric )
3585
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3586
","
3587 3588 3589 3590
The population variance (square of the population standard deviation).
This method returns a double.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3591 3592 3593 3594 3595
","
VAR_POP(X)
"

"Functions (Aggregate)","VAR_SAMP","
3596
VAR_SAMP( [ DISTINCT ] numeric )
3597
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3598
","
3599 3600 3601 3602
The sample variance (square of the sample standard deviation).
This method returns a double.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3603 3604 3605 3606
","
VAR_SAMP(X)
"

3607
"Functions (Aggregate)","MEDIAN","
3608
MEDIAN( [ DISTINCT ] value )
3609
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3610 3611 3612
","
The value separating the higher half of a values from the lower half.
Returns the middle value or an interpolated value between two middle values if number of values is even.
3613
Interpolation is only supported for numeric, date-time, and interval data types.
3614 3615 3616 3617 3618 3619 3620
NULL values are ignored in the calculation.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
MEDIAN(X)
"

3621
"Functions (Aggregate)","MODE","
3622 3623
{ MODE( value ) [ ORDER BY expression [ ASC | DESC ] ] }
    | { MODE() WITHIN GROUP(ORDER BY expression [ ASC | DESC ]) }
3624
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3625 3626 3627
","
Returns the value that occurs with the greatest frequency.
If there are multiple values with the same frequency only one value will be returned.
3628 3629 3630 3631 3632
In this situation value will be chosen based on optional ORDER BY clause
that should specify exactly the same expression as argument of this function.
Use ascending order to get smallest value or descending order to get largest value
from multiple values with the same frequency.
If this clause is not specified the exact chosen value is not determined in this situation.
3633 3634 3635 3636 3637
NULL values are ignored in the calculation.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
MODE(X)
3638
MODE(X ORDER BY X)
3639
MODE() WITHIN GROUP(ORDER BY X)
3640 3641
"

3642
"Functions (Aggregate)","ENVELOPE","
3643
ENVELOPE( value )
3644
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3645 3646 3647 3648 3649 3650 3651
","
Returns the minimum bounding box that encloses all specified GEOMETRY values.
Only 2D coordinate plane is supported.
NULL values are ignored in the calculation.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
3652
ENVELOPE(X)
3653 3654
"

Thomas Mueller's avatar
Thomas Mueller committed
3655
"Functions (Numeric)","ABS","
3656
ABS(numeric|interval)
Thomas Mueller's avatar
Thomas Mueller committed
3657
","
3658
Returns the absolute value of a specified value.
3659
The returned value is of the same data type as the parameter.
3660 3661 3662 3663 3664 3665 3666

Note that TINYINT, SMALLINT, INT, and BIGINT data types cannot represent absolute values
of their minimum negative values, because they have more negative values than positive.
For example, for INT data type allowed values are from -2147483648 to 2147483647.
ABS(-2147483648) should be 2147483648, but this value is not allowed for this data type.
It leads to an exception.
To avoid it cast argument of this function to a higher data type.
Thomas Mueller's avatar
Thomas Mueller committed
3667 3668 3669 3670 3671
","
ABS(ID)
"

"Functions (Numeric)","ACOS","
Thomas Mueller's avatar
Thomas Mueller committed
3672
ACOS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3673
","
Thomas Mueller's avatar
Thomas Mueller committed
3674 3675
Calculate the arc cosine.
See also Java ""Math.acos"".
3676
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3677 3678 3679 3680 3681
","
ACOS(D)
"

"Functions (Numeric)","ASIN","
Thomas Mueller's avatar
Thomas Mueller committed
3682
ASIN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3683
","
Thomas Mueller's avatar
Thomas Mueller committed
3684 3685
Calculate the arc sine.
See also Java ""Math.asin"".
3686
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3687 3688 3689 3690 3691
","
ASIN(D)
"

"Functions (Numeric)","ATAN","
Thomas Mueller's avatar
Thomas Mueller committed
3692
ATAN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3693
","
Thomas Mueller's avatar
Thomas Mueller committed
3694 3695
Calculate the arc tangent.
See also Java ""Math.atan"".
3696
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3697 3698 3699 3700 3701
","
ATAN(D)
"

"Functions (Numeric)","COS","
Thomas Mueller's avatar
Thomas Mueller committed
3702
COS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3703
","
Thomas Mueller's avatar
Thomas Mueller committed
3704 3705
Calculate the trigonometric cosine.
See also Java ""Math.cos"".
3706
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3707 3708 3709 3710
","
COS(ANGLE)
"

3711
"Functions (Numeric)","COSH","
Thomas Mueller's avatar
Thomas Mueller committed
3712
COSH(numeric)
3713 3714 3715 3716 3717 3718 3719 3720
","
Calculate the hyperbolic cosine.
See also Java ""Math.cosh"".
This method returns a double.
","
COSH(X)
"

Thomas Mueller's avatar
Thomas Mueller committed
3721
"Functions (Numeric)","COT","
Thomas Mueller's avatar
Thomas Mueller committed
3722
COT(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3723
","
Thomas Mueller's avatar
Thomas Mueller committed
3724
Calculate the trigonometric cotangent (""1/TAN(ANGLE)"").
3725
See also Java ""Math.*"" functions.
3726
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3727 3728 3729 3730 3731
","
COT(ANGLE)
"

"Functions (Numeric)","SIN","
Thomas Mueller's avatar
Thomas Mueller committed
3732
SIN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3733
","
Thomas Mueller's avatar
Thomas Mueller committed
3734 3735
Calculate the trigonometric sine.
See also Java ""Math.sin"".
3736
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3737 3738 3739 3740
","
SIN(ANGLE)
"

3741
"Functions (Numeric)","SINH","
Thomas Mueller's avatar
Thomas Mueller committed
3742
SINH(numeric)
3743 3744 3745 3746 3747 3748 3749 3750
","
Calculate the hyperbolic sine.
See also Java ""Math.sinh"".
This method returns a double.
","
SINH(ANGLE)
"

Thomas Mueller's avatar
Thomas Mueller committed
3751
"Functions (Numeric)","TAN","
Thomas Mueller's avatar
Thomas Mueller committed
3752
TAN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3753
","
Thomas Mueller's avatar
Thomas Mueller committed
3754 3755
Calculate the trigonometric tangent.
See also Java ""Math.tan"".
3756
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3757 3758 3759 3760
","
TAN(ANGLE)
"

3761
"Functions (Numeric)","TANH","
Thomas Mueller's avatar
Thomas Mueller committed
3762
TANH(numeric)
3763 3764 3765 3766 3767 3768 3769 3770
","
Calculate the hyperbolic tangent.
See also Java ""Math.tanh"".
This method returns a double.
","
TANH(X)
"

Thomas Mueller's avatar
Thomas Mueller committed
3771
"Functions (Numeric)","ATAN2","
Thomas Mueller's avatar
Thomas Mueller committed
3772
ATAN2(numeric, numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3773
","
Thomas Mueller's avatar
Thomas Mueller committed
3774
Calculate the angle when converting the rectangular coordinates to polar coordinates.
3775
See also Java ""Math.atan2"".
3776
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3777 3778 3779 3780 3781
","
ATAN2(X, Y)
"

"Functions (Numeric)","BITAND","
3782
BITAND(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3783
","
3784 3785
The bitwise AND operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3786 3787 3788 3789 3790
See also Java operator &.
","
BITAND(A, B)
"

3791 3792 3793 3794 3795 3796 3797 3798 3799 3800 3801
"Functions (Numeric)","BITGET","
BITGET(long, int)
","
Returns true if and only if the first parameter has a bit set in the
position specified by the second parameter.
This method returns a boolean.
The second parameter is zero-indexed; the least significant bit has position 0.
","
BITGET(A, 1)
"

Thomas Mueller's avatar
Thomas Mueller committed
3802
"Functions (Numeric)","BITOR","
3803
BITOR(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3804
","
3805 3806
The bitwise OR operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3807 3808 3809 3810 3811 3812
See also Java operator |.
","
BITOR(A, B)
"

"Functions (Numeric)","BITXOR","
3813
BITXOR(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3814
","
3815 3816
The bitwise XOR operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3817 3818 3819 3820 3821 3822
See also Java operator ^.
","
BITXOR(A, B)
"

"Functions (Numeric)","MOD","
3823
MOD(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3824
","
3825 3826
The modulo operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3827 3828 3829 3830 3831 3832
See also Java operator %.
","
MOD(A, B)
"

"Functions (Numeric)","CEILING","
Thomas Mueller's avatar
Thomas Mueller committed
3833
{ CEILING | CEIL } (numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3834
","
3835
See also Java ""Math.ceil"".
3836
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3837
","
3838
CEIL(A)
Thomas Mueller's avatar
Thomas Mueller committed
3839 3840 3841
"

"Functions (Numeric)","DEGREES","
Thomas Mueller's avatar
Thomas Mueller committed
3842
DEGREES(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3843
","
3844
See also Java ""Math.toDegrees"".
3845
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3846 3847 3848 3849 3850
","
DEGREES(A)
"

"Functions (Numeric)","EXP","
Thomas Mueller's avatar
Thomas Mueller committed
3851
EXP(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3852
","
3853
See also Java ""Math.exp"".
3854
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3855 3856 3857 3858 3859
","
EXP(A)
"

"Functions (Numeric)","FLOOR","
Thomas Mueller's avatar
Thomas Mueller committed
3860
FLOOR(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3861
","
3862
See also Java ""Math.floor"".
3863
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3864 3865 3866 3867
","
FLOOR(A)
"

3868 3869
"Functions (Numeric)","LN","
{LN|LOG}(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3870
","
3871
Calculates the natural (base e) logarithm as a double value.
3872
In the PostgreSQL mode, LOG(x) is base 10.
3873
See also Java ""Math.log"".
Thomas Mueller's avatar
Thomas Mueller committed
3874
","
3875
LN(A)
Thomas Mueller's avatar
Thomas Mueller committed
3876 3877 3878
"

"Functions (Numeric)","LOG10","
Thomas Mueller's avatar
Thomas Mueller committed
3879
LOG10(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3880
","
3881
Calculates the base 10 logarithm as a double value.
3882
See also Java ""Math.log10"".
Thomas Mueller's avatar
Thomas Mueller committed
3883 3884 3885 3886
","
LOG10(A)
"

3887 3888 3889 3890 3891 3892 3893 3894 3895 3896 3897 3898 3899
"Functions (Numeric)","ORA_HASH","
ORA_HASH(expression [, bucketLong [, seedLong]])
","
Computes a hash value.
Optional bucket argument determines the maximum returned value.
This argument should be between 0 and 4294967295, default is 4294967295.
Optional seed argument is combined with the given expression to return the different values for the same expression.
This argument should be between 0 and 4294967295, default is 0.
This method returns a long value between 0 and the specified or default bucket value inclusive.
","
ORA_HASH(A)
"

Thomas Mueller's avatar
Thomas Mueller committed
3900
"Functions (Numeric)","RADIANS","
Thomas Mueller's avatar
Thomas Mueller committed
3901
RADIANS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3902
","
3903
See also Java ""Math.toRadians"".
3904
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3905 3906 3907 3908 3909
","
RADIANS(A)
"

"Functions (Numeric)","SQRT","
Thomas Mueller's avatar
Thomas Mueller committed
3910
SQRT(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3911
","
3912
See also Java ""Math.sqrt"".
3913
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3914 3915 3916 3917 3918
","
SQRT(A)
"

"Functions (Numeric)","PI","
3919
PI()
Thomas Mueller's avatar
Thomas Mueller committed
3920
","
3921
See also Java ""Math.PI"".
3922
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3923 3924 3925 3926 3927
","
PI()
"

"Functions (Numeric)","POWER","
Thomas Mueller's avatar
Thomas Mueller committed
3928
POWER(numeric, numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3929
","
3930
See also Java ""Math.pow"".
Thomas Mueller's avatar
Thomas Mueller committed
3931
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3932 3933 3934 3935 3936
","
POWER(A, B)
"

"Functions (Numeric)","RAND","
3937
{ RAND | RANDOM } ( [ int ] )
Thomas Mueller's avatar
Thomas Mueller committed
3938 3939 3940
","
Calling the function without parameter returns the next a pseudo random number.
Calling it with an parameter seeds the session's random number generator.
Thomas Mueller's avatar
Thomas Mueller committed
3941
This method returns a double between 0 (including) and 1 (excluding).
Thomas Mueller's avatar
Thomas Mueller committed
3942 3943 3944 3945 3946
","
RAND()
"

"Functions (Numeric)","RANDOM_UUID","
3947
{ RANDOM_UUID | UUID } ()
Thomas Mueller's avatar
Thomas Mueller committed
3948 3949
","
Returns a new UUID with 122 pseudo random bits.
Thomas Mueller's avatar
Thomas Mueller committed
3950 3951 3952 3953 3954

Please note that using an index on randomly generated data will
result on poor performance once there are millions of rows in a table.
The reason is that the cache behavior is very bad with randomly distributed data.
This is a problem for any database system.
Thomas Mueller's avatar
Thomas Mueller committed
3955 3956 3957 3958 3959
","
RANDOM_UUID()
"

"Functions (Numeric)","ROUND","
3960
ROUND(numeric [, digitsInt])
Thomas Mueller's avatar
Thomas Mueller committed
3961
","
3962
Rounds to a number of digits, or to the nearest long if the number of digits if not set.
Thomas Mueller's avatar
Thomas Mueller committed
3963
This method returns a numeric (the same type as the input).
Thomas Mueller's avatar
Thomas Mueller committed
3964 3965 3966 3967 3968
","
ROUND(VALUE, 2)
"

"Functions (Numeric)","ROUNDMAGIC","
Thomas Mueller's avatar
Thomas Mueller committed
3969
ROUNDMAGIC(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3970
","
3971 3972 3973 3974 3975 3976
This function rounds numbers in a good way, but it is slow.
It has a special handling for numbers around 0.
Only numbers smaller or equal +/-1000000000000 are supported.
The value is converted to a String internally, and then the last last 4 characters are checked.
'000x' becomes '0000' and '999x' becomes '999999', which is rounded automatically.
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3977 3978 3979 3980 3981
","
ROUNDMAGIC(VALUE/3*3)
"

"Functions (Numeric)","SECURE_RAND","
3982
SECURE_RAND(int)
Thomas Mueller's avatar
Thomas Mueller committed
3983 3984
","
Generates a number of cryptographically secure random numbers.
3985
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3986 3987 3988 3989 3990
","
CALL SECURE_RAND(16)
"

"Functions (Numeric)","SIGN","
3991
SIGN(numeric|interval)
Thomas Mueller's avatar
Thomas Mueller committed
3992
","
3993
Returns -1 if the value is smaller than 0, 0 if zero, and otherwise 1.
Thomas Mueller's avatar
Thomas Mueller committed
3994 3995 3996 3997 3998
","
SIGN(VALUE)
"

"Functions (Numeric)","ENCRYPT","
3999
ENCRYPT(algorithmString, keyBytes, dataBytes)
Thomas Mueller's avatar
Thomas Mueller committed
4000
","
4001
Encrypts data using a key.
4002
The supported algorithm is AES.
4003 4004
The block size is 16 bytes.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4005 4006 4007 4008 4009
","
CALL ENCRYPT('AES', '00', STRINGTOUTF8('Test'))
"

"Functions (Numeric)","DECRYPT","
4010
DECRYPT(algorithmString, keyBytes, dataBytes)
Thomas Mueller's avatar
Thomas Mueller committed
4011
","
4012
Decrypts data using a key.
4013
The supported algorithm is AES.
4014 4015
The block size is 16 bytes.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4016 4017 4018 4019 4020 4021
","
CALL TRIM(CHAR(0) FROM UTF8TOSTRING(
    DECRYPT('AES', '00', '3fabb4de8f1ee2e97d7793bab2db1116')))
"

"Functions (Numeric)","HASH","
4022
HASH(algorithmString, expression [, iterationInt])
Thomas Mueller's avatar
Thomas Mueller committed
4023
","
4024 4025 4026
Calculate the hash value using an algorithm, and repeat this process for a number of iterations.
Currently, the only algorithm supported is SHA256.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4027 4028 4029 4030 4031
","
CALL HASH('SHA256', STRINGTOUTF8('Password'), 1000)
"

"Functions (Numeric)","TRUNCATE","
4032 4033
{ TRUNC | TRUNCATE } ( { {numeric, digitsInt}
    | timestamp | timestampWithTimeZone | date | timestampString } )
Thomas Mueller's avatar
Thomas Mueller committed
4034 4035
","
Truncates to a number of digits (to the next value closer to 0).
4036
This method returns a double.
4037
When used with a timestamp, truncates a timestamp to a date (day) value.
4038 4039
When used with a date, truncates a date to a date (day) value less time part.
When used with a timestamp as string, truncates a timestamp to a date (day) value.
Thomas Mueller's avatar
Thomas Mueller committed
4040 4041 4042 4043 4044
","
TRUNCATE(VALUE, 2)
"

"Functions (Numeric)","COMPRESS","
4045
COMPRESS(dataBytes [, algorithmString])
Thomas Mueller's avatar
Thomas Mueller committed
4046
","
4047 4048 4049 4050
Compresses the data using the specified compression algorithm.
Supported algorithms are: LZF (faster but lower compression; default), and DEFLATE (higher compression).
Compression does not always reduce size. Very small objects and objects with little redundancy may get larger.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4051 4052 4053 4054 4055
","
COMPRESS(STRINGTOUTF8('Test'))
"

"Functions (Numeric)","EXPAND","
4056
EXPAND(bytes)
Thomas Mueller's avatar
Thomas Mueller committed
4057 4058
","
Expands data that was compressed using the COMPRESS function.
4059
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4060 4061 4062 4063 4064
","
UTF8TOSTRING(EXPAND(COMPRESS(STRINGTOUTF8('Test'))))
"

"Functions (Numeric)","ZERO","
4065
ZERO()
Thomas Mueller's avatar
Thomas Mueller committed
4066 4067 4068 4069 4070 4071 4072
","
Returns the value 0. This function can be used even if numeric literals are disabled.
","
ZERO()
"

"Functions (String)","ASCII","
4073
ASCII(string)
Thomas Mueller's avatar
Thomas Mueller committed
4074 4075
","
Returns the ASCII value of the first character in the string.
4076
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
4077 4078 4079 4080
","
ASCII('Hi')
"
"Functions (String)","BIT_LENGTH","
4081
BIT_LENGTH(string)
Thomas Mueller's avatar
Thomas Mueller committed
4082
","
4083 4084 4085
Returns the number of bits in a string.
This method returns a long.
For BLOB, CLOB, BYTES and JAVA_OBJECT, the precision is used. Each character needs 16 bits.
Thomas Mueller's avatar
Thomas Mueller committed
4086 4087 4088 4089 4090
","
BIT_LENGTH(NAME)
"

"Functions (String)","LENGTH","
4091
{ LENGTH | CHAR_LENGTH | CHARACTER_LENGTH } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4092
","
4093 4094 4095
Returns the number of characters in a string.
This method returns a long.
For BLOB, CLOB, BYTES and JAVA_OBJECT, the precision is used.
Thomas Mueller's avatar
Thomas Mueller committed
4096 4097 4098 4099 4100
","
LENGTH(NAME)
"

"Functions (String)","OCTET_LENGTH","
4101
OCTET_LENGTH(string)
Thomas Mueller's avatar
Thomas Mueller committed
4102
","
4103 4104 4105 4106
Returns the number of bytes in a string.
This method returns a long.
For BLOB, CLOB, BYTES and JAVA_OBJECT, the precision is used.
Each character needs 2 bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4107 4108 4109 4110 4111
","
OCTET_LENGTH(NAME)
"

"Functions (String)","CHAR","
4112
{ CHAR | CHR } ( int )
Thomas Mueller's avatar
Thomas Mueller committed
4113 4114
","
Returns the character that represents the ASCII value.
4115
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4116 4117 4118 4119 4120
","
CHAR(65)
"

"Functions (String)","CONCAT","
4121
CONCAT(string, string [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4122 4123
","
Combines strings.
Thomas Mueller's avatar
Thomas Mueller committed
4124
Unlike with the operator ""||"", NULL parameters are ignored,
Thomas Mueller's avatar
Thomas Mueller committed
4125
and do not cause the result to become NULL.
4126
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4127 4128 4129 4130
","
CONCAT(NAME, '!')
"

4131 4132 4133 4134
"Functions (String)","CONCAT_WS","
CONCAT_WS(separatorString, string, string [,...])
","
Combines strings with separator.
Thomas Mueller's avatar
Thomas Mueller committed
4135
Unlike with the operator ""||"", NULL parameters are ignored,
Thomas Mueller's avatar
Thomas Mueller committed
4136
and do not cause the result to become NULL.
4137 4138 4139 4140 4141
This method returns a string.
","
CONCAT_WS(',', NAME, '!')
"

Thomas Mueller's avatar
Thomas Mueller committed
4142
"Functions (String)","DIFFERENCE","
4143
DIFFERENCE(string, string)
Thomas Mueller's avatar
Thomas Mueller committed
4144 4145
","
Returns the difference between the sounds of two strings.
4146 4147 4148 4149 4150
The difference is calculated as a number of matched characters
in the same positions in SOUNDEX representations of arguments.
This method returns an int between 0 and 4 inclusive, or null if any of its parameters is null.
Note that value of 0 means that strings are not similar to each other.
Value of 4 means that strings are fully similar to each other (have the same SOUNDEX representation).
Thomas Mueller's avatar
Thomas Mueller committed
4151 4152 4153 4154 4155
","
DIFFERENCE(T1.NAME, T2.NAME)
"

"Functions (String)","HEXTORAW","
4156
HEXTORAW(string)
Thomas Mueller's avatar
Thomas Mueller committed
4157
","
4158 4159
Converts a hex representation of a string to a string.
4 hex characters per string character are used.
Thomas Mueller's avatar
Thomas Mueller committed
4160 4161 4162 4163 4164
","
HEXTORAW(DATA)
"

"Functions (String)","RAWTOHEX","
4165
RAWTOHEX(string)
Thomas Mueller's avatar
Thomas Mueller committed
4166
","
4167 4168 4169
Converts a string to the hex representation.
4 hex characters per string character are used.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4170 4171 4172 4173 4174
","
RAWTOHEX(DATA)
"

"Functions (String)","INSTR","
4175
INSTR(string, searchString, [, startInt])
Thomas Mueller's avatar
Thomas Mueller committed
4176
","
4177
Returns the location of a search string in a string.
4178 4179 4180
If a start position is used, the characters before it are ignored.
If position is negative, the rightmost location is returned.
0 is returned if the search string is not found.
Thomas Mueller's avatar
Thomas Mueller committed
4181
Please note this function is case sensitive, even if the parameters are not.
Thomas Mueller's avatar
Thomas Mueller committed
4182 4183 4184 4185 4186
","
INSTR(EMAIL,'@')
"

"Functions (String)","INSERT Function","
4187
INSERT(originalString, startInt, lengthInt, addString)
Thomas Mueller's avatar
Thomas Mueller committed
4188
","
4189 4190 4191
Inserts a additional string into the original string at a specified start position.
The length specifies the number of characters that are removed at the start position in the original string.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4192 4193 4194 4195 4196
","
INSERT(NAME, 1, 1, ' ')
"

"Functions (String)","LOWER","
4197
{ LOWER | LCASE } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4198 4199 4200 4201 4202 4203 4204
","
Converts a string to lowercase.
","
LOWER(NAME)
"

"Functions (String)","UPPER","
4205
{ UPPER | UCASE } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4206 4207 4208 4209 4210 4211 4212
","
Converts a string to uppercase.
","
UPPER(NAME)
"

"Functions (String)","LEFT","
4213
LEFT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4214 4215 4216 4217 4218 4219 4220
","
Returns the leftmost number of characters.
","
LEFT(NAME, 3)
"

"Functions (String)","RIGHT","
4221
RIGHT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4222 4223 4224 4225 4226 4227 4228
","
Returns the rightmost number of characters.
","
RIGHT(NAME, 3)
"

"Functions (String)","LOCATE","
4229
LOCATE(searchString, string [, startInt])
Thomas Mueller's avatar
Thomas Mueller committed
4230
","
4231 4232 4233 4234
Returns the location of a search string in a string.
If a start position is used, the characters before it are ignored.
If position is negative, the rightmost location is returned.
0 is returned if the search string is not found.
Thomas Mueller's avatar
Thomas Mueller committed
4235 4236 4237 4238 4239
","
LOCATE('.', NAME)
"

"Functions (String)","POSITION","
4240
POSITION(searchString, string)
Thomas Mueller's avatar
Thomas Mueller committed
4241 4242 4243 4244 4245 4246 4247
","
Returns the location of a search string in a string. See also LOCATE.
","
POSITION('.', NAME)
"

"Functions (String)","LPAD","
4248
LPAD(string, int[, paddingString])
Thomas Mueller's avatar
Thomas Mueller committed
4249
","
4250 4251 4252
Left pad the string to the specified length.
If the length is shorter than the string, it will be truncated at the end.
If the padding string is not set, spaces will be used.
Thomas Mueller's avatar
Thomas Mueller committed
4253 4254 4255 4256 4257
","
LPAD(AMOUNT, 10, '*')
"

"Functions (String)","RPAD","
4258
RPAD(string, int[, paddingString])
Thomas Mueller's avatar
Thomas Mueller committed
4259
","
4260 4261 4262
Right pad the string to the specified length.
If the length is shorter than the string, it will be truncated.
If the padding string is not set, spaces will be used.
Thomas Mueller's avatar
Thomas Mueller committed
4263 4264 4265 4266 4267
","
RPAD(TEXT, 10, '-')
"

"Functions (String)","LTRIM","
4268
LTRIM(string)
Thomas Mueller's avatar
Thomas Mueller committed
4269 4270 4271 4272 4273 4274 4275
","
Removes all leading spaces from a string.
","
LTRIM(NAME)
"

"Functions (String)","RTRIM","
4276
RTRIM(string)
Thomas Mueller's avatar
Thomas Mueller committed
4277 4278 4279 4280 4281 4282 4283
","
Removes all trailing spaces from a string.
","
RTRIM(NAME)
"

"Functions (String)","TRIM","
4284
TRIM ( [ { LEADING | TRAILING | BOTH } [ string ] FROM ] string )
Thomas Mueller's avatar
Thomas Mueller committed
4285
","
4286 4287
Removes all leading spaces, trailing spaces, or spaces at both ends, from a string.
Other characters can be removed as well.
Thomas Mueller's avatar
Thomas Mueller committed
4288 4289 4290 4291 4292
","
TRIM(BOTH '_' FROM NAME)
"

"Functions (String)","REGEXP_REPLACE","
4293
REGEXP_REPLACE(inputString, regexString, replacementString [, flagsString])
Thomas Mueller's avatar
Thomas Mueller committed
4294
","
4295
Replaces each substring that matches a regular expression.
4296
For details, see the Java ""String.replaceAll()"" method.
4297 4298 4299 4300 4301 4302 4303 4304 4305 4306 4307 4308 4309 4310
If any parameter is null (except optional flagsString parameter), the result is null.

Flags values limited to 'i', 'c', 'n', 'm'. Other symbols causes exception.
Multiple symbols could be uses in one flagsString parameter (like 'im').
Later flags overrides first ones, for example 'ic' equivalent to case sensitive matching 'c'.

'i' enables case insensitive matching (Pattern.CASE_INSENSITIVE)

'c' disables case insensitive matching (Pattern.CASE_INSENSITIVE)

'n' allows the period to match the newline character (Pattern.DOTALL)

'm' enables multiline mode (Pattern.MULTILINE)

Thomas Mueller's avatar
Thomas Mueller committed
4311 4312
","
REGEXP_REPLACE('Hello    World', ' +', ' ')
4313
REGEXP_REPLACE('Hello WWWWorld', 'w+', 'W', 'i')
Thomas Mueller's avatar
Thomas Mueller committed
4314 4315
"

4316 4317 4318 4319
"Functions (String)","REGEXP_LIKE","
REGEXP_LIKE(inputString, regexString [, flagsString])
","
Matches string to a regular expression.
4320 4321 4322 4323 4324 4325 4326 4327 4328 4329 4330 4331 4332 4333 4334
For details, see the Java ""Matcher.find()"" method.
If any parameter is null (except optional flagsString parameter), the result is null.

Flags values limited to 'i', 'c', 'n', 'm'. Other symbols causes exception.
Multiple symbols could be uses in one flagsString parameter (like 'im').
Later flags overrides first ones, for example 'ic' equivalent to case sensitive matching 'c'.

'i' enables case insensitive matching (Pattern.CASE_INSENSITIVE)

'c' disables case insensitive matching (Pattern.CASE_INSENSITIVE)

'n' allows the period to match the newline character (Pattern.DOTALL)

'm' enables multiline mode (Pattern.MULTILINE)

4335 4336
","
REGEXP_LIKE('Hello    World', '[A-Z ]*', 'i')
Thomas Mueller's avatar
Thomas Mueller committed
4337 4338
"

4339

Thomas Mueller's avatar
Thomas Mueller committed
4340
"Functions (String)","REPEAT","
4341
REPEAT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4342 4343 4344 4345 4346 4347 4348
","
Returns a string repeated some number of times.
","
REPEAT(NAME || ' ', 10)
"

"Functions (String)","REPLACE","
4349
REPLACE(string, searchString [, replacementString])
Thomas Mueller's avatar
Thomas Mueller committed
4350
","
4351 4352
Replaces all occurrences of a search string in a text with another string.
If no replacement is specified, the search string is removed from the original string.
4353
If any parameter is null, the result is null.
Thomas Mueller's avatar
Thomas Mueller committed
4354 4355 4356 4357 4358
","
REPLACE(NAME, ' ')
"

"Functions (String)","SOUNDEX","
4359
SOUNDEX(string)
Thomas Mueller's avatar
Thomas Mueller committed
4360
","
4361
Returns a four character code representing the sound of a string.
4362 4363
This method returns a string, or null if parameter is null.
See https://en.wikipedia.org/wiki/Soundex for more information.
Thomas Mueller's avatar
Thomas Mueller committed
4364 4365 4366 4367 4368
","
SOUNDEX(NAME)
"

"Functions (String)","SPACE","
4369
SPACE(int)
Thomas Mueller's avatar
Thomas Mueller committed
4370 4371 4372 4373 4374 4375 4376
","
Returns a string consisting of a number of spaces.
","
SPACE(80)
"

"Functions (String)","STRINGDECODE","
4377
STRINGDECODE(string)
Thomas Mueller's avatar
Thomas Mueller committed
4378
","
4379 4380 4381
Converts a encoded string using the Java string literal encoding format.
Special characters are \b, \t, \n, \f, \r, \"", \\, \<octal>, \u<unicode>.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4382 4383 4384 4385 4386
","
CALL STRINGENCODE(STRINGDECODE('Lines 1\nLine 2'))
"

"Functions (String)","STRINGENCODE","
4387
STRINGENCODE(string)
Thomas Mueller's avatar
Thomas Mueller committed
4388
","
4389 4390 4391
Encodes special characters in a string using the Java string literal encoding format.
Special characters are \b, \t, \n, \f, \r, \"", \\, \<octal>, \u<unicode>.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4392 4393 4394 4395 4396
","
CALL STRINGENCODE(STRINGDECODE('Lines 1\nLine 2'))
"

"Functions (String)","STRINGTOUTF8","
4397
STRINGTOUTF8(string)
Thomas Mueller's avatar
Thomas Mueller committed
4398 4399
","
Encodes a string to a byte array using the UTF8 encoding format.
4400
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4401 4402 4403 4404 4405
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"

"Functions (String)","SUBSTRING","
4406
{ SUBSTRING | SUBSTR } ( string, startInt [, lengthInt ] )
Thomas Mueller's avatar
Thomas Mueller committed
4407
","
4408
Returns a substring of a string starting at a position.
4409
If the start index is negative, then the start index is relative to the end of the string.
4410
The length is optional.
4411
Also supported is: ""SUBSTRING(string [FROM start] [FOR length])"".
Thomas Mueller's avatar
Thomas Mueller committed
4412
","
4413 4414
CALL SUBSTR('[Hello]', 2, 5);
CALL SUBSTR('Hello World', -5);
Thomas Mueller's avatar
Thomas Mueller committed
4415 4416 4417
"

"Functions (String)","UTF8TOSTRING","
4418
UTF8TOSTRING(bytes)
Thomas Mueller's avatar
Thomas Mueller committed
4419 4420 4421 4422 4423 4424 4425
","
Decodes a byte array in the UTF8 format to a string.
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"

"Functions (String)","XMLATTR","
4426
XMLATTR(nameString, valueString)
Thomas Mueller's avatar
Thomas Mueller committed
4427
","
4428
Creates an XML attribute element of the form ""name=value"".
4429 4430
The value is encoded as XML text.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4431 4432 4433 4434 4435
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'))
"

"Functions (String)","XMLNODE","
4436
XMLNODE(elementString [, attributesString [, contentString [, indentBoolean]]])
Thomas Mueller's avatar
Thomas Mueller committed
4437 4438
","
Create an XML node element.
4439 4440 4441
An empty or null attribute string means no attributes are set.
An empty or null content string means the node is empty.
The content is indented by default if it contains a newline.
4442
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4443 4444 4445 4446 4447
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'), 'H2')
"

"Functions (String)","XMLCOMMENT","
4448
XMLCOMMENT(commentString)
Thomas Mueller's avatar
Thomas Mueller committed
4449
","
4450
Creates an XML comment.
4451
Two dashes (""--"") are converted to ""- -"".
4452
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4453 4454 4455 4456 4457
","
CALL XMLCOMMENT('Test')
"

"Functions (String)","XMLCDATA","
4458
XMLCDATA(valueString)
Thomas Mueller's avatar
Thomas Mueller committed
4459
","
4460
Creates an XML CDATA element.
4461
If the value contains ""]]>"", an XML text element is created instead.
4462
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4463 4464 4465 4466 4467
","
CALL XMLCDATA('data')
"

"Functions (String)","XMLSTARTDOC","
4468
XMLSTARTDOC()
Thomas Mueller's avatar
Thomas Mueller committed
4469
","
Thomas Mueller's avatar
Thomas Mueller committed
4470
Returns the XML declaration.
4471
The result is always ""<?xml version=""1.0""?>"".
Thomas Mueller's avatar
Thomas Mueller committed
4472 4473 4474 4475 4476
","
CALL XMLSTARTDOC()
"

"Functions (String)","XMLTEXT","
4477
XMLTEXT(valueString [, escapeNewlineBoolean])
Thomas Mueller's avatar
Thomas Mueller committed
4478 4479
","
Creates an XML text element.
Thomas Mueller's avatar
Thomas Mueller committed
4480
If enabled, newline and linefeed is converted to an XML entity (&#).
4481
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4482 4483 4484 4485
","
CALL XMLTEXT('test')
"

4486
"Functions (String)","TO_CHAR","
4487
TO_CHAR(value [, formatString[, nlsParamString]])
4488 4489 4490 4491 4492 4493
","
Oracle-compatible TO_CHAR function that can format a timestamp, a number, or text.
","
CALL TO_CHAR(TIMESTAMP '2010-01-01 00:00:00', 'DD MON, YYYY')
"

4494
"Functions (String)","TRANSLATE","
4495
TRANSLATE(value, searchString, replacementString)
4496 4497 4498 4499 4500 4501
","
Oracle-compatible TRANSLATE function that replaces a sequence of characters in a string with another set of characters.
","
CALL TRANSLATE('Hello world', 'eo', 'EO')
"

Thomas Mueller's avatar
Thomas Mueller committed
4502
"Functions (Time and Date)","CURRENT_DATE","
4503
{ CURRENT_DATE | CURDATE() | SYSDATE | TODAY }
Thomas Mueller's avatar
Thomas Mueller committed
4504 4505
","
Returns the current date.
4506 4507
These methods always return the same value within a transaction (default)
or within a command depending on database mode.
Thomas Mueller's avatar
Thomas Mueller committed
4508
","
4509
CURRENT_DATE
Thomas Mueller's avatar
Thomas Mueller committed
4510 4511 4512
"

"Functions (Time and Date)","CURRENT_TIME","
4513
{ CURRENT_TIME [ (int) ] | LOCALTIME [ (int) ] | CURTIME([ int ]) }
Thomas Mueller's avatar
Thomas Mueller committed
4514 4515
","
Returns the current time.
4516 4517 4518 4519
If fractional seconds precision is specified it should be from 0 to 9, 0 is default.
The specified value can be used only to limit precision of a result.
The actual maximum available precision depends on operating system and JVM and can be 3 (milliseconds) or higher.
Higher precision is not available before Java 9.
4520 4521
These methods always return the same value within a transaction (default)
or within a command depending on database mode.
Thomas Mueller's avatar
Thomas Mueller committed
4522
","
4523 4524 4525
CURRENT_TIME
LOCALTIME
LOCALTIME(9)
Thomas Mueller's avatar
Thomas Mueller committed
4526 4527 4528
"

"Functions (Time and Date)","CURRENT_TIMESTAMP","
4529
CURRENT_TIMESTAMP [ (int) ]
4530 4531
","
Returns the current timestamp with time zone.
4532
Time zone offset is set to a current time zone offset.
4533
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
4534 4535 4536
The specified value can be used only to limit precision of a result.
The actual maximum available precision depends on operating system and JVM and can be 3 (milliseconds) or higher.
Higher precision is not available before Java 9.
4537 4538
This method always returns the same value within a transaction (default)
or within a command depending on database mode.
4539
","
4540 4541
CURRENT_TIMESTAMP
CURRENT_TIMESTAMP(9)
4542 4543 4544
"

"Functions (Time and Date)","LOCALTIMESTAMP","
4545
{ LOCALTIMESTAMP [ (int) ] | NOW( [ int ] ) }
Thomas Mueller's avatar
Thomas Mueller committed
4546
","
4547
Returns the current timestamp.
4548
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
4549 4550 4551
The specified value can be used only to limit precision of a result.
The actual maximum available precision depends on operating system and JVM and can be 3 (milliseconds) or higher.
Higher precision is not available before Java 9.
4552 4553
These methods always return the same value within a transaction (default)
or within a command depending on database mode.
Thomas Mueller's avatar
Thomas Mueller committed
4554
","
4555 4556
LOCALTIMESTAMP
LOCALTIMESTAMP(9)
Thomas Mueller's avatar
Thomas Mueller committed
4557 4558 4559
"

"Functions (Time and Date)","DATEADD","
4560
{ DATEADD| TIMESTAMPADD } (datetimeField, addIntLong, dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4561
","
4562
Adds units to a date-time value. The datetimeField indicates the unit.
4563
Use negative values to subtract units.
4564
addIntLong may be a long value when manipulating milliseconds,
4565
microseconds, or nanoseconds otherwise its range is restricted to int.
4566
This method returns a value with the same type as specified value if unit is compatible with this value.
4567 4568 4569
If specified field is a HOUR, MINUTE, SECOND, MILLISECOND, etc and value is a DATE value DATEADD returns combined TIMESTAMP.
Fields DAY, MONTH, YEAR, WEEK, etc are not allowed for TIME values.
Fields TIMEZONE_HOUR and TIMEZONE_MINUTE are only allowed for TIMESTAMP WITH TIME ZONE values.
Thomas Mueller's avatar
Thomas Mueller committed
4570 4571 4572 4573 4574
","
DATEADD('MONTH', 1, DATE '2001-01-31')
"

"Functions (Time and Date)","DATEDIFF","
4575
{ DATEDIFF | TIMESTAMPDIFF } (datetimeField, aDateAndTime, bDateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4576
","
4577
Returns the the number of crossed unit boundaries between two date/time values.
4578
This method returns a long.
4579
The datetimeField indicates the unit.
4580 4581
Only TIMEZONE_HOUR and TIMEZONE_MINUTE fields use the time zone offset component.
With all other fields if date/time values have time zone offset component it is ignored.
Thomas Mueller's avatar
Thomas Mueller committed
4582
","
4583
DATEDIFF(YEAR, T1.CREATED, T2.CREATED)
Thomas Mueller's avatar
Thomas Mueller committed
4584 4585 4586
"

"Functions (Time and Date)","DAYNAME","
4587
DAYNAME(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4588 4589 4590 4591 4592 4593 4594
","
Returns the name of the day (in English).
","
DAYNAME(CREATED)
"

"Functions (Time and Date)","DAY_OF_MONTH","
4595
DAY_OF_MONTH(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4596 4597 4598 4599 4600 4601 4602
","
Returns the day of the month (1-31).
","
DAY_OF_MONTH(CREATED)
"

"Functions (Time and Date)","DAY_OF_WEEK","
4603
DAY_OF_WEEK(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4604 4605 4606 4607 4608 4609
","
Returns the day of the week (1 means Sunday).
","
DAY_OF_WEEK(CREATED)
"

4610 4611 4612 4613 4614 4615 4616 4617
"Functions (Time and Date)","ISO_DAY_OF_WEEK","
ISO_DAY_OF_WEEK(dateAndTime)
","
Returns the ISO day of the week (1 means Monday).
","
ISO_DAY_OF_WEEK(CREATED)
"

Thomas Mueller's avatar
Thomas Mueller committed
4618
"Functions (Time and Date)","DAY_OF_YEAR","
4619
DAY_OF_YEAR(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4620 4621 4622 4623 4624 4625 4626
","
Returns the day of the year (1-366).
","
DAY_OF_YEAR(CREATED)
"

"Functions (Time and Date)","EXTRACT","
4627
EXTRACT ( datetimeField FROM { dateAndTime | interval })
Thomas Mueller's avatar
Thomas Mueller committed
4628
","
4629
Returns a value of the specific time unit from a date/time value.
4630 4631
This method returns a numeric value with EPOCH field and
an int for all other fields.
Thomas Mueller's avatar
Thomas Mueller committed
4632 4633 4634 4635 4636
","
EXTRACT(SECOND FROM CURRENT_TIMESTAMP)
"

"Functions (Time and Date)","FORMATDATETIME","
4637
FORMATDATETIME ( dateAndTime, formatString
4638
[ , localeString [ , timeZoneString ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4639
","
4640 4641 4642
Formats a date, time or timestamp as a string.
The most important format characters are:
y year, M month, d day, H hour, m minute, s second.
4643
For details of the format, see ""java.text.SimpleDateFormat"".
4644 4645
timeZoneString may be specified if dateAndTime is a DATE, TIME or TIMESTAMP.
timeZoneString is ignored if dateAndTime is TIMESTAMP WITH TIME ZONE.
4646
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4647 4648 4649 4650 4651 4652
","
CALL FORMATDATETIME(TIMESTAMP '2001-02-03 04:05:06',
    'EEE, d MMM yyyy HH:mm:ss z', 'en', 'GMT')
"

"Functions (Time and Date)","HOUR","
4653
HOUR(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4654
","
4655
Returns the hour (0-23) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4656 4657 4658 4659 4660
","
HOUR(CREATED)
"

"Functions (Time and Date)","MINUTE","
4661
MINUTE(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4662
","
4663
Returns the minute (0-59) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4664 4665 4666 4667 4668
","
MINUTE(CREATED)
"

"Functions (Time and Date)","MONTH","
4669
MONTH(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4670
","
4671
Returns the month (1-12) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4672 4673 4674 4675 4676
","
MONTH(CREATED)
"

"Functions (Time and Date)","MONTHNAME","
4677
MONTHNAME(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4678 4679 4680 4681 4682 4683 4684
","
Returns the name of the month (in English).
","
MONTHNAME(CREATED)
"

"Functions (Time and Date)","PARSEDATETIME","
4685
PARSEDATETIME(string, formatString
4686
[, localeString [, timeZoneString]])
Thomas Mueller's avatar
Thomas Mueller committed
4687
","
4688 4689 4690
Parses a string and returns a timestamp.
The most important format characters are:
y year, M month, d day, H hour, m minute, s second.
4691
For details of the format, see ""java.text.SimpleDateFormat"".
Thomas Mueller's avatar
Thomas Mueller committed
4692 4693 4694 4695 4696 4697
","
CALL PARSEDATETIME('Sat, 3 Feb 2001 03:05:06 GMT',
    'EEE, d MMM yyyy HH:mm:ss z', 'en', 'GMT')
"

"Functions (Time and Date)","QUARTER","
4698
QUARTER(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4699
","
4700
Returns the quarter (1-4) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4701 4702 4703 4704 4705
","
QUARTER(CREATED)
"

"Functions (Time and Date)","SECOND","
4706
SECOND(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4707
","
4708
Returns the second (0-59) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4709 4710 4711 4712 4713
","
SECOND(CREATED)
"

"Functions (Time and Date)","WEEK","
4714
WEEK(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4715
","
4716
Returns the week (1-53) from a date/time value.
4717
This method uses the current system locale.
Thomas Mueller's avatar
Thomas Mueller committed
4718 4719 4720 4721
","
WEEK(CREATED)
"

4722
"Functions (Time and Date)","ISO_WEEK","
4723
ISO_WEEK(dateAndTime)
4724
","
4725
Returns the ISO week (1-53) from a date/time value.
4726
This function uses the ISO definition when
4727 4728 4729 4730 4731 4732
first week of year should have at least four days
and week is started with Monday.
","
ISO_WEEK(CREATED)
"

Thomas Mueller's avatar
Thomas Mueller committed
4733
"Functions (Time and Date)","YEAR","
4734
YEAR(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4735
","
4736
Returns the year from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4737 4738 4739 4740
","
YEAR(CREATED)
"

4741
"Functions (Time and Date)","ISO_YEAR","
4742
ISO_YEAR(dateAndTime)
4743
","
4744
Returns the ISO week year from a date/time value.
4745 4746 4747 4748
","
ISO_YEAR(CREATED)
"

Thomas Mueller's avatar
Thomas Mueller committed
4749
"Functions (System)","ARRAY_GET","
4750
ARRAY_GET(arrayExpression, indexExpression)
Thomas Mueller's avatar
Thomas Mueller committed
4751 4752
","
Returns one element of an array.
4753
Returns NULL if there is no such element or array is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
4754 4755 4756 4757 4758
","
CALL ARRAY_GET(('Hello', 'World'), 2)
"

"Functions (System)","ARRAY_LENGTH","
Thomas Mueller's avatar
Thomas Mueller committed
4759
ARRAY_LENGTH(arrayExpression)
Thomas Mueller's avatar
Thomas Mueller committed
4760 4761
","
Returns the length of an array.
4762
Returns NULL if the specified array is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
4763 4764 4765 4766
","
CALL ARRAY_LENGTH(('Hello', 'World'))
"

4767 4768 4769
"Functions (System)","ARRAY_CONTAINS","
ARRAY_CONTAINS(arrayExpression, value)
","
4770 4771
Returns a boolean TRUE if the array contains the value or FALSE if it does not contain it.
Returns NULL if the specified array is NULL.
4772 4773 4774 4775
","
CALL ARRAY_CONTAINS(('Hello', 'World'), 'Hello')
"

Thomas Mueller's avatar
Thomas Mueller committed
4776
"Functions (System)","AUTOCOMMIT","
4777
AUTOCOMMIT()
Thomas Mueller's avatar
Thomas Mueller committed
4778 4779 4780 4781 4782 4783 4784
","
Returns true if auto commit is switched on for this session.
","
AUTOCOMMIT()
"

"Functions (System)","CANCEL_SESSION","
4785
CANCEL_SESSION(sessionInt)
Thomas Mueller's avatar
Thomas Mueller committed
4786
","
4787 4788 4789
Cancels the currently executing statement of another session.
The method only works if the multithreaded kernel is enabled (see SET MULTI_THREADED).
Returns true if the statement was canceled, false if the session is closed or no statement is currently executing.
Thomas Mueller's avatar
Thomas Mueller committed
4790 4791

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4792 4793 4794 4795 4796
","
CANCEL_SESSION(3)
"

"Functions (System)","CASEWHEN Function","
4797
CASEWHEN(boolean, aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
4798 4799
","
Returns 'a' if the boolean expression is true, otherwise 'b'.
4800
Returns the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
4801 4802 4803 4804 4805
","
CASEWHEN(ID=1, 'A', 'B')
"

"Functions (System)","CAST","
4806
CAST(value AS dataType)
Thomas Mueller's avatar
Thomas Mueller committed
4807
","
4808 4809 4810 4811 4812 4813 4814 4815 4816 4817 4818 4819
Converts a value to another data type. The following conversion rules are used:
When converting a number to a boolean, 0 is false and every other value is true.
When converting a boolean to a number, false is 0 and true is 1.
When converting a number to a number of another type, the value is checked for overflow.
When converting a number to binary, the number of bytes matches the precision.
When converting a string to binary, it is hex encoded (every byte two characters);
a hex string can be converted to a number by first converting it to binary.
If a direct conversion is not possible, the value is first converted to a string.
","
CAST(NAME AS INT);
CAST(65535 AS BINARY);
CAST(CAST('FFFF' AS BINARY) AS INT);
Thomas Mueller's avatar
Thomas Mueller committed
4820 4821 4822
"

"Functions (System)","COALESCE","
4823
{ COALESCE | NVL } (aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4824 4825 4826 4827 4828 4829 4830
","
Returns the first value that is not null.
","
COALESCE(A, B, C)
"

"Functions (System)","CONVERT","
4831
CONVERT(value, dataType)
Thomas Mueller's avatar
Thomas Mueller committed
4832 4833 4834 4835 4836 4837 4838
","
Converts a value to another data type.
","
CONVERT(NAME, INT)
"

"Functions (System)","CURRVAL","
4839
CURRVAL( [ schemaName, ] sequenceString )
Thomas Mueller's avatar
Thomas Mueller committed
4840
","
4841 4842 4843 4844 4845
Returns the current (last) value of the sequence, independent of the session.
If the sequence was just created, the method returns (start - interval).
If the schema name is not set, the current schema is used.
If the schema name is not set, the sequence name is converted to uppercase (for compatibility).
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
4846 4847 4848 4849 4850
","
CURRVAL('TEST_SEQ')
"

"Functions (System)","CSVREAD","
4851
CSVREAD(fileNameString [, columnsString [, csvOptions ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4852
","
4853 4854
Returns the result set of reading the CSV (comma separated values) file.
For each parameter, NULL means the default value should be used.
Thomas Mueller's avatar
Thomas Mueller committed
4855 4856

If the column names are specified (a list of column names separated with the
4857
fieldSeparator), those are used, otherwise (or if they are set to NULL) the first line of
4858 4859 4860 4861 4862
the file is interpreted as the column names.
In that case, column names that contain no special characters (only letters, '_',
and digits; similar to the rule for Java identifiers) are considered case insensitive.
Other column names are case sensitive, that means you need to use quoted identifiers
(see below).
Thomas Mueller's avatar
Thomas Mueller committed
4863 4864 4865 4866 4867

The default charset is the default value for this system, and the default field separator
is a comma. Missing unquoted values as well as data that matches nullString is
parsed as NULL. All columns of type VARCHAR.

4868 4869
The BOM (the byte-order-mark) character 0xfeff at the beginning of the file is ignored.

4870
This function can be used like a table: ""SELECT * FROM CSVREAD(...)"".
4871

Thomas Mueller's avatar
Thomas Mueller committed
4872
Instead of a file, an URL may be used, for example
4873 4874
""jar:file:///c:/temp/example.zip!/org/example/nested.csv"".
To read a stream from the classpath, use the prefix ""classpath:"".
Thomas Mueller's avatar
Thomas Mueller committed
4875
To read from HTTP, use the prefix ""http:"" (as in a browser).
4876

Thomas Mueller's avatar
Thomas Mueller committed
4877 4878 4879
For performance reason, CSVREAD should not be used inside a join.
Instead, import the data first (possibly into a temporary table) and then use the table.

Thomas Mueller's avatar
Thomas Mueller committed
4880 4881 4882 4883
Admin rights are required to execute this command.
","
CALL CSVREAD('test.csv');
-- Read a file containing the columns ID, NAME with
Thomas Mueller's avatar
Thomas Mueller committed
4884 4885 4886 4887
CALL CSVREAD('test2.csv', 'ID|NAME', 'charset=UTF-8 fieldSeparator=|');
SELECT * FROM CSVREAD('data/test.csv', null, 'rowSeparator=;');
-- Read a tab-separated file
SELECT * FROM CSVREAD('data/test.tsv', null, 'rowSeparator=' || CHAR(9));
Thomas Mueller's avatar
Thomas Mueller committed
4888
SELECT ""Last Name"" FROM CSVREAD('address.csv');
4889
SELECT ""Last Name"" FROM CSVREAD('classpath:/org/acme/data/address.csv');
Thomas Mueller's avatar
Thomas Mueller committed
4890 4891 4892
"

"Functions (System)","CSVWRITE","
4893
CSVWRITE ( fileNameString, queryString [, csvOptions [, lineSepString] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4894
","
4895
Writes a CSV (comma separated values). The file is overwritten if it exists.
Thomas Mueller's avatar
Thomas Mueller committed
4896
If only a file name is specified, it will be written to the current working directory.
4897
For each parameter, NULL means the default value should be used.
Thomas Mueller's avatar
Thomas Mueller committed
4898
The default charset is the default value for this system, and the default field separator is a comma.
Thomas Mueller's avatar
Thomas Mueller committed
4899 4900 4901 4902 4903

The values are converted to text using the default string representation;
if another conversion is required you need to change the select statement accordingly.
The parameter nullString is used when writing NULL (by default nothing is written
when NULL appears). The default line separator is the default value for this
4904
system (system property ""line.separator"").
Thomas Mueller's avatar
Thomas Mueller committed
4905

Thomas Mueller's avatar
Thomas Mueller committed
4906 4907
The returned value is the number or rows written.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4908
","
Thomas Mueller's avatar
Thomas Mueller committed
4909 4910 4911 4912
CALL CSVWRITE('data/test.csv', 'SELECT * FROM TEST');
CALL CSVWRITE('data/test2.csv', 'SELECT * FROM TEST', 'charset=UTF-8 fieldSeparator=|');
-- Write a tab-separated file
CALL CSVWRITE('data/test.tsv', 'SELECT * FROM TEST', 'charset=UTF-8 fieldSeparator=' || CHAR(9));
Thomas Mueller's avatar
Thomas Mueller committed
4913 4914 4915
"

"Functions (System)","DATABASE","
4916
DATABASE()
Thomas Mueller's avatar
Thomas Mueller committed
4917 4918 4919 4920 4921 4922 4923
","
Returns the name of the database.
","
CALL DATABASE();
"

"Functions (System)","DATABASE_PATH","
4924
DATABASE_PATH()
Thomas Mueller's avatar
Thomas Mueller committed
4925
","
Thomas Mueller's avatar
Thomas Mueller committed
4926 4927
Returns the directory of the database files and the database name, if it is file based.
Returns NULL otherwise.
Thomas Mueller's avatar
Thomas Mueller committed
4928 4929 4930 4931
","
CALL DATABASE_PATH();
"

4932
"Functions (System)","DECODE","
Thomas Mueller's avatar
Thomas Mueller committed
4933
DECODE(value, whenValue, thenValue [,...])
4934 4935 4936 4937 4938 4939 4940 4941
","
Returns the first matching value. NULL is considered to match NULL.
If no match was found, then NULL or the last parameter (if the parameter count is even) is returned.
This function is provided for Oracle compatibility (see there for details).
","
CALL DECODE(RAND()>0.5, 0, 'Red', 1, 'Black');
"

4942
"Functions (System)","DISK_SPACE_USED","
Thomas Mueller's avatar
Thomas Mueller committed
4943
DISK_SPACE_USED(tableNameString)
4944 4945 4946 4947 4948 4949 4950 4951
","
Returns the approximate amount of space used by the table specified.
Does not currently take into account indexes or LOB's.
This function may be expensive since it has to load every page in the table.
","
CALL DISK_SPACE_USED('my_table');
"

4952
"Functions (System)","SIGNAL","
4953
SIGNAL(sqlStateString, messageString)
4954 4955 4956 4957 4958 4959
","
Throw an SQLException with the passed SQLState and reason.
","
CALL SIGNAL('23505', 'Duplicate user ID: ' || user_id);
"

4960 4961 4962 4963 4964 4965 4966 4967 4968 4969 4970 4971 4972 4973 4974 4975 4976
"Functions (System)","ESTIMATED_ENVELOPE","
ESTIMATED_ENVELOPE(tableNameString, columnNameString)
","
Returns the estimated minimum bounding box that encloses all specified GEOMETRY values.
Only 2D coordinate plane is supported.
NULL values are ignored.
This function is only supported by MVStore engine.
Column must have a spatial index.
This function is fast, but estimation may include uncommitted data (including data from other transactions),
may return approximate bounds, or be different with actual value due to other reasons.
Use with caution.
If estimation is not available this function returns NULL.
For accurate and reliable result use ESTIMATE aggregate function instead.
","
CALL ESTIMATED_ENVELOPE('MY_TABLE', 'GEOMETRY_COLUMN');
"

Thomas Mueller's avatar
Thomas Mueller committed
4977
"Functions (System)","FILE_READ","
4978
FILE_READ(fileNameString [,encodingString])
Thomas Mueller's avatar
Thomas Mueller committed
4979 4980 4981 4982
","
Returns the contents of a file. If only one parameter is supplied, the data are
returned as a BLOB. If two parameters are used, the data is returned as a CLOB
(text). The second parameter is the character set to use, NULL meaning the
4983
default character set for this system.
4984 4985 4986 4987

File names and URLs are supported.
To read a stream from the classpath, use the prefix ""classpath:"".

Thomas Mueller's avatar
Thomas Mueller committed
4988
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4989 4990 4991 4992 4993
","
SELECT LENGTH(FILE_READ('~/.h2.server.properties')) LEN;
SELECT FILE_READ('http://localhost:8182/stylesheet.css', NULL) CSS;
"

4994
"Functions (System)","FILE_WRITE","
4995
FILE_WRITE(blobValue, fileNameString)
4996 4997 4998 4999 5000 5001 5002 5003
","
Write the supplied parameter into a file. Return the number of bytes written.

Write access to folder, and admin rights are required to execute this command.
","
SELECT FILE_WRITE('Hello world', '/tmp/hello.txt')) LEN;
"

Thomas Mueller's avatar
Thomas Mueller committed
5004
"Functions (System)","GREATEST","
5005
GREATEST(aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
5006 5007 5008 5009 5010 5011 5012
","
Returns the largest value that is not NULL, or NULL if all values are NULL.
","
CALL GREATEST(1, 2, 3);
"

"Functions (System)","IDENTITY","
5013
IDENTITY()
Thomas Mueller's avatar
Thomas Mueller committed
5014 5015
","
Returns the last inserted identity value for this session.
5016
This value changes whenever a new sequence number was generated,
5017
even within a trigger or Java function. See also SCOPE_IDENTITY.
5018
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
5019 5020 5021 5022 5023
","
CALL IDENTITY();
"

"Functions (System)","IFNULL","
5024
IFNULL(aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
5025 5026 5027 5028 5029 5030 5031
","
Returns the value of 'a' if it is not null, otherwise 'b'.
","
CALL IFNULL(NULL, '');
"

"Functions (System)","LEAST","
5032
LEAST(aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
5033 5034 5035 5036 5037 5038 5039
","
Returns the smallest value that is not NULL, or NULL if all values are NULL.
","
CALL LEAST(1, 2, 3);
"

"Functions (System)","LOCK_MODE","
5040
LOCK_MODE()
Thomas Mueller's avatar
Thomas Mueller committed
5041 5042
","
Returns the current lock mode. See SET LOCK_MODE.
5043
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
5044 5045 5046 5047 5048
","
CALL LOCK_MODE();
"

"Functions (System)","LOCK_TIMEOUT","
5049
LOCK_TIMEOUT()
Thomas Mueller's avatar
Thomas Mueller committed
5050 5051 5052 5053 5054 5055 5056 5057
","
Returns the lock timeout of the current session (in milliseconds).
","
LOCK_TIMEOUT()
"

"Functions (System)","LINK_SCHEMA","
LINK_SCHEMA(targetSchemaString, driverString, urlString,
5058
userString, passwordString, sourceSchemaString)
Thomas Mueller's avatar
Thomas Mueller committed
5059
","
5060 5061 5062 5063 5064
Creates table links for all tables in a schema.
If tables with the same name already exist, they are dropped first.
The target schema is created automatically if it does not yet exist.
The driver name may be empty if the driver is already loaded.
The list of tables linked is returned in the form of a result set.
Thomas Mueller's avatar
Thomas Mueller committed
5065
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5066 5067 5068 5069 5070
","
CALL LINK_SCHEMA('TEST2', '', 'jdbc:h2:test2', 'sa', 'sa', 'PUBLIC');
"

"Functions (System)","MEMORY_FREE","
5071
MEMORY_FREE()
Thomas Mueller's avatar
Thomas Mueller committed
5072
","
Thomas Mueller's avatar
Thomas Mueller committed
5073
Returns the free memory in KB (where 1024 bytes is a KB).
5074
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
5075 5076
The garbage is run before returning the value.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5077 5078 5079 5080 5081
","
MEMORY_FREE()
"

"Functions (System)","MEMORY_USED","
5082
MEMORY_USED()
Thomas Mueller's avatar
Thomas Mueller committed
5083
","
Thomas Mueller's avatar
Thomas Mueller committed
5084
Returns the used memory in KB (where 1024 bytes is a KB).
5085
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
5086 5087
The garbage is run before returning the value.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5088 5089 5090 5091 5092
","
MEMORY_USED()
"

"Functions (System)","NEXTVAL","
5093
NEXTVAL ( [ schemaName, ] sequenceString )
Thomas Mueller's avatar
Thomas Mueller committed
5094
","
5095 5096 5097 5098
Returns the next value of the sequence.
Used values are never re-used, even when the transaction is rolled back.
If the schema name is not set, the current schema is used, and the sequence name is converted to uppercase (for compatibility).
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
5099 5100 5101 5102 5103
","
NEXTVAL('TEST_SEQ')
"

"Functions (System)","NULLIF","
5104
NULLIF(aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
5105 5106 5107 5108 5109 5110
","
Returns NULL if 'a' is equals to 'b', otherwise 'a'.
","
NULLIF(A, B)
"

5111 5112 5113 5114
"Functions (System)","NVL2","
NVL2(testValue, aValue, bValue)
","
If the test value is null, then 'b' is returned. Otherwise, 'a' is returned.
5115
The data type of the returned value is the data type of 'a' if this is a text type.
5116 5117 5118 5119
","
NVL2(X, 'not null', 'null')
"

Thomas Mueller's avatar
Thomas Mueller committed
5120
"Functions (System)","READONLY","
5121
READONLY()
Thomas Mueller's avatar
Thomas Mueller committed
5122 5123 5124 5125 5126 5127 5128
","
Returns true if the database is read-only.
","
READONLY()
"

"Functions (System)","ROWNUM","
5129
ROWNUM()
Thomas Mueller's avatar
Thomas Mueller committed
5130
","
5131
Returns the number of the current row.
5132
This method returns an integer value.
5133
It is supported for SELECT statements, as well as for DELETE and UPDATE.
5134
The first row has the row number 1, and is calculated before ordering and grouping the result set,
5135
but after evaluating index conditions (even when the index conditions are specified in an outer query).
5136
Use the ROW_NUMBER() OVER () function to get row numbers after grouping or in specified order.
Thomas Mueller's avatar
Thomas Mueller committed
5137
","
5138 5139
SELECT ROWNUM(), * FROM TEST;
SELECT ROWNUM(), * FROM (SELECT * FROM TEST ORDER BY NAME);
Thomas Mueller's avatar
Thomas Mueller committed
5140
SELECT ID FROM (SELECT T.*, ROWNUM AS R FROM TEST T) WHERE R BETWEEN 2 AND 3;
Thomas Mueller's avatar
Thomas Mueller committed
5141 5142 5143
"

"Functions (System)","SCHEMA","
5144
SCHEMA()
Thomas Mueller's avatar
Thomas Mueller committed
5145
","
5146
Returns the name of the default schema for this session.
Thomas Mueller's avatar
Thomas Mueller committed
5147 5148 5149 5150
","
CALL SCHEMA()
"

5151 5152 5153
"Functions (System)","SCOPE_IDENTITY","
SCOPE_IDENTITY()
","
5154
Returns the last inserted identity value for this session for the current scope
5155
(the current statement).
5156 5157 5158 5159 5160 5161
Changes within triggers and Java functions are ignored. See also IDENTITY().
This method returns a long.
","
CALL SCOPE_IDENTITY();
"

Thomas Mueller's avatar
Thomas Mueller committed
5162
"Functions (System)","SESSION_ID","
5163
SESSION_ID()
Thomas Mueller's avatar
Thomas Mueller committed
5164
","
5165 5166 5167 5168
Returns the unique session id number for the current database connection.
This id stays the same while the connection is open.
This method returns an int.
The database engine may re-use a session id after the connection is closed.
Thomas Mueller's avatar
Thomas Mueller committed
5169 5170 5171 5172 5173
","
CALL SESSION_ID()
"

"Functions (System)","SET","
5174
SET(@variableName, value)
Thomas Mueller's avatar
Thomas Mueller committed
5175
","
5176 5177 5178
Updates a variable with the given value.
The new value is returned.
When used in a query, the value is updated in the order the rows are read.
Thomas Mueller's avatar
Thomas Mueller committed
5179
When used in a subquery, not all rows might be read depending on the query plan.
Thomas Mueller's avatar
Thomas Mueller committed
5180
This can be used to implement running totals / cumulative sums.
Thomas Mueller's avatar
Thomas Mueller committed
5181 5182 5183 5184 5185
","
SELECT X, SET(@I, IFNULL(@I, 0)+X) RUNNING_TOTAL FROM SYSTEM_RANGE(1, 10)
"

"Functions (System)","TABLE","
5186
{ TABLE | TABLE_DISTINCT } ( { name dataType = expression } [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
5187 5188 5189 5190 5191 5192 5193
","
Returns the result set. TABLE_DISTINCT removes duplicate rows.
","
SELECT * FROM TABLE(ID INT=(1, 2), NAME VARCHAR=('Hello', 'World'))
"

"Functions (System)","TRANSACTION_ID","
5194
TRANSACTION_ID()
Thomas Mueller's avatar
Thomas Mueller committed
5195
","
5196 5197
Returns the current transaction id for this session.
This method returns NULL if there is no uncommitted change, or if the the database is not persisted.
Thomas Mueller's avatar
Thomas Mueller committed
5198
Otherwise a value of the following form is returned:
5199
""logFileId-position-sessionId"".
5200 5201
This method returns a string.
The value is unique across database restarts (values are not re-used).
Thomas Mueller's avatar
Thomas Mueller committed
5202 5203 5204 5205
","
CALL TRANSACTION_ID()
"

5206 5207 5208 5209 5210 5211 5212 5213 5214 5215 5216 5217
"Functions (System)","TRUNCATE_VALUE","
TRUNCATE_VALUE(value, precisionInt, forceBoolean)
","
Truncate a value to the required precision.
The precision of the returned value may be a bit larger than requested,
because fixed precision values are not truncated (unlike the numeric TRUNCATE method).
Unlike CAST, the truncating a decimal value may lose precision if the force flag is set to true.
The method returns a value with the same data type as the first parameter.
","
CALL TRUNCATE_VALUE(X, 10, TRUE);
"

5218 5219 5220 5221 5222 5223 5224 5225 5226 5227 5228 5229
"Functions (System)","UNNEST","
UNNEST(array, [,...]) [WITH ORDINALITY]
","
Returns the result set.
Number of columns is equal to number of arguments,
plus one additional column with row number if WITH ORDINALITY is specified.
Number of rows is equal to length of longest specified array.
If multiple arguments are specified and they have different length, cells with missing values will contain null values.
","
SELECT * FROM UNNEST(ARRAY['a', 'b', 'c']);
"

Thomas Mueller's avatar
Thomas Mueller committed
5230
"Functions (System)","USER","
5231
{ USER | CURRENT_USER } ()
Thomas Mueller's avatar
Thomas Mueller committed
5232 5233 5234 5235 5236 5237
","
Returns the name of the current user of this session.
","
CURRENT_USER()
"

5238 5239 5240 5241 5242 5243 5244 5245
"Functions (System)","H2VERSION","
H2VERSION()
","
Returns the H2 version as a String.
","
H2VERSION()
"

5246
"Functions (Window)","ROW_NUMBER","
5247
ROW_NUMBER() OVER windowNameOrSpecification
5248 5249
","
Returns the number of the current row starting with 1.
5250
Window frame clause is not allowed for this function.
5251 5252 5253 5254 5255 5256 5257 5258 5259 5260

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT ROW_NUMBER() OVER (), * FROM TEST;
SELECT ROW_NUMBER() OVER (ORDER BY ID), * FROM TEST;
SELECT ROW_NUMBER() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

"Functions (Window)","RANK","
5261
RANK() OVER windowNameOrSpecification
5262 5263 5264 5265 5266
","
Returns the rank of the current row.
The rank of a row is the number of rows that precede this row plus 1.
If two or more rows have the same values in ORDER BY columns, these rows get the same rank from the first row with the same values.
It means that gaps in ranks are possible.
5267 5268
This function requires window order clause.
Window frame clause is not allowed for this function.
5269 5270 5271 5272 5273 5274 5275 5276 5277

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT RANK() OVER (ORDER BY ID), * FROM TEST;
SELECT RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

"Functions (Window)","DENSE_RANK","
5278
DENSE_RANK() OVER windowNameOrSpecification
5279 5280 5281 5282 5283
","
Returns the dense rank of the current row.
The rank of a row is the number of groups of rows with the same values in ORDER BY columns that precede group with this row plus 1.
If two or more rows have the same values in ORDER BY columns, these rows get the same rank.
Gaps in ranks are not possible.
5284 5285
This function requires window order clause.
Window frame clause is not allowed for this function.
5286 5287 5288 5289

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
5290 5291 5292 5293 5294
SELECT DENSE_RANK() OVER (ORDER BY ID), * FROM TEST;
SELECT DENSE_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

"Functions (Window)","PERCENT_RANK","
5295
PERCENT_RANK() OVER windowNameOrSpecification
5296 5297 5298 5299
","
Returns the relative rank of the current row.
The relative rank is calculated as (RANK - 1) / (NR - 1),
where RANK is a rank of the row and NR is a number of rows in window partition with this row.
5300
Note that result is always 0 if window order clause is not specified.
5301
Window frame clause is not allowed for this function.
5302 5303 5304 5305 5306 5307 5308 5309 5310

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT PERCENT_RANK() OVER (ORDER BY ID), * FROM TEST;
SELECT PERCENT_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

"Functions (Window)","CUME_DIST","
5311
CUME_DIST() OVER windowNameOrSpecification
5312 5313 5314 5315 5316
","
Returns the relative rank of the current row.
The relative rank is calculated as NP / NR
where NP is a number of rows that precede the current row or have the same values in ORDER BY columns
and NR is a number of rows in window partition with this row.
5317
Note that result is always 1 if window order clause is not specified.
5318
Window frame clause is not allowed for this function.
5319 5320 5321 5322 5323 5324

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT CUME_DIST() OVER (ORDER BY ID), * FROM TEST;
SELECT CUME_DIST() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
5325 5326
"

5327
"Functions (Window)","NTILE","
5328
NTILE(int) OVER windowNameOrSpecification
5329 5330 5331 5332 5333 5334
","
Distributes the rows into a specified number of groups.
Number of groups should be a positive integer value.
NTILE returns the 1-based number of the group to which the current row belongs.
First groups will have more rows if number of rows is not divisible by number of groups.
For example, if 5 rows are distributed into 2 groups this function returns 1 for the first 3 row and 2 for the last 2 rows.
5335 5336
This function requires window order clause.
Window frame clause is not allowed for this function.
5337 5338 5339 5340 5341 5342 5343 5344

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT NTILE(10) OVER (ORDER BY ID), * FROM TEST;
SELECT NTILE(5) OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

5345 5346
"Functions (Window)","LEAD","
LEAD(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS]
5347
OVER windowNameOrSpecification
5348 5349 5350 5351 5352 5353 5354
","
Returns the value in a next row with specified offset relative to the current row.
Offset must be non-negative.
If IGNORE NULLS is specified rows with null values in selected expression are skipped.
If number of considered rows is less than specified relative number this function returns NULL
or the specified default value, if any.
If offset is 0 the value from the current row is returned unconditionally.
5355 5356
This function requires window order clause.
Window frame clause is not allowed for this function.
5357 5358 5359 5360 5361 5362 5363 5364 5365 5366 5367 5368

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT LEAD(X) OVER (ORDER BY ID), * FROM TEST;
SELECT LEAD(X, 2, 0) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
), * FROM TEST;
"

"Functions (Window)","LAG","
LAG(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS]
5369
OVER windowNameOrSpecification
5370 5371 5372 5373 5374 5375 5376
","
Returns the value in a previous row with specified offset relative to the current row.
Offset must be non-negative.
If IGNORE NULLS is specified rows with null values in selected expression are skipped.
If number of considered rows is less than specified relative number this function returns NULL
or the specified default value, if any.
If offset is 0 the value from the current row is returned unconditionally.
5377 5378
This function requires window order clause.
Window frame clause is not allowed for this function.
5379 5380 5381 5382 5383 5384 5385 5386 5387 5388

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT LAG(X) OVER (ORDER BY ID), * FROM TEST;
SELECT LAG(X, 2, 0) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
), * FROM TEST;
"

5389
"Functions (Window)","FIRST_VALUE","
5390 5391
FIRST_VALUE(value) [{RESPECT|IGNORE} NULLS]
OVER windowNameOrSpecification
5392 5393 5394 5395 5396 5397 5398 5399 5400 5401 5402 5403
","
Returns the first value in a window.
If IGNORE NULLS is specified null values are skipped and the function returns first non-null value, if any.

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT FIRST_VALUE(X) OVER (ORDER BY ID), * FROM TEST;
SELECT FIRST_VALUE(X) IGNORE NULLS OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

"Functions (Window)","LAST_VALUE","
5404 5405
LAST_VALUE(value) [{RESPECT|IGNORE} NULLS]
OVER windowNameOrSpecification
5406 5407 5408 5409
","
Returns the last value in a window.
If IGNORE NULLS is specified null values are skipped and the function returns last non-null value before them, if any;
if there is no non-null value it returns NULL.
5410 5411
Note that the last value is actually a value in the current group of rows
if window order clause is specified and window frame clause is not specified.
5412 5413 5414 5415 5416

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT LAST_VALUE(X) OVER (ORDER BY ID), * FROM TEST;
5417 5418 5419 5420
SELECT LAST_VALUE(X) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
    RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
), * FROM TEST;
5421 5422 5423
"

"Functions (Window)","NTH_VALUE","
5424
NTH_VALUE(value, nInt) [FROM {FIRST|LAST}] [{RESPECT|IGNORE} NULLS]
5425
OVER windowNameOrSpecification
5426 5427 5428
","
Returns the value in a row with a specified relative number in a window.
Relative row number must be positive.
5429
If FROM LAST is specified rows a counted backwards from the last row.
5430 5431
If IGNORE NULLS is specified rows with null values in selected expression are skipped.
If number of considered rows is less than specified relative number this function returns NULL.
5432 5433
Note that the last row is actually a last row in the current group of rows
if window order clause is specified and window frame clause is not specified.
5434 5435 5436 5437 5438

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT NTH_VALUE(X) OVER (ORDER BY ID), * FROM TEST;
5439 5440 5441 5442
SELECT NTH_VALUE(X) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
    RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
), * FROM TEST;
5443 5444
"

Thomas Mueller's avatar
Thomas Mueller committed
5445 5446 5447 5448 5449 5450 5451 5452 5453 5454 5455 5456 5457 5458 5459
"System Tables","Information Schema","
INFORMATION_SCHEMA
","
To get the list of system tables, execute the statement SELECT * FROM
INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'INFORMATION_SCHEMA'
","

"
"System Tables","Range Table","
SYSTEM_RANGE(start, end)
","
Contains all values from start to end (this is a dynamic table).
","
SYSTEM_RANGE(0, 100)
"
Thomas Mueller's avatar
Thomas Mueller committed
5460