help.csv 136.4 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 7 8
SELECT [ TOP term ] [ DISTINCT | ALL ] selectExpression [,...]
FROM tableExpression [,...] [ WHERE expression ]
[ GROUP BY expression [,...] ] [ HAVING expression ]
9 10 11 12 13
[ { UNION [ ALL ] | MINUS | EXCEPT | INTERSECT } select ]
[ ORDER BY order [,...] ]
[ { LIMIT expression [ OFFSET expression ] [ SAMPLE_SIZE rowCountInt ] }
    | { [ OFFSET expression { ROW | ROWS } ]
    [ { FETCH { FIRST | NEXT } expression { ROW | ROWS } ONLY } ] } ]
14
[ FOR UPDATE ]
Thomas Mueller's avatar
Thomas Mueller committed
15 16
","
Selects data from a table or multiple tables.
17 18 19 20
GROUP BY groups the the result by the given expression(s).
HAVING filter rows after grouping.
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
21

22
LIMIT and FETCH FIRST/NEXT ROW(S) ONLY limits the number of rows returned by the query (no limit if null or smaller than zero).
Thomas Mueller's avatar
Thomas Mueller committed
23
OFFSET specified how many rows to skip.
24
Please note using high offset values should be avoided because it can cause performance problems.
25
SAMPLE_SIZE limits the number of rows read for aggregate queries.
26

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

31 32
If FOR UPDATE is specified, the tables are locked for writing. When using
MVCC, only the selected rows are locked as in an UPDATE statement.
Thomas Mueller's avatar
Thomas Mueller committed
33
In this case, aggregate, GROUP BY, DISTINCT queries or joins
34
are not allowed in this case.
Thomas Mueller's avatar
Thomas Mueller committed
35 36
","
SELECT * FROM TEST;
37 38 39 40 41
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;
SELECT * FROM TEST LIMIT 1000;
Thomas Mueller's avatar
Thomas Mueller committed
42 43 44 45 46 47
SELECT * FROM (SELECT ID, COUNT(*) FROM TEST
    GROUP BY ID UNION SELECT NULL, COUNT(*) FROM TEST)
    ORDER BY 1 NULLS LAST;
"

"Commands (DML)","INSERT","
48 49
INSERT INTO tableName
{ [ ( columnName [,...] ) ]
50 51
    { VALUES { ( { DEFAULT | expression } [,...] ) } [,...]
        | [ DIRECT ] [ SORTED ] select } } |
52
    { SET { columnName = { DEFAULT | expression } } [,...] }
Thomas Mueller's avatar
Thomas Mueller committed
53 54
","
Inserts a new row / new rows into a table.
55 56 57 58

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
59 60 61 62 63
","
INSERT INTO TEST VALUES(1, 'Hello')
"

"Commands (DML)","UPDATE","
64 65 66
UPDATE tableName [ [ AS ] newTableAlias ] SET
{ { columnName = { DEFAULT | expression } } [,...] } |
    { ( columnName [,...] ) = ( select ) }
67
[ WHERE expression ] [ ORDER BY order [,...] ] [ LIMIT expression ]
Thomas Mueller's avatar
Thomas Mueller committed
68 69
","
Updates data in a table.
70
ORDER BY is supported for MySQL compatibility, but it is ignored.
Thomas Mueller's avatar
Thomas Mueller committed
71
","
72 73
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
74 75 76
"

"Commands (DML)","DELETE","
77
DELETE [ TOP term ] FROM tableName [ WHERE expression ] [ LIMIT term ]
Thomas Mueller's avatar
Thomas Mueller committed
78 79
","
Deletes rows form a table.
80
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
81 82 83 84 85 86 87
","
DELETE FROM TEST WHERE ID=2
"

"Commands (DML)","BACKUP","
BACKUP TO fileNameString
","
Thomas Mueller's avatar
Thomas Mueller committed
88 89
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
90
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
91 92 93 94 95 96 97
","
BACKUP TO 'backup.zip'
"

"Commands (DML)","CALL","
CALL expression
","
Thomas Mueller's avatar
Thomas Mueller committed
98 99 100
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
101 102 103 104 105
","
CALL 15*25
"

"Commands (DML)","EXPLAIN","
106 107
EXPLAIN { [ PLAN FOR ] | ANALYZE }
{ select | insert | update | delete | merge }
Thomas Mueller's avatar
Thomas Mueller committed
108 109
","
Shows the execution plan for a statement.
110 111
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
112 113 114 115 116
","
EXPLAIN SELECT * FROM TEST WHERE ID=1
"

"Commands (DML)","MERGE","
117 118
MERGE INTO tableName [ ( columnName [,...] ) ]
[ KEY ( columnName [,...] ) ]
119
{ VALUES { ( { DEFAULT | expression } [,...] ) } [,...] | select }
Thomas Mueller's avatar
Thomas Mueller committed
120 121 122
","
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
123
row per new row is affected, an exception is thrown.
Thomas Mueller's avatar
Thomas Mueller committed
124 125 126 127
","
MERGE INTO TEST KEY(ID) VALUES(2, 'World')
"

Owner's avatar
Owner committed
128
"Commands (DML)","MERGE USING","
129 130 131 132
MERGE INTO targetTableName [ [AS] targetAlias]
USING { ( select ) | sourceTableName }[ [AS] sourceAlias ]
ON ( expression )
[ WHEN MATCHED THEN [ update ] [ delete] ]
133
[ WHEN NOT MATCHED THEN insert ]
134 135 136 137 138 139 140
","
Updates or deletes existing rows, and insert rows that don't exist. The ON clause
specifies the matching column expression and must be specified. If more than one row
is updated per input row, an exception is thrown.
If the source data contains duplicate rows (specifically those columns used in the
row matching ON clause), then an exception is thrown to prevent two updates applying
to the same target row. The embedded update, delete or insert statements can not re-specify
Owner's avatar
Owner committed
141 142
the target table name.
","
143 144 145 146 147 148 149 150 151 152 153 154 155 156
MERGE INTO TARGET_TABLE AS T USING SOURCE_TABLE AS S
    ON (T.ID = S.ID)
    WHEN MATCHED THEN
        UPDATE SET T.COL1 = S.COL1 WHERE T.COL2<>'FINAL'
        DELETE WHERE T.COL2='FINAL'
    WHEN NOT MATCHED THEN
        INSERT (ID,COL1,COL2) VALUES(S.ID,S.COL1,S.COL2)
MERGE INTO TARGET_TABLE AS T USING (SELECT * FROM SOURCE_TABLE) AS S
    ON (T.ID = S.ID)
    WHEN MATCHED THEN
        UPDATE SET T.COL1 = S.COL1 WHERE T.COL2<>'FINAL'
        DELETE WHERE T.COL2='FINAL'
    WHEN NOT MATCHED THEN
        INSERT (ID,COL1,COL2) VALUES(S.ID,S.COL1,S.COL2)
Owner's avatar
Owner committed
157 158
"

Thomas Mueller's avatar
Thomas Mueller committed
159
"Commands (DML)","RUNSCRIPT","
160 161
RUNSCRIPT FROM fileNameString scriptCompressionEncryption
[ CHARSET charsetString ]
Thomas Mueller's avatar
Thomas Mueller committed
162 163 164 165 166 167
","
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.

168
Instead of a file name, an URL may be used.
169
To read a stream from the classpath, use the prefix 'classpath:'.
170
See the Pluggable File System section on the Advanced page.
171

172
The compression algorithm must match the one used when creating the script.
Thomas Mueller's avatar
Thomas Mueller committed
173 174 175
Instead of a file, an URL may be used.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
176
","
177
RUNSCRIPT FROM 'backup.sql'
178
RUNSCRIPT FROM 'classpath:/com/acme/test.sql'
Thomas Mueller's avatar
Thomas Mueller committed
179 180 181
"

"Commands (DML)","SCRIPT","
182 183
SCRIPT [ SIMPLE ] [ NODATA ] [ NOPASSWORDS ] [ NOSETTINGS ]
[ DROP ] [ BLOCKSIZE blockSizeInt ]
184
[ TO fileNameString scriptCompressionEncryption
185
    [ CHARSET charsetString ] ]
186 187
[ TABLE tableName [, ...] ]
[ SCHEMA schemaName [, ...] ]
Thomas Mueller's avatar
Thomas Mueller committed
188
","
189 190 191 192 193 194 195
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
196 197
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
198
out-of-line commands.
Thomas Mueller's avatar
Thomas Mueller committed
199
NOSETTINGS turns off dumping the database settings (the SET XXX commands)
200

201
If no 'TO fileName' clause is specified, the
Thomas Mueller's avatar
Thomas Mueller committed
202 203 204 205
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.

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

Thomas Mueller's avatar
Thomas Mueller committed
210 211 212
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
213
Admin rights are required to execute this command.
214

215
When using the TABLE or SCHEMA option, only the selected table(s) / schema(s) are included.
Thomas Mueller's avatar
Thomas Mueller committed
216 217 218 219 220
","
SCRIPT NODATA
"

"Commands (DML)","SHOW","
221 222
SHOW { SCHEMAS | TABLES [ FROM schemaName ] |
    COLUMNS FROM tableName [ FROM schemaName ] }
Thomas Mueller's avatar
Thomas Mueller committed
223 224 225 226 227 228
","
Lists the schemas, tables, or the columns of a table.
","
SHOW TABLES
"

229
"Commands (DML)","WITH","
230 231
WITH [ RECURSIVE ] { name [( columnName [,...] )] AS ( select ) [,...] }
{ select | insert | update | merge | delete | createTable }
232
","
233
Can be used to create a recursive or non-recursive query (common table expression).
234
For recursive queries the first select has to be a UNION.
235
One or more common table entries can be referred to by name.
236
Column name declarations are now optional - the column names will be inferred from the named select queries.
237
The final action in a WITH statement can be a select, insert, update, merge, delete or create table.
238
","
239
WITH RECURSIVE cte(n) AS (
240 241 242
        SELECT 1
    UNION ALL
        SELECT n + 1
243
        FROM cte
244 245
        WHERE n < 100
)
246 247 248 249
SELECT sum(n) FROM cte;

Example 2:
WITH cte1 AS (
250
        SELECT 1 AS FIRST_COLUMN
251 252
), cte2 AS (
        SELECT FIRST_COLUMN+1 AS FIRST_COLUMN FROM cte1
253
)
254
SELECT sum(FIRST_COLUMN) FROM cte2;
255 256
"

Thomas Mueller's avatar
Thomas Mueller committed
257
"Commands (DDL)","ALTER INDEX RENAME","
258
ALTER INDEX [ IF EXISTS ] indexName RENAME TO newIndexName
Thomas Mueller's avatar
Thomas Mueller committed
259
","
Thomas Mueller's avatar
Thomas Mueller committed
260
Renames an index.
Thomas Mueller's avatar
Thomas Mueller committed
261
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
262 263 264 265
","
ALTER INDEX IDXNAME RENAME TO IDX_TEST_NAME
"

266
"Commands (DDL)","ALTER SCHEMA RENAME","
267
ALTER SCHEMA [ IF EXISTS ] schema RENAME TO newSchemaName
268 269
","
Renames a schema.
Thomas Mueller's avatar
Thomas Mueller committed
270
This command commits an open transaction in this connection.
271 272 273 274
","
ALTER SCHEMA TEST RENAME TO PRODUCTION
"

Thomas Mueller's avatar
Thomas Mueller committed
275
"Commands (DDL)","ALTER SEQUENCE","
276 277 278
ALTER SEQUENCE [ IF EXISTS ] sequenceName
[ RESTART WITH long ]
[ INCREMENT BY long ]
279 280
[ MINVALUE long | NOMINVALUE | NO MINVALUE ]
[ MAXVALUE long | NOMAXVALUE | NO MAXVALUE ]
281 282
[ CYCLE long | NOCYCLE | NO CYCLE ]
[ CACHE long | NOCACHE | NO CACHE ]
Thomas Mueller's avatar
Thomas Mueller committed
283
","
284
Changes the parameters of a sequence.
Thomas Mueller's avatar
Thomas Mueller committed
285
This command does not commit the current transaction; however the new value is used by other
Thomas Mueller's avatar
Thomas Mueller committed
286 287 288 289 290 291
transactions immediately, and rolling back this command has no effect.
","
ALTER SEQUENCE SEQ_ID RESTART WITH 1000
"

"Commands (DDL)","ALTER TABLE ADD","
292
ALTER TABLE [ IF EXISTS ] tableName ADD [ COLUMN ]
293 294
{ [ IF NOT EXISTS ] columnName columnDefinition
    | ( { columnName columnDefinition | constraint } [,...] ) }
295
[ { { BEFORE | AFTER } columnName } | FIRST ]
Thomas Mueller's avatar
Thomas Mueller committed
296
","
Thomas Mueller's avatar
Thomas Mueller committed
297
Adds a new column to a table.
Thomas Mueller's avatar
Thomas Mueller committed
298
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
299 300 301 302 303
","
ALTER TABLE TEST ADD CREATEDATE TIMESTAMP
"

"Commands (DDL)","ALTER TABLE ADD CONSTRAINT","
304
ALTER TABLE [ IF EXISTS ] tableName ADD constraint [ CHECK | NOCHECK ]
Thomas Mueller's avatar
Thomas Mueller committed
305 306 307
","
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
308
The required indexes are automatically created if they don't exist yet.
Thomas Mueller's avatar
Thomas Mueller committed
309
It is not possible to disable checking for unique constraints.
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
","
ALTER TABLE TEST ADD CONSTRAINT NAME_UNIQUE UNIQUE(NAME)
"

315
"Commands (DDL)","ALTER TABLE RENAME CONSTRAINT","
316 317
ALTER TABLE [ IF EXISTS ] tableName RENAME oldConstraintName
TO newConstraintName
318 319 320 321 322 323 324
","
Renames a constraint.
This command commits an open transaction in this connection.
","
ALTER TABLE TEST RENAME CONSTRAINT FOO TO BAR
"

325
"Commands (DDL)","ALTER TABLE ALTER COLUMN","
326
ALTER TABLE [ IF EXISTS ] tableName ALTER COLUMN columnName
327
{ { columnDefinition }
328 329 330 331
    | { RENAME TO name }
    | { RESTART WITH long }
    | { SELECTIVITY int }
    | { SET DEFAULT expression }
332
    | { SET ON UPDATE expression }
333
    | { SET NULL }
334
    | { SET NOT NULL }
335 336
    | { SET { VISIBLE | INVISIBLE } }
    | { DROP { DEFAULT | ON UPDATE } } }
Thomas Mueller's avatar
Thomas Mueller committed
337
","
338 339
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
340

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

343 344 345
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
346

347 348 349 350
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
351

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

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

356
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
357
Single column indexes on this column are dropped.
358 359 360

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

361 362 363
SET INVISIBLE makes the column hidden, i.e. it will not appear in SELECT * results.
SET VISIBLE has the reverse effect.

364 365 366 367
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
368
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
369
","
370 371 372 373 374 375 376
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;
377 378
ALTER TABLE TEST ALTER COLUMN NAME SET VISIBLE;
ALTER TABLE TEST ALTER COLUMN NAME SET INVISIBLE;
Thomas Mueller's avatar
Thomas Mueller committed
379 380 381
"

"Commands (DDL)","ALTER TABLE DROP COLUMN","
382
ALTER TABLE [ IF EXISTS ] tableName DROP COLUMN [ IF EXISTS ]
383
columnName [,...] | ( columnName [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
384
","
385
Removes column(s) from a table.
Thomas Mueller's avatar
Thomas Mueller committed
386
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
387 388
","
ALTER TABLE TEST DROP COLUMN NAME
389
ALTER TABLE TEST DROP COLUMN NAME1, NAME2
390
ALTER TABLE TEST DROP COLUMN (NAME1, NAME2)
Thomas Mueller's avatar
Thomas Mueller committed
391 392 393
"

"Commands (DDL)","ALTER TABLE DROP CONSTRAINT","
394 395
ALTER TABLE [ IF EXISTS ] tableName DROP
{ CONSTRAINT [ IF EXISTS ] constraintName | PRIMARY KEY }
Thomas Mueller's avatar
Thomas Mueller committed
396 397
","
Removes a constraint or a primary key 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 401 402 403
","
ALTER TABLE TEST DROP CONSTRAINT UNIQUE_NAME
"

"Commands (DDL)","ALTER TABLE SET","
404
ALTER TABLE [ IF EXISTS ] tableName SET REFERENTIAL_INTEGRITY
405
{ FALSE | TRUE } [ CHECK | NOCHECK ]
Thomas Mueller's avatar
Thomas Mueller committed
406 407 408 409 410 411
","
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.
412

Thomas Mueller's avatar
Thomas Mueller committed
413
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
414 415 416 417 418
","
ALTER TABLE TEST SET REFERENTIAL_INTEGRITY FALSE
"

"Commands (DDL)","ALTER TABLE RENAME","
419
ALTER TABLE [ IF EXISTS ] tableName RENAME TO newName
Thomas Mueller's avatar
Thomas Mueller committed
420
","
Thomas Mueller's avatar
Thomas Mueller committed
421
Renames a table.
Thomas Mueller's avatar
Thomas Mueller committed
422
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
423 424 425 426 427
","
ALTER TABLE TEST RENAME TO MY_DATA
"

"Commands (DDL)","ALTER USER ADMIN","
428
ALTER USER userName ADMIN { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
429
","
Thomas Mueller's avatar
Thomas Mueller committed
430 431 432 433
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
434
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
435 436 437 438 439 440 441
","
ALTER USER TOM ADMIN TRUE
"

"Commands (DDL)","ALTER USER RENAME","
ALTER USER userName RENAME TO newUserName
","
Thomas Mueller's avatar
Thomas Mueller committed
442 443 444 445
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
446
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
447
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
448 449 450 451 452
","
ALTER USER TOM RENAME TO THOMAS
"

"Commands (DDL)","ALTER USER SET PASSWORD","
453
ALTER USER userName SET { PASSWORD string | SALT bytes HASH bytes }
Thomas Mueller's avatar
Thomas Mueller committed
454
","
Thomas Mueller's avatar
Thomas Mueller committed
455 456 457 458 459 460
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
461
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
462 463 464 465 466
","
ALTER USER SA SET PASSWORD 'rioyxlgt'
"

"Commands (DDL)","ALTER VIEW","
467
ALTER VIEW [ IF EXISTS ] viewName RECOMPILE
Thomas Mueller's avatar
Thomas Mueller committed
468 469
","
Recompiles a view after the underlying tables have been changed or created.
Thomas Mueller's avatar
Thomas Mueller committed
470
This command is used for views created using CREATE FORCE VIEW.
Thomas Mueller's avatar
Thomas Mueller committed
471
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
472 473 474 475 476
","
ALTER VIEW ADDRESS_VIEW RECOMPILE
"

"Commands (DDL)","ANALYZE","
477
ANALYZE [ TABLE tableName ] [ SAMPLE_SIZE rowCountInt ]
Thomas Mueller's avatar
Thomas Mueller committed
478
","
479 480 481
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
482 483 484 485 486
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.
487

Thomas Mueller's avatar
Thomas Mueller committed
488
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
489 490 491 492 493
","
ANALYZE SAMPLE_SIZE 1000
"

"Commands (DDL)","COMMENT","
494 495 496 497 498
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
499
","
Thomas Mueller's avatar
Thomas Mueller committed
500 501 502
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
503
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
504 505 506 507 508
","
COMMENT ON TABLE TEST IS 'Table used for testing'
"

"Commands (DDL)","CREATE AGGREGATE","
509
CREATE AGGREGATE [ IF NOT EXISTS ] newAggregateName FOR className
Thomas Mueller's avatar
Thomas Mueller committed
510 511 512
","
Creates a new user-defined aggregate function. The method name must be the full
qualified class name. The class must implement the interface
513
""org.h2.api.AggregateFunction"".
Thomas Mueller's avatar
Thomas Mueller committed
514 515

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
516
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
517
","
518
CREATE AGGREGATE SIMPLE_MEDIAN FOR ""com.acme.db.Median""
Thomas Mueller's avatar
Thomas Mueller committed
519 520 521
"

"Commands (DDL)","CREATE ALIAS","
Thomas Mueller's avatar
Thomas Mueller committed
522
CREATE ALIAS [ IF NOT EXISTS ] newFunctionAliasName [ DETERMINISTIC ]
Thomas Mueller's avatar
Thomas Mueller committed
523
[ NOBUFFER ] { FOR classAndMethodName | AS sourceCodeString }
Thomas Mueller's avatar
Thomas Mueller committed
524
","
525 526 527 528 529 530
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.
531 532 533

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

539 540
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.
541 542
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
543 544
as dollar quoted text to avoid escaping problems. If import statements are used,
then the tag @CODE must be added before the method.
545

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

549
If the first parameter of the Java function is a ""java.sql.Connection"", then a
Thomas Mueller's avatar
Thomas Mueller committed
550 551 552
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.
553

Thomas Mueller's avatar
Thomas Mueller committed
554
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
555
This command commits an open transaction in this connection.
556 557

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
558 559 560 561 562
","
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');
563 564
CREATE ALIAS REVERSE AS $$ String reverse(String s) { return new StringBuilder(s).reverse().toString(); } $$;
CALL REVERSE('Test');
565 566 567 568 569
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
570 571 572
"

"Commands (DDL)","CREATE CONSTANT","
573
CREATE CONSTANT [ IF NOT EXISTS ] newConstantName VALUE expression
Thomas Mueller's avatar
Thomas Mueller committed
574
","
Thomas Mueller's avatar
Thomas Mueller committed
575
Creates a new constant.
Thomas Mueller's avatar
Thomas Mueller committed
576
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
577 578 579 580 581
","
CREATE CONSTANT ONE VALUE 1
"

"Commands (DDL)","CREATE DOMAIN","
582 583 584
CREATE DOMAIN [ IF NOT EXISTS ] newDomainName AS dataType
[ DEFAULT expression ] [ [ NOT ] NULL ] [ SELECTIVITY selectivity ]
[ CHECK condition ]
Thomas Mueller's avatar
Thomas Mueller committed
585 586
","
Creates a new data type (domain). The check condition must evaluate to true or
Thomas Mueller's avatar
Thomas Mueller committed
587
to NULL (to prevent NULL, use ""NOT NULL""). In the condition, the term VALUE refers
Thomas Mueller's avatar
Thomas Mueller committed
588
to the value being tested.
589

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

Thomas Mueller's avatar
Thomas Mueller committed
592
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
593 594 595 596 597
","
CREATE DOMAIN EMAIL AS VARCHAR(255) CHECK (POSITION('@', VALUE) > 1)
"

"Commands (DDL)","CREATE INDEX","
598
CREATE
Thomas Mueller's avatar
Thomas Mueller committed
599
{ [ UNIQUE ] [ HASH | SPATIAL] INDEX [ [ IF NOT EXISTS ] newIndexName ]
600 601
    | PRIMARY KEY [ HASH ] }
ON tableName ( indexColumn [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
602
","
Thomas Mueller's avatar
Thomas Mueller committed
603
Creates a new index.
Thomas Mueller's avatar
Thomas Mueller committed
604
This command commits an open transaction in this connection.
605

Thomas Mueller's avatar
Thomas Mueller committed
606
Hash indexes are meant for in-memory databases and memory tables (CREATE MEMORY TABLE).
607 608
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
609
Non-unique keys are supported.
610
Spatial indexes are supported only on Geometry columns.
Thomas Mueller's avatar
Thomas Mueller committed
611 612 613 614 615
","
CREATE INDEX IDXNAME ON TEST(NAME)
"

"Commands (DDL)","CREATE LINKED TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
616
CREATE [ FORCE ] [ [ GLOBAL | LOCAL ] TEMPORARY ]
Thomas Mueller's avatar
Thomas Mueller committed
617
LINKED TABLE [ IF NOT EXISTS ]
618 619
name ( driverString, urlString, userString, passwordString,
[ originalSchemaString, ] originalTableString ) [ EMIT UPDATES | READONLY ]
Thomas Mueller's avatar
Thomas Mueller committed
620 621 622 623 624
","
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.

625 626 627
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
628 629
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
630
work. Linked tables to the same database share one connection.
631

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

Thomas Mueller's avatar
Thomas Mueller committed
634 635 636
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).

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

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

Thomas Mueller's avatar
Thomas Mueller committed
644
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
645
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
646
","
647 648
CREATE LINKED TABLE LINK('org.h2.Driver', 'jdbc:h2:test2',
    'sa', 'sa', 'TEST');
Thomas Mueller's avatar
Thomas Mueller committed
649 650 651
CREATE LINKED TABLE LINK('', 'jdbc:h2:test2', 'sa', 'sa',
    '(SELECT * FROM TEST WHERE ID>0)');
CREATE LINKED TABLE LINK('javax.naming.InitialContext',
652 653
    'java:comp/env/jdbc/Test', NULL, NULL,
    '(SELECT * FROM TEST WHERE ID>0)');
Thomas Mueller's avatar
Thomas Mueller committed
654 655 656
"

"Commands (DDL)","CREATE ROLE","
657
CREATE ROLE [ IF NOT EXISTS ] newRoleName
Thomas Mueller's avatar
Thomas Mueller committed
658
","
Thomas Mueller's avatar
Thomas Mueller committed
659
Creates a new role.
Thomas Mueller's avatar
Thomas Mueller committed
660
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
661 662 663 664 665
","
CREATE ROLE READONLY
"

"Commands (DDL)","CREATE SCHEMA","
666 667
CREATE SCHEMA [ IF NOT EXISTS ] name
[ AUTHORIZATION ownerUserName ]
668
[ WITH tableEngineParamName [,...] ]
Thomas Mueller's avatar
Thomas Mueller committed
669 670 671
","
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
672
Specifying the owner currently has no effect.
673 674
Optional table engine parameters are used when CREATE TABLE command
is run on this schema without having its engine params set.
675

Thomas Mueller's avatar
Thomas Mueller committed
676
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
677 678 679 680 681
","
CREATE SCHEMA TEST_SCHEMA AUTHORIZATION SA
"

"Commands (DDL)","CREATE SEQUENCE","
682 683
CREATE SEQUENCE [ IF NOT EXISTS ] newSequenceName
[ START WITH long ]
684 685 686
[ INCREMENT BY long ]
[ MINVALUE long | NOMINVALUE | NO MINVALUE ]
[ MAXVALUE long | NOMAXVALUE | NO MAXVALUE ]
687 688
[ CYCLE long | NOCYCLE | NO CYCLE ]
[ CACHE long | NOCACHE | NO CACHE ]
Thomas Mueller's avatar
Thomas Mueller committed
689
","
Thomas Mueller's avatar
Thomas Mueller committed
690 691 692
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
693 694 695 696 697

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
698

Thomas Mueller's avatar
Thomas Mueller committed
699
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
700 701 702 703 704
","
CREATE SEQUENCE SEQ_ID
"

"Commands (DDL)","CREATE TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
705 706
CREATE [ CACHED | MEMORY ] [ TEMP | [ GLOBAL | LOCAL ] TEMPORARY ]
TABLE [ IF NOT EXISTS ] name
707
[ ( { columnName columnDefinition | constraint } [,...] ) ]
708 709
[ ENGINE tableEngineName ]
[ WITH tableEngineParamName [,...] ]
710
[ NOT PERSISTENT ] [ TRANSACTIONAL ]
711
[ AS select ]","
Thomas Mueller's avatar
Thomas Mueller committed
712 713
Creates a new table.

Thomas Mueller's avatar
Thomas Mueller committed
714 715 716 717
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
718
that means memory tables should not get too large.
719

Thomas Mueller's avatar
Thomas Mueller committed
720 721 722 723 724
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,
725
unless the temporary table is created using CREATE CACHED TABLE.
Thomas Mueller's avatar
Thomas Mueller committed
726

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

731 732 733
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.

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

737 738 739
The column definition is optional if a query is specified.
In that case the column list of the query is used.

Thomas Mueller's avatar
Thomas Mueller committed
740 741
This command commits an open transaction, except when using
TRANSACTIONAL (only supported for temporary tables).
Thomas Mueller's avatar
Thomas Mueller committed
742 743 744 745 746
","
CREATE TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR(255))
"

"Commands (DDL)","CREATE TRIGGER","
747 748 749 750 751 752
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
753
","
Thomas Mueller's avatar
Thomas Mueller committed
754 755 756 757 758
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).
759

760 761
The sourceCodeString must define a single method with no parameters that returns ""org.h2.api.Trigger"".
See CREATE ALIAS for requirements regarding the compilation.
762 763 764
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"".
765

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

Thomas Mueller's avatar
Thomas Mueller committed
771
ROLLBACK can be specified in combination with INSERT, UPDATE, and DELETE.
772
Only row based AFTER trigger can be called on ROLLBACK.
773
Exceptions that occur within such triggers are ignored.
774 775
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.
776

777
INSTEAD OF triggers are implicitly row based and behave like BEFORE triggers.
778
Only the first such trigger is called. Such triggers on views are supported.
779
They can be used to make views updatable.
780

Thomas Mueller's avatar
Thomas Mueller committed
781 782
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.
783 784
The trigger is called with both 'old' and 'new' set to null.

785 786 787 788
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
789 790
Committing or rolling back a transaction within a trigger is not allowed, except for SELECT triggers.

Thomas Mueller's avatar
Thomas Mueller committed
791 792 793
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.

794 795
QUEUE is implemented for syntax compatibility with HSQL and has no effect.

Thomas Mueller's avatar
Thomas Mueller committed
796 797
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.
798

Thomas Mueller's avatar
Thomas Mueller committed
799
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
800
","
801
CREATE TRIGGER TRIG_INS BEFORE INSERT ON TEST FOR EACH ROW CALL ""MyTrigger"";
Thomas Mueller's avatar
Thomas Mueller committed
802
CREATE TRIGGER TRIG_SRC BEFORE INSERT ON TEST AS $$org.h2.api.Trigger create() { return new MyTrigger(""constructorParam""); } $$;
803 804
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
805 806
"
"Commands (DDL)","CREATE USER","
807 808
CREATE USER [ IF NOT EXISTS ] newUserName
{ PASSWORD string | SALT bytes HASH bytes } [ ADMIN ]
Thomas Mueller's avatar
Thomas Mueller committed
809
","
Thomas Mueller's avatar
Thomas Mueller committed
810 811 812
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.
813

Thomas Mueller's avatar
Thomas Mueller committed
814
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
815
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
816 817 818 819 820
","
CREATE USER GUEST PASSWORD 'abc'
"

"Commands (DDL)","CREATE VIEW","
Thomas Mueller's avatar
Thomas Mueller committed
821
CREATE [ OR REPLACE ] [ FORCE ] VIEW [ IF NOT EXISTS ] newViewName
822
[ ( columnName [,...] ) ] AS select
Thomas Mueller's avatar
Thomas Mueller committed
823 824
","
Creates a new view. If the force option is used, then the view is created even
Thomas Mueller's avatar
Thomas Mueller committed
825
if the underlying table(s) don't exist.
826

Thomas Mueller's avatar
Thomas Mueller committed
827 828 829 830 831
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.

832 833
Views are not updatable except when using 'instead of' triggers.

Thomas Mueller's avatar
Thomas Mueller committed
834
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
835
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
836 837 838 839 840
","
CREATE VIEW TEST_VIEW AS SELECT * FROM TEST WHERE ID < 100
"

"Commands (DDL)","DROP AGGREGATE","
841
DROP AGGREGATE [ IF EXISTS ] aggregateName
Thomas Mueller's avatar
Thomas Mueller committed
842
","
Thomas Mueller's avatar
Thomas Mueller committed
843 844 845
Drops an existing user-defined aggregate function.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
846
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
847
","
848
DROP AGGREGATE SIMPLE_MEDIAN
Thomas Mueller's avatar
Thomas Mueller committed
849 850 851
"

"Commands (DDL)","DROP ALIAS","
852
DROP ALIAS [ IF EXISTS ] existingFunctionAliasName
Thomas Mueller's avatar
Thomas Mueller committed
853
","
Thomas Mueller's avatar
Thomas Mueller committed
854 855 856
Drops an existing function alias.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
857
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
858
","
Thomas Mueller's avatar
Thomas Mueller committed
859
DROP ALIAS MY_SQRT
Thomas Mueller's avatar
Thomas Mueller committed
860 861 862
"

"Commands (DDL)","DROP ALL OBJECTS","
863
DROP ALL OBJECTS [ DELETE FILES ]
Thomas Mueller's avatar
Thomas Mueller committed
864 865 866 867 868
","
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
869 870 871
back.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
872 873 874 875 876
","
DROP ALL OBJECTS
"

"Commands (DDL)","DROP CONSTANT","
877
DROP CONSTANT [ IF EXISTS ] constantName
Thomas Mueller's avatar
Thomas Mueller committed
878
","
Thomas Mueller's avatar
Thomas Mueller committed
879
Drops a constant.
Thomas Mueller's avatar
Thomas Mueller committed
880
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
881 882 883 884 885
","
DROP CONSTANT ONE
"

"Commands (DDL)","DROP DOMAIN","
886
DROP DOMAIN [ IF EXISTS ] domainName
Thomas Mueller's avatar
Thomas Mueller committed
887
","
Thomas Mueller's avatar
Thomas Mueller committed
888
Drops a data type (domain).
Thomas Mueller's avatar
Thomas Mueller committed
889
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
890 891 892 893 894
","
DROP DOMAIN EMAIL
"

"Commands (DDL)","DROP INDEX","
895
DROP INDEX [ IF EXISTS ] indexName
Thomas Mueller's avatar
Thomas Mueller committed
896
","
Thomas Mueller's avatar
Thomas Mueller committed
897
Drops an index.
Thomas Mueller's avatar
Thomas Mueller committed
898
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
899 900 901 902 903
","
DROP INDEX IF EXISTS IDXNAME
"

"Commands (DDL)","DROP ROLE","
904
DROP ROLE [ IF EXISTS ] roleName
Thomas Mueller's avatar
Thomas Mueller committed
905
","
Thomas Mueller's avatar
Thomas Mueller committed
906
Drops a role.
Thomas Mueller's avatar
Thomas Mueller committed
907
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
908 909 910 911 912
","
DROP ROLE READONLY
"

"Commands (DDL)","DROP SCHEMA","
913
DROP SCHEMA [ IF EXISTS ] schemaName [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
914
","
Thomas Mueller's avatar
Thomas Mueller committed
915
Drops a schema.
916 917
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
918
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
919 920 921 922 923
","
DROP SCHEMA TEST_SCHEMA
"

"Commands (DDL)","DROP SEQUENCE","
924
DROP SEQUENCE [ IF EXISTS ] sequenceName
Thomas Mueller's avatar
Thomas Mueller committed
925
","
Thomas Mueller's avatar
Thomas Mueller committed
926
Drops a sequence.
Thomas Mueller's avatar
Thomas Mueller committed
927
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
928 929 930 931 932
","
DROP SEQUENCE SEQ_ID
"

"Commands (DDL)","DROP TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
933
DROP TABLE [ IF EXISTS ] tableName [,...] [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
934
","
Thomas Mueller's avatar
Thomas Mueller committed
935
Drops an existing table, or a list of tables.
936 937
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
938
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
939 940 941 942 943
","
DROP TABLE TEST
"

"Commands (DDL)","DROP TRIGGER","
944
DROP TRIGGER [ IF EXISTS ] triggerName
Thomas Mueller's avatar
Thomas Mueller committed
945
","
Thomas Mueller's avatar
Thomas Mueller committed
946
Drops an existing trigger.
Thomas Mueller's avatar
Thomas Mueller committed
947
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
948 949 950 951 952
","
DROP TRIGGER TRIG_INS
"

"Commands (DDL)","DROP USER","
953
DROP USER [ IF EXISTS ] userName
Thomas Mueller's avatar
Thomas Mueller committed
954
","
Thomas Mueller's avatar
Thomas Mueller committed
955 956
Drops a user. The current user cannot be dropped.
For compatibility, only unquoted or uppercase user names are allowed.
957

Thomas Mueller's avatar
Thomas Mueller committed
958
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
959
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
960 961 962 963 964
","
DROP USER TOM
"

"Commands (DDL)","DROP VIEW","
965
DROP VIEW [ IF EXISTS ] viewName [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
966
","
Thomas Mueller's avatar
Thomas Mueller committed
967 968 969
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
970
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
971 972 973 974 975 976 977
","
DROP VIEW TEST_VIEW
"

"Commands (DDL)","TRUNCATE TABLE","
TRUNCATE TABLE tableName
","
978 979 980 981 982
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).
983
Linked tables can't be truncated.
Thomas Mueller's avatar
Thomas Mueller committed
984

Thomas Mueller's avatar
Thomas Mueller committed
985
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
986 987 988 989 990 991 992
","
TRUNCATE TABLE TEST
"

"Commands (Other)","CHECKPOINT","
CHECKPOINT
","
Thomas Mueller's avatar
Thomas Mueller committed
993
Flushes the data to disk.
Thomas Mueller's avatar
Thomas Mueller committed
994 995

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
996 997 998 999 1000 1001 1002
","
CHECKPOINT
"

"Commands (Other)","CHECKPOINT SYNC","
CHECKPOINT SYNC
","
Thomas Mueller's avatar
Thomas Mueller committed
1003
Flushes the data to disk and and forces all system buffers be written
Thomas Mueller's avatar
Thomas Mueller committed
1004 1005 1006
to the underlying device.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1007 1008 1009 1010 1011
","
CHECKPOINT SYNC
"

"Commands (Other)","COMMIT","
1012
COMMIT [ WORK ]
Thomas Mueller's avatar
Thomas Mueller committed
1013 1014 1015 1016 1017 1018 1019 1020 1021
","
Commits a transaction.
","
COMMIT
"

"Commands (Other)","COMMIT TRANSACTION","
COMMIT TRANSACTION transactionName
","
Thomas Mueller's avatar
Thomas Mueller committed
1022 1023 1024 1025
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
1026 1027 1028 1029 1030
","
COMMIT TRANSACTION XID_TEST
"

"Commands (Other)","GRANT RIGHT","
1031
GRANT { SELECT | INSERT | UPDATE | DELETE | ALL } [,...] ON
1032 1033
{ { SCHEMA schemaName } | { tableName [,...] } }
TO { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1034
","
Thomas Mueller's avatar
Thomas Mueller committed
1035 1036 1037
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
1038
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1039 1040 1041 1042
","
GRANT SELECT ON TEST TO READONLY
"

1043 1044 1045 1046 1047 1048
"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
1049
This command commits an open transaction in this connection.
1050 1051 1052 1053
","
GRANT ALTER ANY SCHEMA TO Bob
"

Thomas Mueller's avatar
Thomas Mueller committed
1054
"Commands (Other)","GRANT ROLE","
1055
GRANT roleName TO { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1056
","
Thomas Mueller's avatar
Thomas Mueller committed
1057 1058 1059
Grants a role to a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1060
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1061 1062 1063 1064 1065
","
GRANT READONLY TO PUBLIC
"

"Commands (Other)","HELP","
1066
HELP [ anything [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
1067 1068 1069 1070 1071 1072 1073 1074 1075
","
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
1076 1077
Prepares committing a transaction.
This command is part of the 2-phase-commit protocol.
Thomas Mueller's avatar
Thomas Mueller committed
1078 1079 1080 1081 1082
","
PREPARE COMMIT XID_TEST
"

"Commands (Other)","REVOKE RIGHT","
1083
REVOKE { SELECT | INSERT | UPDATE | DELETE | ALL } [,...] ON
1084 1085
{ { SCHEMA schemaName } | { tableName [,...] } }
FROM { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1086
","
Thomas Mueller's avatar
Thomas Mueller committed
1087 1088 1089
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
1090
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1091 1092 1093 1094 1095
","
REVOKE SELECT ON TEST FROM READONLY
"

"Commands (Other)","REVOKE ROLE","
1096
REVOKE roleName FROM { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1097
","
Thomas Mueller's avatar
Thomas Mueller committed
1098 1099 1100
Removes a role from a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1101
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1102 1103 1104 1105 1106
","
REVOKE READONLY FROM TOM
"

"Commands (Other)","ROLLBACK","
1107
ROLLBACK [ TO SAVEPOINT savepointName ]
Thomas Mueller's avatar
Thomas Mueller committed
1108 1109 1110 1111 1112 1113 1114 1115 1116 1117
","
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
1118 1119 1120 1121
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
1122 1123 1124 1125 1126 1127 1128
","
ROLLBACK TRANSACTION XID_TEST
"

"Commands (Other)","SAVEPOINT","
SAVEPOINT savepointName
","
Thomas Mueller's avatar
Thomas Mueller committed
1129 1130
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
1131 1132 1133 1134 1135
","
SAVEPOINT HALF_DONE
"

"Commands (Other)","SET @","
1136
SET @variableName [ = ] expression
Thomas Mueller's avatar
Thomas Mueller committed
1137
","
Thomas Mueller's avatar
Thomas Mueller committed
1138
Updates a user-defined variable.
Thomas Mueller's avatar
Thomas Mueller committed
1139
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
1140
This command does not commit a transaction, and rollback does not affect it.
Thomas Mueller's avatar
Thomas Mueller committed
1141 1142 1143 1144 1145
","
SET @TOTAL=0
"

"Commands (Other)","SET ALLOW_LITERALS","
1146
SET ALLOW_LITERALS { NONE | ALL | NUMBERS }
Thomas Mueller's avatar
Thomas Mueller committed
1147 1148 1149 1150 1151 1152 1153 1154 1155 1156
","
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
1157 1158
See also CREATE CONSTANT.

Thomas Mueller's avatar
Thomas Mueller committed
1159
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1160
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1161
This setting is persistent.
1162
This setting can be appended to the database URL: ""jdbc:h2:test;ALLOW_LITERALS=NONE""
Thomas Mueller's avatar
Thomas Mueller committed
1163 1164 1165 1166 1167
","
SET ALLOW_LITERALS NONE
"

"Commands (Other)","SET AUTOCOMMIT","
1168
SET AUTOCOMMIT { TRUE | ON | FALSE | OFF }
Thomas Mueller's avatar
Thomas Mueller committed
1169 1170
","
Switches auto commit on or off.
1171
This setting can be appended to the database URL: ""jdbc:h2:test;AUTOCOMMIT=OFF"" -
1172
however this will not work as expected when using a connection pool
1173 1174
(the connection pool manager will re-enable autocommit when returning
the connection to the pool, so autocommit will only be disabled the first
1175
time the connection is used.
Thomas Mueller's avatar
Thomas Mueller committed
1176 1177 1178 1179 1180 1181 1182
","
SET AUTOCOMMIT OFF
"

"Commands (Other)","SET CACHE_SIZE","
SET CACHE_SIZE int
","
1183
Sets the size of the cache in KB (each KB being 1024 bytes) for the current database.
1184 1185
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
1186 1187
Depending on the virtual machine, the actual memory required may be higher.

Thomas Mueller's avatar
Thomas Mueller committed
1188
This setting is persistent and affects all connections as there is only one cache per database.
Thomas Mueller's avatar
Thomas Mueller committed
1189
Using a very small value (specially 0) will reduce performance a lot.
Thomas Mueller's avatar
Thomas Mueller committed
1190 1191
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
1192
It has no effect for in-memory databases.
1193

Thomas Mueller's avatar
Thomas Mueller committed
1194
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1195
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1196
This setting is persistent.
1197
This setting can be appended to the database URL: ""jdbc:h2:test;CACHE_SIZE=8192""
Thomas Mueller's avatar
Thomas Mueller committed
1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209
","
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
1210 1211
server is not responding).

Thomas Mueller's avatar
Thomas Mueller committed
1212
This command is effective immediately, but does not commit an open transaction.
Thomas Mueller's avatar
Thomas Mueller committed
1213 1214 1215 1216
","
SET CLUSTER ''
"

1217 1218 1219 1220
"Commands (Other)","SET BINARY_COLLATION","
SET BINARY_COLLATION
{ UNSIGNED | SIGNED } ] }
","
Thomas Mueller's avatar
Thomas Mueller committed
1221 1222
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.
1223 1224 1225
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
1226
This command commits an open transaction in this connection.
1227 1228 1229 1230 1231
This setting is persistent.
","
SET BINARY_COLLATION SIGNED
"

1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244
"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
1245
"Commands (Other)","SET COLLATION","
1246
SET [ DATABASE ] COLLATION
1247 1248
{ OFF | collationName
    [ STRENGTH { PRIMARY | SECONDARY | TERTIARY | IDENTICAL } ] }
Thomas Mueller's avatar
Thomas Mueller committed
1249
","
Thomas Mueller's avatar
Thomas Mueller committed
1250 1251
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
1252 1253
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
1254
TERTIARY is both case- and umlaut-sensitive; IDENTICAL is sensitive to all differences and only affects ordering).
Thomas Mueller's avatar
Thomas Mueller committed
1255

1256 1257 1258 1259 1260
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).
1261 1262
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.
1263

Thomas Mueller's avatar
Thomas Mueller committed
1264
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1265
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1266
This setting is persistent.
1267
This setting can be appended to the database URL: ""jdbc:h2:test;COLLATION='ENGLISH'""
Thomas Mueller's avatar
Thomas Mueller committed
1268 1269
","
SET COLLATION ENGLISH
1270
SET COLLATION CHARSET_CP500
Thomas Mueller's avatar
Thomas Mueller committed
1271 1272 1273
"

"Commands (Other)","SET COMPRESS_LOB","
1274
SET COMPRESS_LOB { NO | LZF | DEFLATE }
Thomas Mueller's avatar
Thomas Mueller committed
1275
","
Thomas Mueller's avatar
Thomas Mueller committed
1276 1277 1278 1279
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
1280 1281
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
1282

Thomas Mueller's avatar
Thomas Mueller committed
1283
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1284
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1285
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1286 1287 1288 1289 1290 1291 1292 1293
","
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
1294 1295 1296 1297
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).
1298
This setting can be appended to the database URL: ""jdbc:h2:test;DATABASE_EVENT_LISTENER='sample.MyListener'""
Thomas Mueller's avatar
Thomas Mueller committed
1299 1300 1301 1302 1303 1304 1305
","
SET DATABASE_EVENT_LISTENER 'sample.MyListener'
"

"Commands (Other)","SET DB_CLOSE_DELAY","
SET DB_CLOSE_DELAY int
","
Thomas Mueller's avatar
Thomas Mueller committed
1306 1307
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
1308 1309 1310 1311
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
1312

Thomas Mueller's avatar
Thomas Mueller committed
1313
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1314
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1315
This setting is persistent.
1316
This setting can be appended to the database URL: ""jdbc:h2:test;DB_CLOSE_DELAY=-1""
Thomas Mueller's avatar
Thomas Mueller committed
1317 1318 1319 1320 1321 1322 1323 1324
","
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
1325 1326
for the new sessions. The default value for this setting is 1000 (one second).

Thomas Mueller's avatar
Thomas Mueller committed
1327
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1328
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1329
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1330 1331 1332 1333 1334
","
SET DEFAULT_LOCK_TIMEOUT 5000
"

"Commands (Other)","SET DEFAULT_TABLE_TYPE","
1335
SET DEFAULT_TABLE_TYPE { MEMORY | CACHED }
Thomas Mueller's avatar
Thomas Mueller committed
1336 1337 1338
","
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
1339
the data is still stored in the database file. The size of memory tables is
Thomas Mueller's avatar
Thomas Mueller committed
1340
limited by the memory. The default is CACHED.
Thomas Mueller's avatar
Thomas Mueller committed
1341

Thomas Mueller's avatar
Thomas Mueller committed
1342
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1343
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1344
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1345
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1346 1347 1348 1349 1350
","
SET DEFAULT_TABLE_TYPE MEMORY
"

"Commands (Other)","SET EXCLUSIVE","
Thomas Mueller's avatar
Thomas Mueller committed
1351
SET EXCLUSIVE { 0 | 1 | 2 }
Thomas Mueller's avatar
Thomas Mueller committed
1352
","
Thomas Mueller's avatar
Thomas Mueller committed
1353 1354 1355 1356 1357 1358 1359 1360 1361 1362
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
1363 1364

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1365
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1366
","
Thomas Mueller's avatar
Thomas Mueller committed
1367
SET EXCLUSIVE 1
Thomas Mueller's avatar
Thomas Mueller committed
1368 1369 1370
"

"Commands (Other)","SET IGNORECASE","
1371
SET IGNORECASE { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
1372 1373 1374 1375 1376
","
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
1377
String literals and parameters are however still considered case sensitive even if this option is set.
Thomas Mueller's avatar
Thomas Mueller committed
1378

Thomas Mueller's avatar
Thomas Mueller committed
1379
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1380
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1381
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1382
This setting can be appended to the database URL: ""jdbc:h2:test;IGNORECASE=TRUE""
Thomas Mueller's avatar
Thomas Mueller committed
1383 1384 1385 1386
","
SET IGNORECASE TRUE
"

1387 1388 1389 1390 1391 1392 1393 1394 1395 1396 1397 1398
"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
1399
This command commits an open transaction in this connection.
1400 1401 1402 1403 1404 1405 1406
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'
"


1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418 1419 1420 1421 1422 1423
"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
"

1424
"Commands (Other)","SET LOG","
1425
SET LOG int
1426 1427 1428 1429
","
Sets the transaction log mode. The values 0, 1, and 2 are supported, the default is 2.
This setting affects all connections.

1430
LOG 0 means the transaction log is disabled completely. It is the fastest mode,
1431 1432 1433 1434
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.

1435 1436
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
1437 1438
against power failure is required, but the data must be protected against killing the process.

1439 1440
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
1441 1442
file system, this will also protect against power failure in the majority if cases.

Thomas Mueller's avatar
Thomas Mueller committed
1443
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1444
This command commits an open transaction in this connection.
1445
This setting is not persistent.
1446
This setting can be appended to the database URL: ""jdbc:h2:test;LOG=0""
1447 1448 1449 1450
","
SET LOG 1
"

Thomas Mueller's avatar
Thomas Mueller committed
1451 1452 1453 1454
"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
1455
(READ_COMMITTED). This setting affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1456 1457 1458 1459 1460 1461 1462 1463 1464 1465 1466 1467 1468

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
1469
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1470
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1471
This setting is persistent.
1472
This setting can be appended to the database URL: ""jdbc:h2:test;LOCK_MODE=3""
Thomas Mueller's avatar
Thomas Mueller committed
1473 1474 1475 1476 1477 1478 1479 1480
","
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
1481 1482 1483
value for this setting is 1000 (one second).

This command does not commit a transaction, and rollback does not affect it.
1484
This setting can be appended to the database URL: ""jdbc:h2:test;LOCK_TIMEOUT=10000""
Thomas Mueller's avatar
Thomas Mueller committed
1485 1486 1487 1488 1489 1490 1491
","
SET LOCK_TIMEOUT 1000
"

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

1494
This is the maximum length of an LOB that is stored with the record itself,
1495 1496
and the default value is 128.

Thomas Mueller's avatar
Thomas Mueller committed
1497
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1498
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1499
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1500 1501 1502 1503 1504 1505 1506
","
SET MAX_LENGTH_INPLACE_LOB 128
"

"Commands (Other)","SET MAX_LOG_SIZE","
SET MAX_LOG_SIZE int
","
Thomas Mueller's avatar
Thomas Mueller committed
1507 1508
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
1509
If there is an open transaction, the transaction log will continue to grow however.
Thomas Mueller's avatar
Thomas Mueller committed
1510
The default max size is 16 MB.
Thomas Mueller's avatar
Thomas Mueller committed
1511
This setting has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1512

Thomas Mueller's avatar
Thomas Mueller committed
1513
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1514
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1515
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1516 1517 1518 1519 1520 1521 1522 1523
","
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
1524
are read, then the rows are buffered to disk.
1525
The default is 40000 per GB of available RAM.
Thomas Mueller's avatar
Thomas Mueller committed
1526

Thomas Mueller's avatar
Thomas Mueller committed
1527
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1528
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1529
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1530
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1531 1532 1533 1534 1535 1536 1537
","
SET MAX_MEMORY_ROWS 1000
"

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

Thomas Mueller's avatar
Thomas Mueller committed
1544
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1545
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1546
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1547
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1548 1549 1550 1551 1552 1553 1554 1555 1556
","
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
1557 1558 1559
operation. The default max size is 100000. 0 means no limit.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1560
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1561
It has no effect for in-memory databases.
1562
This setting can be appended to the database URL: ""jdbc:h2:test;MAX_OPERATION_MEMORY=10000""
Thomas Mueller's avatar
Thomas Mueller committed
1563 1564 1565 1566 1567
","
SET MAX_OPERATION_MEMORY 0
"

"Commands (Other)","SET MODE","
1568
SET MODE { REGULAR | DB2 | DERBY | HSQLDB | MSSQLSERVER | MYSQL | ORACLE | POSTGRESQL }
Thomas Mueller's avatar
Thomas Mueller committed
1569 1570
","
Changes to another database compatibility mode. For details, see Compatibility
Thomas Mueller's avatar
Thomas Mueller committed
1571 1572 1573
Modes in the feature section.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1574
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1575
This command commits an open transaction in this connection.
1576
This setting can be appended to the database URL: ""jdbc:h2:test;MODE=MYSQL""
Thomas Mueller's avatar
Thomas Mueller committed
1577 1578 1579 1580 1581
","
SET MODE HSQLDB
"

"Commands (Other)","SET MULTI_THREADED","
1582
SET MULTI_THREADED { 0 | 1 }
Thomas Mueller's avatar
Thomas Mueller committed
1583 1584 1585
","
Enabled (1) or disabled (0) multi-threading inside the database engine. By
default, this setting is disabled. Currently, enabling this is experimental
Thomas Mueller's avatar
Thomas Mueller committed
1586 1587 1588 1589 1590
only.

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
1591
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1592
This command commits an open transaction in this connection.
1593
This setting can be appended to the database URL: ""jdbc:h2:test;MULTI_THREADED=1""
Thomas Mueller's avatar
Thomas Mueller committed
1594 1595 1596 1597 1598
","
SET MULTI_THREADED 1
"

"Commands (Other)","SET OPTIMIZE_REUSE_RESULTS","
1599
SET OPTIMIZE_REUSE_RESULTS { 0 | 1 }
Thomas Mueller's avatar
Thomas Mueller committed
1600 1601 1602
","
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
1603 1604
the tables was changed. This option is enabled by default.

Thomas Mueller's avatar
Thomas Mueller committed
1605
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1606
This command commits an open transaction in this connection.
1607
This setting can be appended to the database URL: ""jdbc:h2:test;OPTIMIZE_REUSE_RESULTS=0""
Thomas Mueller's avatar
Thomas Mueller committed
1608 1609 1610 1611 1612 1613 1614 1615 1616
","
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
1617

Thomas Mueller's avatar
Thomas Mueller committed
1618
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1619 1620 1621 1622
","
SET PASSWORD 'abcstzri!.5'
"

1623 1624 1625 1626 1627 1628 1629
"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
1630
This command commits an open transaction in this connection.
1631 1632 1633 1634 1635
Admin rights are required to execute this command, as it affects all connections.
","
SET QUERY_STATISTICS FALSE
"

1636 1637 1638 1639 1640 1641 1642 1643 1644 1645 1646 1647 1648
"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
1649 1650 1651 1652 1653
"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
1654 1655 1656
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
1657 1658 1659 1660 1661
","
SET QUERY_TIMEOUT 10000
"

"Commands (Other)","SET REFERENTIAL_INTEGRITY","
1662
SET REFERENTIAL_INTEGRITY { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
1663 1664 1665
","
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
1666 1667 1668
for one table.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1669
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1670
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1671 1672 1673 1674
","
SET REFERENTIAL_INTEGRITY FALSE
"

1675 1676 1677 1678 1679 1680
"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.
1681 1682 1683
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,
1684 1685 1686 1687
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
1688
This command commits an open transaction in this connection.
1689 1690 1691 1692 1693 1694
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
1695 1696 1697 1698 1699
"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
1700

Thomas Mueller's avatar
Thomas Mueller committed
1701
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1702 1703 1704 1705 1706 1707 1708 1709 1710
","
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
1711 1712 1713
connections is PUBLIC.

This command does not commit a transaction, and rollback does not affect it.
1714
This setting can be appended to the database URL: ""jdbc:h2:test;SCHEMA=ABC""
Thomas Mueller's avatar
Thomas Mueller committed
1715 1716 1717 1718 1719 1720 1721 1722 1723
","
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
1724 1725 1726
connections is PUBLIC.

This command does not commit a transaction, and rollback does not affect it.
1727
This setting can be appended to the database URL: ""jdbc:h2:test;SCHEMA_SEARCH_PATH=ABC,DEF""
Thomas Mueller's avatar
Thomas Mueller committed
1728 1729 1730 1731 1732 1733 1734 1735 1736
","
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
1737 1738 1739
disabled).

This command does not commit a transaction, and rollback does not affect it.
1740
This setting can be appended to the database URL: ""jdbc:h2:test;THROTTLE=50""
Thomas Mueller's avatar
Thomas Mueller committed
1741 1742 1743 1744 1745
","
SET THROTTLE 200
"

"Commands (Other)","SET TRACE_LEVEL","
1746
SET { TRACE_LEVEL_FILE | TRACE_LEVEL_SYSTEM_OUT } int
Thomas Mueller's avatar
Thomas Mueller committed
1747 1748 1749
","
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.
1750
To use SLF4J, append "";TRACE_LEVEL_FILE=4"" to the database URL when opening the database.
Thomas Mueller's avatar
Thomas Mueller committed
1751

Thomas Mueller's avatar
Thomas Mueller committed
1752
This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1753
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1754
This command does not commit a transaction, and rollback does not affect it.
1755
This setting can be appended to the database URL: ""jdbc:h2:test;TRACE_LEVEL_SYSTEM_OUT=3""
Thomas Mueller's avatar
Thomas Mueller committed
1756 1757 1758 1759 1760 1761 1762 1763 1764 1765 1766
","
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
1767
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1768
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1769
This command commits an open transaction in this connection.
1770
This setting can be appended to the database URL: ""jdbc:h2:test;TRACE_MAX_FILE_SIZE=3""
Thomas Mueller's avatar
Thomas Mueller committed
1771 1772 1773 1774 1775 1776 1777 1778 1779 1780
","
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
1781

Thomas Mueller's avatar
Thomas Mueller committed
1782
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1783 1784 1785 1786 1787 1788 1789 1790
","
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
1791 1792
This setting is persistent. The default is 500 ms.

Thomas Mueller's avatar
Thomas Mueller committed
1793
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1794
This command commits an open transaction in this connection.
1795
This setting can be appended to the database URL: ""jdbc:h2:test;WRITE_DELAY=0""
Thomas Mueller's avatar
Thomas Mueller committed
1796 1797 1798 1799 1800
","
SET WRITE_DELAY 2000
"

"Commands (Other)","SHUTDOWN","
1801
SHUTDOWN [ IMMEDIATELY | COMPACT | DEFRAG ]
Thomas Mueller's avatar
Thomas Mueller committed
1802
","
1803 1804
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
1805
closed automatically when the last connection to it is closed.
Thomas Mueller's avatar
Thomas Mueller committed
1806

1807 1808
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
1809 1810 1811

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,
1812
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
1813 1814

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

1816 1817
SHUTDOWN DEFRAG re-orders the pages when closing the database so that table scans are faster.

Thomas Mueller's avatar
Thomas Mueller committed
1818
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1819
","
1820
SHUTDOWN COMPACT
Thomas Mueller's avatar
Thomas Mueller committed
1821 1822
"

1823 1824 1825 1826 1827 1828 1829 1830 1831 1832 1833 1834 1835 1836 1837 1838 1839 1840 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
"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).
1955 1956
ISO definition is used when first week of year should have at least four days
and week is started with Monday.
1957 1958 1959 1960 1961 1962 1963 1964 1965 1966 1967 1968 1969 1970 1971 1972 1973 1974 1975 1976 1977 1978 1979 1980 1981 1982 1983 1984 1985 1986 1987
","
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
"

1988 1989
"Other Grammar","Alias","
name
Thomas Mueller's avatar
Thomas Mueller committed
1990
","
1991
An alias is a name that is only valid in the context of the statement.
Thomas Mueller's avatar
Thomas Mueller committed
1992
","
1993
A
Thomas Mueller's avatar
Thomas Mueller committed
1994 1995
"

1996 1997
"Other Grammar","And Condition","
condition [ { AND condition } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
1998
","
1999
Value or condition.
Thomas Mueller's avatar
Thomas Mueller committed
2000
","
2001
ID=1 AND NAME='Hi'
Thomas Mueller's avatar
Thomas Mueller committed
2002 2003
"

2004
"Other Grammar","Array","
2005
( [ expression, [ expression [,...] ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
2006
","
2007 2008
An array of values. An empty array is '()'. Trailing commas are ignored.
An array with one element must contain a comma to be parsed as an array.
Thomas Mueller's avatar
Thomas Mueller committed
2009
","
2010
(1, 2)
2011 2012
(1, )
()
Thomas Mueller's avatar
Thomas Mueller committed
2013 2014
"

2015 2016
"Other Grammar","Boolean","
TRUE | FALSE
2017
","
2018
A boolean value.
2019
","
2020
TRUE
2021 2022
"

2023 2024
"Other Grammar","Bytes","
X'hex'
Thomas Mueller's avatar
Thomas Mueller committed
2025
","
2026
A binary value. The hex value is not case sensitive.
Thomas Mueller's avatar
Thomas Mueller committed
2027
","
2028
X'01FF'
Thomas Mueller's avatar
Thomas Mueller committed
2029 2030
"

2031 2032 2033
"Other Grammar","Case","
CASE expression { WHEN expression THEN expression } [...]
[ ELSE expression ] END
Thomas Mueller's avatar
Thomas Mueller committed
2034
","
2035 2036
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
2037
","
2038
CASE CNT WHEN 0 THEN 'No' WHEN 1 THEN 'One' ELSE 'Some' END
Thomas Mueller's avatar
Thomas Mueller committed
2039 2040
"

2041 2042 2043
"Other Grammar","Case When","
CASE { WHEN expression THEN expression} [...]
[ ELSE expression ] END
Thomas Mueller's avatar
Thomas Mueller committed
2044
","
2045 2046
Returns the first expression where the condition is true. If no else part is
specified, return NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2047
","
2048 2049 2050 2051
CASE WHEN CNT<10 THEN 'Low' ELSE 'High' END
"

"Other Grammar","Cipher","
2052
AES
2053
","
2054
Only the algorithm AES (""AES-128"") is supported currently.
2055 2056
","
AES
Thomas Mueller's avatar
Thomas Mueller committed
2057 2058
"

2059
"Other Grammar","Column Definition","
2060
dataType [ VISIBLE | INVISIBLE ]
2061 2062
[ { DEFAULT expression | AS computedColumnExpression } ]
[ ON UPDATE expression ] [ [ NOT ] NULL ]
2063
[ { AUTO_INCREMENT | IDENTITY } [ ( startInt [, incrementInt ] ) ] ]
Thomas Mueller's avatar
Thomas Mueller committed
2064 2065
[ SELECTIVITY selectivity ] [ COMMENT expression ]
[ PRIMARY KEY [ HASH ] | UNIQUE ] [ CHECK condition ]
2066 2067
","
Default expressions are used if no explicit value was used when adding a row.
Thomas Mueller's avatar
Thomas Mueller committed
2068
The computed column expression is evaluated and assigned whenever the row changes.
2069 2070 2071
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.
2072 2073 2074 2075

Identity and auto-increment columns are columns with a sequence as the
default. The column declared as the identity columns is implicitly the
primary key column of this table (unlike auto-increment columns).
Thomas Mueller's avatar
Thomas Mueller committed
2076

2077 2078 2079
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
2080 2081
The options PRIMARY KEY, UNIQUE, and CHECK are not supported for ALTER statements.

Thomas Mueller's avatar
Thomas Mueller committed
2082 2083
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
2084 2085
Conditions are only checked when a row is added or modified
in the table where the constraint exists.
2086

2087
","
Thomas Mueller's avatar
Thomas Mueller committed
2088 2089 2090
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);
2091 2092
"

2093 2094
"Other Grammar","Comments","
-- anythingUntilEndOfLine | // anythingUntilEndOfLine | /* anythingUntilEndComment */
Thomas Mueller's avatar
Thomas Mueller committed
2095
","
2096 2097 2098
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
2099
","
2100
// This is a comment
Thomas Mueller's avatar
Thomas Mueller committed
2101 2102
"

2103
"Other Grammar","Compare","
2104
<> | <= | >= | = | < | > | != | &&
Thomas Mueller's avatar
Thomas Mueller committed
2105
","
2106
Comparison operator. The operator != is the same as <>.
2107
The operator ""&&"" means overlapping; it can only be used with geometry types.
Thomas Mueller's avatar
Thomas Mueller committed
2108
","
2109
<>
Thomas Mueller's avatar
Thomas Mueller committed
2110 2111 2112
"

"Other Grammar","Condition","
2113
operand [ conditionRightHandSide ] | NOT condition | EXISTS ( select )
Thomas Mueller's avatar
Thomas Mueller committed
2114 2115 2116 2117 2118 2119 2120
","
Boolean value or condition.
","
ID<>2
"

"Other Grammar","Condition Right Hand Side","
2121 2122
compare { { { ALL | ANY | SOME } ( select ) } | operand }
    | IS [ NOT ] NULL
2123
    | IS [ NOT ] [ DISTINCT FROM ] operand
2124 2125
    | BETWEEN operand AND operand
    | IN ( { select | expression [,...] } )
2126
    | [ NOT ] [ LIKE | ILIKE ] operand [ ESCAPE string ]
2127
    | [ NOT ] REGEXP operand
Thomas Mueller's avatar
Thomas Mueller committed
2128
","
Thomas Mueller's avatar
Thomas Mueller committed
2129
The right hand side of a condition.
2130

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

Thomas Mueller's avatar
Thomas Mueller committed
2134 2135 2136 2137 2138
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).
2139 2140 2141
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.
2142

2143 2144
ILIKE does a case-insensitive compare.

Thomas Mueller's avatar
Thomas Mueller committed
2145
When comparing with REGEXP, regular expression matching is used.
2146
See Java ""Matcher.find"" for details.
Thomas Mueller's avatar
Thomas Mueller committed
2147 2148 2149 2150
","
LIKE 'Jo%'
"

2151
"Other Grammar","Constraint","
Thomas Mueller's avatar
Thomas Mueller committed
2152 2153 2154 2155 2156
[ constraintNameDefinition ]
{ CHECK expression
    | UNIQUE ( columnName [,...] )
    | referentialConstraint
    | PRIMARY KEY [ HASH ] ( columnName [,...] ) }
Thomas Mueller's avatar
Thomas Mueller committed
2157
","
Thomas Mueller's avatar
Thomas Mueller committed
2158 2159
Defines a constraint.
The check condition must evaluate to TRUE, FALSE or NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2160
TRUE and NULL mean the operation is to be permitted,
Thomas Mueller's avatar
Thomas Mueller committed
2161 2162
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
2163
","
2164
PRIMARY KEY(ID, NAME)
Thomas Mueller's avatar
Thomas Mueller committed
2165 2166
"

2167 2168
"Other Grammar","Constraint Name Definition","
CONSTRAINT [ IF NOT EXISTS ] newConstraintName
Thomas Mueller's avatar
Thomas Mueller committed
2169
","
2170
Defines a constraint name.
Thomas Mueller's avatar
Thomas Mueller committed
2171
","
2172
CONSTRAINT CONST_ID
Thomas Mueller's avatar
Thomas Mueller committed
2173 2174
"

2175 2176
"Other Grammar","Csv Options","
charsetString [, fieldSepString [, fieldDelimString [, escString [, nullString]]]]]
2177
    | optionString
Thomas Mueller's avatar
Thomas Mueller committed
2178
","
2179
Optional parameters for CSVREAD and CSVWRITE.
2180 2181
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
2182 2183
""STRINGDECODE('charset=UTF-8 escape=\"" fieldDelimiter=\"" fieldSeparator=, ' ||""
""'lineComment=# lineSeparator=\n null= rowSeparator=')"".
2184
The following options are supported:
2185

2186
""caseSensitiveColumnNames"" (true or false; disabled by default),
2187

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

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

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

thomasmueller's avatar
thomasmueller committed
2194
""fieldSeparator"" (a comma by default),
2195

2196
""lineComment"" (disabled by default),
2197

2198
""lineSeparator"" (the line separator used for writing; ignored for reading),
2199

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

2203
""preserveWhitespace"" (true or false; disabled by default),
2204

2205
""writeColumnHeader"" (true or false; enabled by default).
2206

Thomas Mueller's avatar
Thomas Mueller committed
2207
For a newline or other special character, use STRINGDECODE as in the example above.
Thomas Mueller's avatar
Thomas Mueller committed
2208
A space needs to be escaped with a backslash (""'\ '""), and
Thomas Mueller's avatar
Thomas Mueller committed
2209 2210 2211
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
2212
","
2213
CALL CSVWRITE('test2.csv', 'SELECT * FROM TEST', 'charset=UTF-8 fieldSeparator=|');
Thomas Mueller's avatar
Thomas Mueller committed
2214 2215
"

2216 2217 2218
"Other Grammar","Data Type","
intType | booleanType | tinyintType | smallintType | bigintType | identityType
    | decimalType | doubleType | realType | dateType | timeType | timestampType
2219 2220 2221
    | timestampWithTimeZoneType | binaryType | otherType | varcharType
    | varcharIgnorecaseType | charType | blobType | clobType | uuidType
    | arrayType | enumType
Thomas Mueller's avatar
Thomas Mueller committed
2222
","
2223
A data type definition.
Thomas Mueller's avatar
Thomas Mueller committed
2224
","
2225
INT
Thomas Mueller's avatar
Thomas Mueller committed
2226 2227
"

2228 2229
"Other Grammar","Date","
DATE 'yyyy-MM-dd'
Thomas Mueller's avatar
Thomas Mueller committed
2230
","
2231
A date literal. The limitations are the same as for the Java data type
2232
""java.sql.Date"", but for compatibility with other databases the suggested minimum
2233
and maximum years are 0001 and 9999.
Thomas Mueller's avatar
Thomas Mueller committed
2234
","
2235
DATE '2004-12-31'
Thomas Mueller's avatar
Thomas Mueller committed
2236 2237
"

2238
"Other Grammar","Decimal","
2239 2240
[ + | - ] { { number [ . number ] } | { . number } }
[ E [ + | - ] expNumber [...] ] ]
2241
","
Thomas Mueller's avatar
Thomas Mueller committed
2242 2243 2244 2245 2246 2247
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)"".
2248
","
Thomas Mueller's avatar
Thomas Mueller committed
2249 2250 2251
SELECT -1600.05
SELECT CAST(0 AS DOUBLE)
SELECT -1.4e-10
2252 2253
"

2254 2255
"Other Grammar","Digit","
0-9
Thomas Mueller's avatar
Thomas Mueller committed
2256
","
2257
A digit.
Thomas Mueller's avatar
Thomas Mueller committed
2258
","
2259
0
Thomas Mueller's avatar
Thomas Mueller committed
2260 2261
"

2262 2263
"Other Grammar","Dollar Quoted String","
$$anythingExceptTwoDollarSigns$$
Thomas Mueller's avatar
Thomas Mueller committed
2264
","
2265 2266 2267
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
2268
","
2269
$$John's car$$
Thomas Mueller's avatar
Thomas Mueller committed
2270 2271
"

2272 2273
"Other Grammar","Expression","
andCondition [ { OR andCondition } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2274
","
2275
Value or condition.
Thomas Mueller's avatar
Thomas Mueller committed
2276
","
2277
ID=1 OR NAME='Hi'
Thomas Mueller's avatar
Thomas Mueller committed
2278 2279
"

2280
"Other Grammar","Factor","
2281
term [ { { * | / | % } term } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2282
","
2283
A value or a numeric factor.
Thomas Mueller's avatar
Thomas Mueller committed
2284
","
2285
ID * 10
Thomas Mueller's avatar
Thomas Mueller committed
2286 2287
"

2288 2289
"Other Grammar","Hex","
{ { digit | a-f | A-F } { digit | a-f | A-F } } [...]
Thomas Mueller's avatar
Thomas Mueller committed
2290
","
2291 2292
The hexadecimal representation of a number or of bytes. Two characters are one
byte.
Thomas Mueller's avatar
Thomas Mueller committed
2293
","
2294
cafe
Thomas Mueller's avatar
Thomas Mueller committed
2295 2296
"

2297 2298
"Other Grammar","Hex Number","
[ + | - ] 0x hex
Thomas Mueller's avatar
Thomas Mueller committed
2299
","
2300
A number written in hexadecimal notation.
Thomas Mueller's avatar
Thomas Mueller committed
2301
","
2302
0xff
Thomas Mueller's avatar
Thomas Mueller committed
2303 2304
"

2305 2306
"Other Grammar","Index Column","
columnName [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
Thomas Mueller's avatar
Thomas Mueller committed
2307
","
2308 2309 2310
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
2311
","
2312
NAME
Thomas Mueller's avatar
Thomas Mueller committed
2313 2314 2315
"

"Other Grammar","Int","
2316
[ + | - ] number
Thomas Mueller's avatar
Thomas Mueller committed
2317 2318 2319 2320 2321 2322 2323
","
The maximum integer number is 2147483647, the minimum is -2147483648.
","
10
"

"Other Grammar","Long","
2324
[ + | - ] number
Thomas Mueller's avatar
Thomas Mueller committed
2325 2326 2327 2328 2329 2330
","
Long numbers are between -9223372036854775808 and 9223372036854775807.
","
100000
"

2331
"Other Grammar","Name","
2332
{ { A-Z|_ } [ { A-Z|_|0-9 } [...] ] } | quotedName
Thomas Mueller's avatar
Thomas Mueller committed
2333
","
2334
Names are not case sensitive. There is no maximum name length.
Thomas Mueller's avatar
Thomas Mueller committed
2335
","
2336
TEST
Thomas Mueller's avatar
Thomas Mueller committed
2337 2338
"

2339 2340
"Other Grammar","Null","
NULL
Thomas Mueller's avatar
Thomas Mueller committed
2341
","
2342
NULL is a value without data type and means 'unknown value'.
Thomas Mueller's avatar
Thomas Mueller committed
2343
","
2344
NULL
Thomas Mueller's avatar
Thomas Mueller committed
2345 2346
"

2347 2348 2349 2350 2351 2352 2353 2354
"Other Grammar","Number","
digit [...]
","
The maximum length of the number depends on the data type used.
","
100
"

Thomas Mueller's avatar
Thomas Mueller committed
2355
"Other Grammar","Numeric","
Thomas Mueller's avatar
Thomas Mueller committed
2356
decimal | int | long | hexNumber
Thomas Mueller's avatar
Thomas Mueller committed
2357
","
Thomas Mueller's avatar
Thomas Mueller committed
2358
The data type of a numeric value is always the lowest possible for the given value.
Thomas Mueller's avatar
Thomas Mueller committed
2359 2360 2361 2362 2363 2364 2365
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
"

2366 2367
"Other Grammar","Operand","
summand [ { || summand } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2368
","
2369
A value or a concatenation of values.
Thomas Mueller's avatar
Thomas Mueller committed
2370
In the default mode, the result is NULL if either parameter is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2371
","
2372
'Hi' || ' Eva'
Thomas Mueller's avatar
Thomas Mueller committed
2373 2374
"

2375 2376
"Other Grammar","Order","
{ int | expression } [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
Thomas Mueller's avatar
Thomas Mueller committed
2377
","
2378 2379 2380
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
2381
","
2382
NAME DESC NULLS LAST
Thomas Mueller's avatar
Thomas Mueller committed
2383 2384
"

2385 2386
"Other Grammar","Quoted Name","
""anythingExceptDoubleQuote""
Thomas Mueller's avatar
Thomas Mueller committed
2387
","
2388 2389 2390
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
2391
","
2392
""FirstName""
Thomas Mueller's avatar
Thomas Mueller committed
2393 2394
"

2395 2396 2397
"Other Grammar","Referential Constraint","
FOREIGN KEY ( columnName [,...] )
REFERENCES [ refTableName ] [ ( refColumnName [,...] ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2398
[ ON DELETE referentialAction ] [ ON UPDATE referentialAction ]
Thomas Mueller's avatar
Thomas Mueller committed
2399
","
Thomas Mueller's avatar
Thomas Mueller committed
2400 2401 2402
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
2403 2404 2405
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
2406
","
2407
FOREIGN KEY(ID) REFERENCES TEST(ID)
Thomas Mueller's avatar
Thomas Mueller committed
2408 2409
"

Thomas Mueller's avatar
Thomas Mueller committed
2410 2411 2412 2413 2414 2415 2416 2417 2418 2419 2420
"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
"

2421
"Other Grammar","Script Compression Encryption","
2422 2423
[ COMPRESSION { DEFLATE | LZF | ZIP | GZIP } ]
[ CIPHER cipher PASSWORD string ]
Thomas Mueller's avatar
Thomas Mueller committed
2424
","
2425 2426
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
2427 2428 2429 2430 2431
LZF is faster but uses more space.
","
COMPRESSION LZF
"

2432 2433
"Other Grammar","Select Expression","
* | expression [ [ AS ] columnAlias ] | tableAlias.*
Thomas Mueller's avatar
Thomas Mueller committed
2434
","
2435
An expression in a SELECT statement.
Thomas Mueller's avatar
Thomas Mueller committed
2436
","
2437
ID AS VALUE
Thomas Mueller's avatar
Thomas Mueller committed
2438 2439
"

2440 2441
"Other Grammar","String","
'anythingExceptSingleQuote'
Thomas Mueller's avatar
Thomas Mueller committed
2442
","
2443 2444
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
2445
","
2446
'John''s car'
Thomas Mueller's avatar
Thomas Mueller committed
2447 2448
"

2449 2450
"Other Grammar","Summand","
factor [ { { + | - } factor } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2451
","
Thomas Mueller's avatar
Thomas Mueller committed
2452
A value or a numeric sum.
Thomas Mueller's avatar
Thomas Mueller committed
2453

Thomas Mueller's avatar
Thomas Mueller committed
2454
Please note the text concatenation operator is ""||"".
Thomas Mueller's avatar
Thomas Mueller committed
2455
","
2456
ID + 20
Thomas Mueller's avatar
Thomas Mueller committed
2457 2458
"

2459
"Other Grammar","Table Expression","
2460 2461
{ [ schemaName. ] tableName | ( select ) | valuesExpression }
[ [ AS ] newTableAlias [ ( columnName [,...] ) ] ]
2462
[ USE INDEX ([ indexName [,...] ]) ]
2463 2464
[ { { LEFT | RIGHT } [ OUTER ] | [ INNER ] | CROSS | NATURAL }
    JOIN tableExpression [ ON expression ] ]
Thomas Mueller's avatar
Thomas Mueller committed
2465
","
2466 2467 2468
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
2469
","
2470
TEST AS T LEFT JOIN TEST AS T1 ON T.ID = T1.ID
Thomas Mueller's avatar
Thomas Mueller committed
2471 2472
"

2473 2474 2475 2476 2477 2478 2479 2480 2481
"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;
"

2482 2483 2484 2485 2486 2487 2488 2489 2490 2491 2492 2493
"Other Grammar","Term","
value
    | columnName
    | ?[ int ]
    | NEXT VALUE FOR sequenceName
    | function
    | { - | + } term
    | ( expression )
    | select
    | case
    | caseWhen
    | tableAlias.columnName
2494
    | userDefinedFunctionName
Thomas Mueller's avatar
Thomas Mueller committed
2495
","
2496
A value. Parameters can be indexed, for example ""?1"" meaning the first parameter.
Thomas Mueller's avatar
Thomas Mueller committed
2497
Each table has a pseudo-column named ""_ROWID_"" that contains the unique row identifier.
Thomas Mueller's avatar
Thomas Mueller committed
2498
","
2499 2500 2501 2502
'Hello'
"

"Other Grammar","Time","
2503
TIME [ WITHOUT TIME ZONE ] 'hh:mm:ss[.nnnnnnnnn]'
2504
","
2505
A time literal. A value is between 0:00:00 and 23:59:59.999999999
2506
and has nanosecond resolution.
2507 2508 2509 2510 2511
","
TIME '23:59:59'
"

"Other Grammar","Timestamp","
2512
TIMESTAMP [ WITHOUT TIME ZONE ] 'yyyy-MM-dd hh:mm:ss[.nnnnnnnnn]'
2513 2514
","
A timestamp literal. The limitations are the same as for the Java data type
2515
""java.sql.Timestamp"", but for compatibility with other databases the suggested
2516 2517 2518 2519 2520
minimum and maximum years are 0001 and 9999.
","
TIMESTAMP '2005-12-31 23:59:59'
"

2521
"Other Grammar","Timestamp with time zone","
2522
TIMESTAMP WITH TIME ZONE 'yyyy-MM-dd hh:mm:ss[.nnnnnnnnn]
2523 2524 2525 2526 2527 2528 2529 2530 2531 2532 2533
[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'
"

2534 2535 2536 2537 2538 2539 2540 2541
"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'
"

2542
"Other Grammar","Value","
2543
string | dollarQuotedString | numeric | dateAndTime | boolean | bytes | array | null
2544
","
Thomas Mueller's avatar
Thomas Mueller committed
2545
A literal value of any data type, or null.
2546 2547
","
10
Thomas Mueller's avatar
Thomas Mueller committed
2548 2549 2550 2551 2552 2553 2554
"

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

2555
Mapped to ""java.lang.Integer"".
Thomas Mueller's avatar
Thomas Mueller committed
2556 2557 2558 2559 2560 2561 2562 2563 2564
","
INT
"

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

2565
Mapped to ""java.lang.Boolean"".
Thomas Mueller's avatar
Thomas Mueller committed
2566 2567 2568 2569 2570 2571 2572 2573 2574
","
BOOLEAN
"

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

2575
Mapped to ""java.lang.Byte"".
Thomas Mueller's avatar
Thomas Mueller committed
2576 2577 2578 2579 2580 2581 2582 2583 2584
","
TINYINT
"

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

2585
Mapped to ""java.lang.Short"".
Thomas Mueller's avatar
Thomas Mueller committed
2586 2587 2588 2589 2590 2591 2592 2593 2594
","
SMALLINT
"

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

2595
Mapped to ""java.lang.Long"".
Thomas Mueller's avatar
Thomas Mueller committed
2596 2597 2598 2599 2600 2601 2602 2603 2604 2605 2606
","
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.

2607
Mapped to ""java.lang.Long"".
Thomas Mueller's avatar
Thomas Mueller committed
2608 2609 2610 2611 2612
","
IDENTITY
"

"Data Types","DECIMAL Type","
2613
{ DECIMAL | NUMBER | DEC | NUMERIC } ( precisionInt [ , scaleInt ] )
Thomas Mueller's avatar
Thomas Mueller committed
2614 2615 2616 2617
","
Data type with fixed precision and scale. This data type is recommended for
storing currency values.

2618
Mapped to ""java.math.BigDecimal"".
Thomas Mueller's avatar
Thomas Mueller committed
2619 2620 2621 2622 2623
","
DECIMAL(20, 2)
"

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

2630
Mapped to ""java.lang.Double"".
Thomas Mueller's avatar
Thomas Mueller committed
2631 2632 2633 2634 2635
","
DOUBLE
"

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

2642
Mapped to ""java.lang.Float"".
Thomas Mueller's avatar
Thomas Mueller committed
2643 2644 2645 2646 2647
","
REAL
"

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

2653
Mapped to ""java.sql.Time"". When converted to a ""java.sql.Date"", the date is set to ""1970-01-01"".
2654
""java.time.LocalTime"" is also supported on Java 8 and later versions.
Evgenij Ryazanov's avatar
Evgenij Ryazanov committed
2655
Resolution of ""java.sql.Time"" is limited to milliseconds, use ""String"" or ""java.time.LocalTime"" if you need nanosecond resolution.
Thomas Mueller's avatar
Thomas Mueller committed
2656 2657 2658 2659 2660 2661 2662
","
TIME
"

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

2665
Mapped to ""java.sql.Date"", with the time set to ""00:00:00""
Thomas Mueller's avatar
Thomas Mueller committed
2666
(or to the next possible time if midnight doesn't exist for the given date and timezone due to a daylight saving change).
2667
""java.time.LocalDate"" is also supported on Java 8 and later versions.
Thomas Mueller's avatar
Thomas Mueller committed
2668 2669 2670 2671 2672
","
DATE
"

"Data Types","TIMESTAMP Type","
2673 2674
{ TIMESTAMP [ ( precisionInt ) ] [ WITHOUT TIME ZONE ]
    | DATETIME | SMALLDATETIME }
Thomas Mueller's avatar
Thomas Mueller committed
2675
","
Thomas Mueller's avatar
Thomas Mueller committed
2676
The timestamp data type. The format is yyyy-MM-dd hh:mm:ss[.nnnnnnnnn].
2677
Stored internally as a BCD-encoded date, and nanoseconds since midnight.
2678
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
Thomas Mueller's avatar
Thomas Mueller committed
2679

2680 2681
Mapped to ""java.sql.Timestamp"" (""java.util.Date"" may be used too).
""java.time.LocalDateTime"" is also supported on Java 8 and later versions.
Thomas Mueller's avatar
Thomas Mueller committed
2682 2683 2684 2685
","
TIMESTAMP
"

2686
"Data Types","TIMESTAMP WITH TIME ZONE Type","
2687
TIMESTAMP [ ( precisionInt ) ] WITH TIME ZONE
2688
","
2689
The timestamp with time zone data type.
2690
Stored internally as a BCD-encoded date, nanoseconds since midnight, and time zone offset in minutes.
2691
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
2692

2693 2694 2695 2696 2697 2698 2699
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.
2700
","
2701
TIMESTAMP WITH TIME ZONE
2702 2703
"

Thomas Mueller's avatar
Thomas Mueller committed
2704
"Data Types","BINARY Type","
2705 2706
{ BINARY | VARBINARY | LONGVARBINARY | RAW | BYTEA }
[ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2707
","
2708 2709 2710 2711 2712
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
2713 2714 2715 2716 2717 2718 2719 2720 2721

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

"Data Types","OTHER Type","
OTHER
","
Thomas Mueller's avatar
Thomas Mueller committed
2722 2723 2724 2725 2726
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
2727

2728
Mapped to ""java.lang.Object"" (or any subclass).
Thomas Mueller's avatar
Thomas Mueller committed
2729 2730 2731 2732 2733
","
OTHER
"

"Data Types","VARCHAR Type","
2734
{ VARCHAR | LONGVARCHAR | VARCHAR2 | NVARCHAR
2735
    | NVARCHAR2 | VARCHAR_CASESENSITIVE} [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2736
","
Thomas Mueller's avatar
Thomas Mueller committed
2737
A Unicode String.
Thomas Mueller's avatar
Thomas Mueller committed
2738 2739 2740 2741 2742 2743 2744
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
2745

2746
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
2747 2748 2749 2750 2751
","
VARCHAR(255)
"

"Data Types","VARCHAR_IGNORECASE Type","
2752
VARCHAR_IGNORECASE [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2753
","
Thomas Mueller's avatar
Thomas Mueller committed
2754
Same as VARCHAR, but not case sensitive when comparing.
Thomas Mueller's avatar
Thomas Mueller committed
2755 2756 2757 2758 2759 2760 2761
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
2762

2763
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
2764 2765 2766 2767 2768
","
VARCHAR_IGNORECASE
"

"Data Types","CHAR Type","
2769
{ CHAR | CHARACTER | NCHAR } [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2770
","
Thomas Mueller's avatar
Thomas Mueller committed
2771 2772 2773
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
2774

Thomas Mueller's avatar
Thomas Mueller committed
2775 2776
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
2777

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

2781
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
2782 2783 2784 2785 2786
","
CHAR(10)
"

"Data Types","BLOB Type","
2787 2788
{ BLOB | TINYBLOB | MEDIUMBLOB | LONGBLOB | IMAGE | OID }
[ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2789 2790 2791
","
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
2792
""PreparedStatement.setBinaryStream"" to store values. See also CLOB and
Thomas Mueller's avatar
Thomas Mueller committed
2793 2794
Advanced / Large Objects.

2795
Mapped to ""java.sql.Blob"" (""java.io.InputStream"" is also supported).
Thomas Mueller's avatar
Thomas Mueller committed
2796 2797 2798 2799 2800
","
BLOB
"

"Data Types","CLOB Type","
2801 2802
{ CLOB | TINYTEXT | TEXT | MEDIUMTEXT | LONGTEXT | NTEXT | NCLOB }
[ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2803 2804 2805 2806 2807
","
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
2808
""PreparedStatement.setCharacterStream"" to store values. See also Advanced / Large Objects.
Thomas Mueller's avatar
Thomas Mueller committed
2809 2810 2811 2812 2813

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.

2814
Mapped to ""java.sql.Clob"" (""java.io.Reader"" is also supported).
Thomas Mueller's avatar
Thomas Mueller committed
2815 2816 2817 2818 2819 2820 2821
","
CLOB
"

"Data Types","UUID Type","
UUID
","
Thomas Mueller's avatar
Thomas Mueller committed
2822 2823 2824 2825
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
2826

Thomas Mueller's avatar
Thomas Mueller committed
2827 2828 2829 2830 2831
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
2832
For details, see the documentation of ""java.util.UUID"".
Thomas Mueller's avatar
Thomas Mueller committed
2833 2834 2835 2836 2837 2838 2839
","
UUID
"

"Data Types","ARRAY Type","
ARRAY
","
Thomas Mueller's avatar
Thomas Mueller committed
2840
An array of values.
2841
Mapped to ""java.lang.Object[]"" (arrays of any non-primitive type are also supported).
Thomas Mueller's avatar
Thomas Mueller committed
2842 2843 2844 2845


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
2846 2847 2848 2849
","
ARRAY
"

2850 2851 2852 2853 2854 2855 2856 2857 2858 2859 2860 2861 2862 2863
"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')
"
2864 2865 2866
"Data Types","GEOMETRY Type","
GEOMETRY
","
2867
A spatial geometry type, based on the ""org.locationtech.jts"" library.
2868
Normally represented in textual format using the WKT (well known text) format.
2869

Thomas Mueller's avatar
Thomas Mueller committed
2870
Use a quoted string containing a WKT formatted string or ""PreparedStatement.setObject()"" to store values,
2871 2872
and ""ResultSet.getObject(..)"" or ""ResultSet.getString(..)"" to retrieve the values.
","
2873
GEOMETRY
2874 2875
"

Thomas Mueller's avatar
Thomas Mueller committed
2876
"Functions (Aggregate)","AVG","
2877
AVG ( [ DISTINCT ] { numeric } ) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2878
","
2879 2880
The average (mean) value.
If no rows are selected, the result is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2881
Aggregates are only allowed in select statements.
2882
The returned value is of the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
2883 2884 2885 2886
","
AVG(X)
"

2887
"Functions (Aggregate)","BIT_AND","
2888
BIT_AND(expression) [ FILTER ( WHERE expression ) ]
2889 2890 2891 2892 2893 2894 2895 2896 2897
","
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","
2898
BIT_OR(expression) [ FILTER ( WHERE expression ) ]
2899 2900 2901 2902 2903 2904 2905 2906
","
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)
"

Thomas Mueller's avatar
Thomas Mueller committed
2907
"Functions (Aggregate)","BOOL_AND","
2908
BOOL_AND(boolean) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2909
","
2910 2911 2912
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
2913 2914 2915 2916 2917
","
BOOL_AND(ID>10)
"

"Functions (Aggregate)","BOOL_OR","
2918
BOOL_OR(boolean) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2919
","
2920 2921 2922
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
2923 2924 2925 2926 2927
","
BOOL_OR(NAME LIKE 'W%')
"

"Functions (Aggregate)","COUNT","
2928
COUNT( { * | { [ DISTINCT ] expression } } ) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2929
","
2930 2931 2932 2933
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
2934 2935 2936 2937 2938
","
COUNT(*)
"

"Functions (Aggregate)","GROUP_CONCAT","
2939 2940
GROUP_CONCAT ( [ DISTINCT ] string
[ ORDER BY { expression [ ASC | DESC ] } [,...] ]
2941
[ SEPARATOR expression ] ) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2942
","
2943 2944 2945 2946 2947
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
2948 2949 2950 2951
","
GROUP_CONCAT(NAME ORDER BY ID SEPARATOR ', ')
"

2952 2953 2954 2955 2956 2957 2958 2959 2960 2961 2962 2963 2964
"Functions (Aggregate)","ARRAY_AGG","
ARRAY_AGG ( [ DISTINCT ] string
[ ORDER BY { expression [ ASC | DESC ] } [,...] ] )
[ FILTER ( WHERE expression ) ]
","
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
2965
"Functions (Aggregate)","MAX","
2966
MAX(value) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2967
","
2968 2969 2970 2971
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
2972 2973 2974 2975 2976
","
MAX(NAME)
"

"Functions (Aggregate)","MIN","
2977
MIN(value) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2978
","
2979 2980 2981 2982
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
2983 2984 2985 2986 2987
","
MIN(NAME)
"

"Functions (Aggregate)","SUM","
2988
SUM( [ DISTINCT ] { numeric } ) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2989
","
2990 2991 2992
The sum of all values.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
2993
The data type of the returned value depends on the parameter data type like this:
Thomas Mueller's avatar
Thomas Mueller committed
2994
""BOOLEAN, TINYINT, SMALLINT, INT -> BIGINT, BIGINT -> DECIMAL, REAL -> DOUBLE""
Thomas Mueller's avatar
Thomas Mueller committed
2995 2996 2997 2998 2999
","
SUM(X)
"

"Functions (Aggregate)","SELECTIVITY","
3000
SELECTIVITY(value) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3001
","
3002 3003 3004 3005 3006
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
3007 3008 3009 3010 3011
","
SELECT SELECTIVITY(FIRSTNAME), SELECTIVITY(NAME) FROM TEST WHERE ROWNUM()<20000
"

"Functions (Aggregate)","STDDEV_POP","
3012
STDDEV_POP( [ DISTINCT ] numeric ) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3013
","
3014 3015 3016
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
3017 3018 3019 3020 3021 3022
Aggregates are only allowed in select statements.
","
STDDEV_POP(X)
"

"Functions (Aggregate)","STDDEV_SAMP","
3023
STDDEV_SAMP( [ DISTINCT ] numeric ) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3024
","
3025 3026 3027
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
3028 3029 3030 3031 3032 3033
Aggregates are only allowed in select statements.
","
STDDEV(X)
"

"Functions (Aggregate)","VAR_POP","
3034
VAR_POP( [ DISTINCT ] numeric ) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3035
","
3036 3037 3038 3039
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
3040 3041 3042 3043 3044
","
VAR_POP(X)
"

"Functions (Aggregate)","VAR_SAMP","
3045
VAR_SAMP( [ DISTINCT ] numeric ) [ FILTER ( WHERE expression ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3046
","
3047 3048 3049 3050
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
3051 3052 3053 3054
","
VAR_SAMP(X)
"

3055
"Functions (Aggregate)","MEDIAN","
3056
MEDIAN( [ DISTINCT ] value ) [ FILTER ( WHERE expression ) ]
3057 3058 3059 3060 3061 3062 3063 3064 3065 3066 3067
","
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.
Interpolation is only supported for numeric, date, and time data types.
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)
"

Thomas Mueller's avatar
Thomas Mueller committed
3068
"Functions (Numeric)","ABS","
Thomas Mueller's avatar
Thomas Mueller committed
3069
ABS ( { numeric } )
Thomas Mueller's avatar
Thomas Mueller committed
3070
","
3071 3072
See also Java ""Math.abs"".
Please note that ""Math.abs(Integer.MIN_VALUE) == Integer.MIN_VALUE"" and ""Math.abs(Long.MIN_VALUE) == Long.MIN_VALUE"".
3073
The returned value is of the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
3074 3075 3076 3077 3078
","
ABS(ID)
"

"Functions (Numeric)","ACOS","
Thomas Mueller's avatar
Thomas Mueller committed
3079
ACOS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3080
","
Thomas Mueller's avatar
Thomas Mueller committed
3081 3082
Calculate the arc cosine.
See also Java ""Math.acos"".
3083
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3084 3085 3086 3087 3088
","
ACOS(D)
"

"Functions (Numeric)","ASIN","
Thomas Mueller's avatar
Thomas Mueller committed
3089
ASIN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3090
","
Thomas Mueller's avatar
Thomas Mueller committed
3091 3092
Calculate the arc sine.
See also Java ""Math.asin"".
3093
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3094 3095 3096 3097 3098
","
ASIN(D)
"

"Functions (Numeric)","ATAN","
Thomas Mueller's avatar
Thomas Mueller committed
3099
ATAN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3100
","
Thomas Mueller's avatar
Thomas Mueller committed
3101 3102
Calculate the arc tangent.
See also Java ""Math.atan"".
3103
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3104 3105 3106 3107 3108
","
ATAN(D)
"

"Functions (Numeric)","COS","
Thomas Mueller's avatar
Thomas Mueller committed
3109
COS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3110
","
Thomas Mueller's avatar
Thomas Mueller committed
3111 3112
Calculate the trigonometric cosine.
See also Java ""Math.cos"".
3113
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3114 3115 3116 3117
","
COS(ANGLE)
"

3118
"Functions (Numeric)","COSH","
Thomas Mueller's avatar
Thomas Mueller committed
3119
COSH(numeric)
3120 3121 3122 3123 3124 3125 3126 3127
","
Calculate the hyperbolic cosine.
See also Java ""Math.cosh"".
This method returns a double.
","
COSH(X)
"

Thomas Mueller's avatar
Thomas Mueller committed
3128
"Functions (Numeric)","COT","
Thomas Mueller's avatar
Thomas Mueller committed
3129
COT(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3130
","
Thomas Mueller's avatar
Thomas Mueller committed
3131
Calculate the trigonometric cotangent (""1/TAN(ANGLE)"").
3132
See also Java ""Math.*"" functions.
3133
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3134 3135 3136 3137 3138
","
COT(ANGLE)
"

"Functions (Numeric)","SIN","
Thomas Mueller's avatar
Thomas Mueller committed
3139
SIN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3140
","
Thomas Mueller's avatar
Thomas Mueller committed
3141 3142
Calculate the trigonometric sine.
See also Java ""Math.sin"".
3143
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3144 3145 3146 3147
","
SIN(ANGLE)
"

3148
"Functions (Numeric)","SINH","
Thomas Mueller's avatar
Thomas Mueller committed
3149
SINH(numeric)
3150 3151 3152 3153 3154 3155 3156 3157
","
Calculate the hyperbolic sine.
See also Java ""Math.sinh"".
This method returns a double.
","
SINH(ANGLE)
"

Thomas Mueller's avatar
Thomas Mueller committed
3158
"Functions (Numeric)","TAN","
Thomas Mueller's avatar
Thomas Mueller committed
3159
TAN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3160
","
Thomas Mueller's avatar
Thomas Mueller committed
3161 3162
Calculate the trigonometric tangent.
See also Java ""Math.tan"".
3163
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3164 3165 3166 3167
","
TAN(ANGLE)
"

3168
"Functions (Numeric)","TANH","
Thomas Mueller's avatar
Thomas Mueller committed
3169
TANH(numeric)
3170 3171 3172 3173 3174 3175 3176 3177
","
Calculate the hyperbolic tangent.
See also Java ""Math.tanh"".
This method returns a double.
","
TANH(X)
"

Thomas Mueller's avatar
Thomas Mueller committed
3178
"Functions (Numeric)","ATAN2","
Thomas Mueller's avatar
Thomas Mueller committed
3179
ATAN2(numeric, numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3180
","
Thomas Mueller's avatar
Thomas Mueller committed
3181
Calculate the angle when converting the rectangular coordinates to polar coordinates.
3182
See also Java ""Math.atan2"".
3183
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3184 3185 3186 3187 3188
","
ATAN2(X, Y)
"

"Functions (Numeric)","BITAND","
3189
BITAND(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3190
","
3191 3192
The bitwise AND operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3193 3194 3195 3196 3197
See also Java operator &.
","
BITAND(A, B)
"

3198 3199 3200 3201 3202 3203 3204 3205 3206 3207 3208
"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
3209
"Functions (Numeric)","BITOR","
3210
BITOR(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3211
","
3212 3213
The bitwise OR operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3214 3215 3216 3217 3218 3219
See also Java operator |.
","
BITOR(A, B)
"

"Functions (Numeric)","BITXOR","
3220
BITXOR(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3221
","
3222 3223
The bitwise XOR operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3224 3225 3226 3227 3228 3229
See also Java operator ^.
","
BITXOR(A, B)
"

"Functions (Numeric)","MOD","
3230
MOD(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3231
","
3232 3233
The modulo operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3234 3235 3236 3237 3238 3239
See also Java operator %.
","
MOD(A, B)
"

"Functions (Numeric)","CEILING","
Thomas Mueller's avatar
Thomas Mueller committed
3240
{ CEILING | CEIL } (numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3241
","
3242
See also Java ""Math.ceil"".
3243
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3244
","
3245
CEIL(A)
Thomas Mueller's avatar
Thomas Mueller committed
3246 3247 3248
"

"Functions (Numeric)","DEGREES","
Thomas Mueller's avatar
Thomas Mueller committed
3249
DEGREES(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3250
","
3251
See also Java ""Math.toDegrees"".
3252
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3253 3254 3255 3256 3257
","
DEGREES(A)
"

"Functions (Numeric)","EXP","
Thomas Mueller's avatar
Thomas Mueller committed
3258
EXP(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3259
","
3260
See also Java ""Math.exp"".
3261
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3262 3263 3264 3265 3266
","
EXP(A)
"

"Functions (Numeric)","FLOOR","
Thomas Mueller's avatar
Thomas Mueller committed
3267
FLOOR(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3268
","
3269
See also Java ""Math.floor"".
3270
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3271 3272 3273 3274 3275
","
FLOOR(A)
"

"Functions (Numeric)","LOG","
Thomas Mueller's avatar
Thomas Mueller committed
3276
{ LOG | LN } (numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3277
","
3278
See also Java ""Math.log"".
3279
In the PostgreSQL mode, LOG(x) is base 10.
3280
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3281 3282 3283 3284 3285
","
LOG(A)
"

"Functions (Numeric)","LOG10","
Thomas Mueller's avatar
Thomas Mueller committed
3286
LOG10(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3287
","
3288
See also Java ""Math.log10"".
3289
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3290 3291 3292 3293
","
LOG10(A)
"

3294 3295 3296 3297 3298 3299 3300 3301 3302 3303 3304 3305 3306
"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
3307
"Functions (Numeric)","RADIANS","
Thomas Mueller's avatar
Thomas Mueller committed
3308
RADIANS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3309
","
3310
See also Java ""Math.toRadians"".
3311
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3312 3313 3314 3315 3316
","
RADIANS(A)
"

"Functions (Numeric)","SQRT","
Thomas Mueller's avatar
Thomas Mueller committed
3317
SQRT(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3318
","
3319
See also Java ""Math.sqrt"".
3320
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3321 3322 3323 3324 3325
","
SQRT(A)
"

"Functions (Numeric)","PI","
3326
PI()
Thomas Mueller's avatar
Thomas Mueller committed
3327
","
3328
See also Java ""Math.PI"".
3329
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3330 3331 3332 3333 3334
","
PI()
"

"Functions (Numeric)","POWER","
Thomas Mueller's avatar
Thomas Mueller committed
3335
POWER(numeric, numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3336
","
3337
See also Java ""Math.pow"".
Thomas Mueller's avatar
Thomas Mueller committed
3338
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3339 3340 3341 3342 3343
","
POWER(A, B)
"

"Functions (Numeric)","RAND","
3344
{ RAND | RANDOM } ( [ int ] )
Thomas Mueller's avatar
Thomas Mueller committed
3345 3346 3347
","
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
3348
This method returns a double between 0 (including) and 1 (excluding).
Thomas Mueller's avatar
Thomas Mueller committed
3349 3350 3351 3352 3353
","
RAND()
"

"Functions (Numeric)","RANDOM_UUID","
3354
{ RANDOM_UUID | UUID } ()
Thomas Mueller's avatar
Thomas Mueller committed
3355 3356
","
Returns a new UUID with 122 pseudo random bits.
Thomas Mueller's avatar
Thomas Mueller committed
3357 3358 3359 3360 3361

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
3362 3363 3364 3365 3366
","
RANDOM_UUID()
"

"Functions (Numeric)","ROUND","
3367
ROUND(numeric [, digitsInt])
Thomas Mueller's avatar
Thomas Mueller committed
3368
","
3369
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
3370
This method returns a numeric (the same type as the input).
Thomas Mueller's avatar
Thomas Mueller committed
3371 3372 3373 3374 3375
","
ROUND(VALUE, 2)
"

"Functions (Numeric)","ROUNDMAGIC","
Thomas Mueller's avatar
Thomas Mueller committed
3376
ROUNDMAGIC(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3377
","
3378 3379 3380 3381 3382 3383
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
3384 3385 3386 3387 3388
","
ROUNDMAGIC(VALUE/3*3)
"

"Functions (Numeric)","SECURE_RAND","
3389
SECURE_RAND(int)
Thomas Mueller's avatar
Thomas Mueller committed
3390 3391
","
Generates a number of cryptographically secure random numbers.
3392
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3393 3394 3395 3396 3397
","
CALL SECURE_RAND(16)
"

"Functions (Numeric)","SIGN","
Thomas Mueller's avatar
Thomas Mueller committed
3398
SIGN ( { numeric } )
Thomas Mueller's avatar
Thomas Mueller committed
3399 3400 3401 3402 3403 3404 3405
","
Returns -1 if the value is smaller 0, 0 if zero, and otherwise 1.
","
SIGN(VALUE)
"

"Functions (Numeric)","ENCRYPT","
3406
ENCRYPT(algorithmString, keyBytes, dataBytes)
Thomas Mueller's avatar
Thomas Mueller committed
3407
","
3408
Encrypts data using a key.
3409
The supported algorithm is AES.
3410 3411
The block size is 16 bytes.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3412 3413 3414 3415 3416
","
CALL ENCRYPT('AES', '00', STRINGTOUTF8('Test'))
"

"Functions (Numeric)","DECRYPT","
3417
DECRYPT(algorithmString, keyBytes, dataBytes)
Thomas Mueller's avatar
Thomas Mueller committed
3418
","
3419
Decrypts data using a key.
3420
The supported algorithm is AES.
3421 3422
The block size is 16 bytes.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3423 3424 3425 3426 3427 3428
","
CALL TRIM(CHAR(0) FROM UTF8TOSTRING(
    DECRYPT('AES', '00', '3fabb4de8f1ee2e97d7793bab2db1116')))
"

"Functions (Numeric)","HASH","
3429
HASH(algorithmString, expression [, iterationInt])
Thomas Mueller's avatar
Thomas Mueller committed
3430
","
3431 3432 3433
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
3434 3435 3436 3437 3438
","
CALL HASH('SHA256', STRINGTOUTF8('Password'), 1000)
"

"Functions (Numeric)","TRUNCATE","
3439 3440
{ TRUNC | TRUNCATE } ( { {numeric, digitsInt}
    | timestamp | timestampWithTimeZone | date | timestampString } )
Thomas Mueller's avatar
Thomas Mueller committed
3441 3442
","
Truncates to a number of digits (to the next value closer to 0).
3443
This method returns a double.
3444
When used with a timestamp, truncates a timestamp to a date (day) value.
3445 3446
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
3447 3448 3449 3450 3451
","
TRUNCATE(VALUE, 2)
"

"Functions (Numeric)","COMPRESS","
3452
COMPRESS(dataBytes [, algorithmString])
Thomas Mueller's avatar
Thomas Mueller committed
3453
","
3454 3455 3456 3457
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
3458 3459 3460 3461 3462
","
COMPRESS(STRINGTOUTF8('Test'))
"

"Functions (Numeric)","EXPAND","
3463
EXPAND(bytes)
Thomas Mueller's avatar
Thomas Mueller committed
3464 3465
","
Expands data that was compressed using the COMPRESS function.
3466
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3467 3468 3469 3470 3471
","
UTF8TOSTRING(EXPAND(COMPRESS(STRINGTOUTF8('Test'))))
"

"Functions (Numeric)","ZERO","
3472
ZERO()
Thomas Mueller's avatar
Thomas Mueller committed
3473 3474 3475 3476 3477 3478 3479
","
Returns the value 0. This function can be used even if numeric literals are disabled.
","
ZERO()
"

"Functions (String)","ASCII","
3480
ASCII(string)
Thomas Mueller's avatar
Thomas Mueller committed
3481 3482
","
Returns the ASCII value of the first character in the string.
3483
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
3484 3485 3486 3487
","
ASCII('Hi')
"
"Functions (String)","BIT_LENGTH","
3488
BIT_LENGTH(string)
Thomas Mueller's avatar
Thomas Mueller committed
3489
","
3490 3491 3492
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
3493 3494 3495 3496 3497
","
BIT_LENGTH(NAME)
"

"Functions (String)","LENGTH","
3498
{ LENGTH | CHAR_LENGTH | CHARACTER_LENGTH } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
3499
","
3500 3501 3502
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
3503 3504 3505 3506 3507
","
LENGTH(NAME)
"

"Functions (String)","OCTET_LENGTH","
3508
OCTET_LENGTH(string)
Thomas Mueller's avatar
Thomas Mueller committed
3509
","
3510 3511 3512 3513
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
3514 3515 3516 3517 3518
","
OCTET_LENGTH(NAME)
"

"Functions (String)","CHAR","
3519
{ CHAR | CHR } ( int )
Thomas Mueller's avatar
Thomas Mueller committed
3520 3521
","
Returns the character that represents the ASCII value.
3522
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
3523 3524 3525 3526 3527
","
CHAR(65)
"

"Functions (String)","CONCAT","
3528
CONCAT(string, string [,...])
Thomas Mueller's avatar
Thomas Mueller committed
3529 3530
","
Combines strings.
Thomas Mueller's avatar
Thomas Mueller committed
3531
Unlike with the operator ""||"", NULL parameters are ignored,
Thomas Mueller's avatar
Thomas Mueller committed
3532
and do not cause the result to become NULL.
3533
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
3534 3535 3536 3537
","
CONCAT(NAME, '!')
"

3538 3539 3540 3541
"Functions (String)","CONCAT_WS","
CONCAT_WS(separatorString, string, string [,...])
","
Combines strings with separator.
Thomas Mueller's avatar
Thomas Mueller committed
3542
Unlike with the operator ""||"", NULL parameters are ignored,
Thomas Mueller's avatar
Thomas Mueller committed
3543
and do not cause the result to become NULL.
3544 3545 3546 3547 3548
This method returns a string.
","
CONCAT_WS(',', NAME, '!')
"

Thomas Mueller's avatar
Thomas Mueller committed
3549
"Functions (String)","DIFFERENCE","
3550
DIFFERENCE(string, string)
Thomas Mueller's avatar
Thomas Mueller committed
3551 3552
","
Returns the difference between the sounds of two strings.
3553
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
3554 3555 3556 3557 3558
","
DIFFERENCE(T1.NAME, T2.NAME)
"

"Functions (String)","HEXTORAW","
3559
HEXTORAW(string)
Thomas Mueller's avatar
Thomas Mueller committed
3560
","
3561 3562
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
3563 3564 3565 3566 3567
","
HEXTORAW(DATA)
"

"Functions (String)","RAWTOHEX","
3568
RAWTOHEX(string)
Thomas Mueller's avatar
Thomas Mueller committed
3569
","
3570 3571 3572
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
3573 3574 3575 3576 3577
","
RAWTOHEX(DATA)
"

"Functions (String)","INSTR","
3578
INSTR(string, searchString, [, startInt])
Thomas Mueller's avatar
Thomas Mueller committed
3579
","
3580
Returns the location of a search string in a string.
3581 3582 3583
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
3584
Please note this function is case sensitive, even if the parameters are not.
Thomas Mueller's avatar
Thomas Mueller committed
3585 3586 3587 3588 3589
","
INSTR(EMAIL,'@')
"

"Functions (String)","INSERT Function","
3590
INSERT(originalString, startInt, lengthInt, addString)
Thomas Mueller's avatar
Thomas Mueller committed
3591
","
3592 3593 3594
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
3595 3596 3597 3598 3599
","
INSERT(NAME, 1, 1, ' ')
"

"Functions (String)","LOWER","
3600
{ LOWER | LCASE } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
3601 3602 3603 3604 3605 3606 3607
","
Converts a string to lowercase.
","
LOWER(NAME)
"

"Functions (String)","UPPER","
3608
{ UPPER | UCASE } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
3609 3610 3611 3612 3613 3614 3615
","
Converts a string to uppercase.
","
UPPER(NAME)
"

"Functions (String)","LEFT","
3616
LEFT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
3617 3618 3619 3620 3621 3622 3623
","
Returns the leftmost number of characters.
","
LEFT(NAME, 3)
"

"Functions (String)","RIGHT","
3624
RIGHT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
3625 3626 3627 3628 3629 3630 3631
","
Returns the rightmost number of characters.
","
RIGHT(NAME, 3)
"

"Functions (String)","LOCATE","
3632
LOCATE(searchString, string [, startInt])
Thomas Mueller's avatar
Thomas Mueller committed
3633
","
3634 3635 3636 3637
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
3638 3639 3640 3641 3642
","
LOCATE('.', NAME)
"

"Functions (String)","POSITION","
3643
POSITION(searchString, string)
Thomas Mueller's avatar
Thomas Mueller committed
3644 3645 3646 3647 3648 3649 3650
","
Returns the location of a search string in a string. See also LOCATE.
","
POSITION('.', NAME)
"

"Functions (String)","LPAD","
3651
LPAD(string, int[, paddingString])
Thomas Mueller's avatar
Thomas Mueller committed
3652
","
3653 3654 3655
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
3656 3657 3658 3659 3660
","
LPAD(AMOUNT, 10, '*')
"

"Functions (String)","RPAD","
3661
RPAD(string, int[, paddingString])
Thomas Mueller's avatar
Thomas Mueller committed
3662
","
3663 3664 3665
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
3666 3667 3668 3669 3670
","
RPAD(TEXT, 10, '-')
"

"Functions (String)","LTRIM","
3671
LTRIM(string)
Thomas Mueller's avatar
Thomas Mueller committed
3672 3673 3674 3675 3676 3677 3678
","
Removes all leading spaces from a string.
","
LTRIM(NAME)
"

"Functions (String)","RTRIM","
3679
RTRIM(string)
Thomas Mueller's avatar
Thomas Mueller committed
3680 3681 3682 3683 3684 3685 3686
","
Removes all trailing spaces from a string.
","
RTRIM(NAME)
"

"Functions (String)","TRIM","
3687
TRIM ( [ { LEADING | TRAILING | BOTH } [ string ] FROM ] string )
Thomas Mueller's avatar
Thomas Mueller committed
3688
","
3689 3690
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
3691 3692 3693 3694 3695
","
TRIM(BOTH '_' FROM NAME)
"

"Functions (String)","REGEXP_REPLACE","
3696
REGEXP_REPLACE(inputString, regexString, replacementString [, flagsString])
Thomas Mueller's avatar
Thomas Mueller committed
3697
","
3698
Replaces each substring that matches a regular expression.
3699
For details, see the Java ""String.replaceAll()"" method.
3700 3701 3702 3703 3704 3705 3706 3707 3708 3709 3710 3711 3712 3713
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
3714 3715
","
REGEXP_REPLACE('Hello    World', ' +', ' ')
3716
REGEXP_REPLACE('Hello WWWWorld', 'w+', 'W', 'i')
Thomas Mueller's avatar
Thomas Mueller committed
3717 3718
"

3719 3720 3721 3722
"Functions (String)","REGEXP_LIKE","
REGEXP_LIKE(inputString, regexString [, flagsString])
","
Matches string to a regular expression.
3723 3724 3725 3726 3727 3728 3729 3730 3731 3732 3733 3734 3735 3736 3737
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)

3738 3739
","
REGEXP_LIKE('Hello    World', '[A-Z ]*', 'i')
Thomas Mueller's avatar
Thomas Mueller committed
3740 3741
"

3742

Thomas Mueller's avatar
Thomas Mueller committed
3743
"Functions (String)","REPEAT","
3744
REPEAT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
3745 3746 3747 3748 3749 3750 3751
","
Returns a string repeated some number of times.
","
REPEAT(NAME || ' ', 10)
"

"Functions (String)","REPLACE","
3752
REPLACE(string, searchString [, replacementString])
Thomas Mueller's avatar
Thomas Mueller committed
3753
","
3754 3755
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.
3756
If any parameter is null, the result is null.
Thomas Mueller's avatar
Thomas Mueller committed
3757 3758 3759 3760 3761
","
REPLACE(NAME, ' ')
"

"Functions (String)","SOUNDEX","
3762
SOUNDEX(string)
Thomas Mueller's avatar
Thomas Mueller committed
3763
","
3764 3765 3766
Returns a four character code representing the sound of a string.
See also http://www.archives.gov/genealogy/census/soundex.html .
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
3767 3768 3769 3770 3771
","
SOUNDEX(NAME)
"

"Functions (String)","SPACE","
3772
SPACE(int)
Thomas Mueller's avatar
Thomas Mueller committed
3773 3774 3775 3776 3777 3778 3779
","
Returns a string consisting of a number of spaces.
","
SPACE(80)
"

"Functions (String)","STRINGDECODE","
3780
STRINGDECODE(string)
Thomas Mueller's avatar
Thomas Mueller committed
3781
","
3782 3783 3784
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
3785 3786 3787 3788 3789
","
CALL STRINGENCODE(STRINGDECODE('Lines 1\nLine 2'))
"

"Functions (String)","STRINGENCODE","
3790
STRINGENCODE(string)
Thomas Mueller's avatar
Thomas Mueller committed
3791
","
3792 3793 3794
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
3795 3796 3797 3798 3799
","
CALL STRINGENCODE(STRINGDECODE('Lines 1\nLine 2'))
"

"Functions (String)","STRINGTOUTF8","
3800
STRINGTOUTF8(string)
Thomas Mueller's avatar
Thomas Mueller committed
3801 3802
","
Encodes a string to a byte array using the UTF8 encoding format.
3803
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3804 3805 3806 3807 3808
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"

"Functions (String)","SUBSTRING","
3809
{ SUBSTRING | SUBSTR } ( string, startInt [, lengthInt ] )
Thomas Mueller's avatar
Thomas Mueller committed
3810
","
3811
Returns a substring of a string starting at a position.
3812
If the start index is negative, then the start index is relative to the end of the string.
3813
The length is optional.
3814
Also supported is: ""SUBSTRING(string [FROM start] [FOR length])"".
Thomas Mueller's avatar
Thomas Mueller committed
3815
","
3816 3817
CALL SUBSTR('[Hello]', 2, 5);
CALL SUBSTR('Hello World', -5);
Thomas Mueller's avatar
Thomas Mueller committed
3818 3819 3820
"

"Functions (String)","UTF8TOSTRING","
3821
UTF8TOSTRING(bytes)
Thomas Mueller's avatar
Thomas Mueller committed
3822 3823 3824 3825 3826 3827 3828
","
Decodes a byte array in the UTF8 format to a string.
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"

"Functions (String)","XMLATTR","
3829
XMLATTR(nameString, valueString)
Thomas Mueller's avatar
Thomas Mueller committed
3830
","
3831
Creates an XML attribute element of the form ""name=value"".
3832 3833
The value is encoded as XML text.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
3834 3835 3836 3837 3838
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'))
"

"Functions (String)","XMLNODE","
3839
XMLNODE(elementString [, attributesString [, contentString [, indentBoolean]]])
Thomas Mueller's avatar
Thomas Mueller committed
3840 3841
","
Create an XML node element.
3842 3843 3844
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.
3845
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
3846 3847 3848 3849 3850
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'), 'H2')
"

"Functions (String)","XMLCOMMENT","
3851
XMLCOMMENT(commentString)
Thomas Mueller's avatar
Thomas Mueller committed
3852
","
3853
Creates an XML comment.
3854
Two dashes (""--"") are converted to ""- -"".
3855
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
3856 3857 3858 3859 3860
","
CALL XMLCOMMENT('Test')
"

"Functions (String)","XMLCDATA","
3861
XMLCDATA(valueString)
Thomas Mueller's avatar
Thomas Mueller committed
3862
","
3863
Creates an XML CDATA element.
3864
If the value contains ""]]>"", an XML text element is created instead.
3865
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
3866 3867 3868 3869 3870
","
CALL XMLCDATA('data')
"

"Functions (String)","XMLSTARTDOC","
3871
XMLSTARTDOC()
Thomas Mueller's avatar
Thomas Mueller committed
3872
","
Thomas Mueller's avatar
Thomas Mueller committed
3873
Returns the XML declaration.
3874
The result is always ""<?xml version=""1.0""?>"".
Thomas Mueller's avatar
Thomas Mueller committed
3875 3876 3877 3878 3879
","
CALL XMLSTARTDOC()
"

"Functions (String)","XMLTEXT","
3880
XMLTEXT(valueString [, escapeNewlineBoolean])
Thomas Mueller's avatar
Thomas Mueller committed
3881 3882
","
Creates an XML text element.
Thomas Mueller's avatar
Thomas Mueller committed
3883
If enabled, newline and linefeed is converted to an XML entity (&#).
3884
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
3885 3886 3887 3888
","
CALL XMLTEXT('test')
"

3889
"Functions (String)","TO_CHAR","
3890
TO_CHAR(value [, formatString[, nlsParamString]])
3891 3892 3893 3894 3895 3896
","
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')
"

3897
"Functions (String)","TRANSLATE","
3898
TRANSLATE(value, searchString, replacementString)
3899 3900 3901 3902 3903 3904
","
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
3905
"Functions (Time and Date)","CURRENT_DATE","
3906
{ CURRENT_DATE [ () ] | CURDATE() | SYSDATE | TODAY }
Thomas Mueller's avatar
Thomas Mueller committed
3907 3908
","
Returns the current date.
3909
This method always returns the same value within a transaction.
Thomas Mueller's avatar
Thomas Mueller committed
3910 3911 3912 3913 3914
","
CURRENT_DATE()
"

"Functions (Time and Date)","CURRENT_TIME","
3915
{ CURRENT_TIME [ () ] | CURTIME() }
Thomas Mueller's avatar
Thomas Mueller committed
3916 3917
","
Returns the current time.
3918
This method always returns the same value within a transaction.
Thomas Mueller's avatar
Thomas Mueller committed
3919 3920 3921 3922 3923
","
CURRENT_TIME()
"

"Functions (Time and Date)","CURRENT_TIMESTAMP","
3924
{ CURRENT_TIMESTAMP [ ( [ int ] ) ] | NOW( [ int ] ) }
Thomas Mueller's avatar
Thomas Mueller committed
3925
","
3926 3927
Returns the current timestamp.
The precision parameter for nanoseconds precision is optional.
3928
This method always returns the same value within a transaction.
Thomas Mueller's avatar
Thomas Mueller committed
3929 3930 3931 3932 3933
","
CURRENT_TIMESTAMP()
"

"Functions (Time and Date)","DATEADD","
3934
{ DATEADD| TIMESTAMPADD } (datetimeField, addIntLong, dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
3935
","
3936
Adds units to a date-time value. The datetimeField indicates the unit.
3937
Use negative values to subtract units.
3938
addIntLong may be a long value when manipulating milliseconds,
3939
microseconds, or nanoseconds otherwise its range is restricted to int.
3940
This method returns a value with the same type as specified value if unit is compatible with this value.
3941 3942 3943
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
3944 3945 3946 3947 3948
","
DATEADD('MONTH', 1, DATE '2001-01-31')
"

"Functions (Time and Date)","DATEDIFF","
3949
{ DATEDIFF | TIMESTAMPDIFF } (datetimeField, aDateAndTime, bDateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
3950
","
3951
Returns the the number of crossed unit boundaries between two date/time values.
3952
This method returns a long.
3953
The datetimeField indicates the unit.
3954 3955
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
3956 3957 3958 3959 3960
","
DATEDIFF('YEAR', T1.CREATED, T2.CREATED)
"

"Functions (Time and Date)","DAYNAME","
3961
DAYNAME(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
3962 3963 3964 3965 3966 3967 3968
","
Returns the name of the day (in English).
","
DAYNAME(CREATED)
"

"Functions (Time and Date)","DAY_OF_MONTH","
3969
DAY_OF_MONTH(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
3970 3971 3972 3973 3974 3975 3976
","
Returns the day of the month (1-31).
","
DAY_OF_MONTH(CREATED)
"

"Functions (Time and Date)","DAY_OF_WEEK","
3977
DAY_OF_WEEK(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
3978 3979 3980 3981 3982 3983
","
Returns the day of the week (1 means Sunday).
","
DAY_OF_WEEK(CREATED)
"

3984 3985 3986 3987 3988 3989 3990 3991
"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
3992
"Functions (Time and Date)","DAY_OF_YEAR","
3993
DAY_OF_YEAR(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
3994 3995 3996 3997 3998 3999 4000
","
Returns the day of the year (1-366).
","
DAY_OF_YEAR(CREATED)
"

"Functions (Time and Date)","EXTRACT","
4001
EXTRACT ( datetimeField FROM dateAndTime )
Thomas Mueller's avatar
Thomas Mueller committed
4002
","
4003
Returns a value of the specific time unit from a date/time value.
4004 4005
This method returns a numeric value with EPOCH field and
an int for all other fields.
Thomas Mueller's avatar
Thomas Mueller committed
4006 4007 4008 4009 4010
","
EXTRACT(SECOND FROM CURRENT_TIMESTAMP)
"

"Functions (Time and Date)","FORMATDATETIME","
4011
FORMATDATETIME ( dateAndTime, formatString
4012
[ , localeString [ , timeZoneString ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4013
","
4014 4015 4016
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.
4017
For details of the format, see ""java.text.SimpleDateFormat"".
4018 4019
timeZoneString may be specified if dateAndTime is a DATE, TIME or TIMESTAMP.
timeZoneString is ignored if dateAndTime is TIMESTAMP WITH TIME ZONE.
4020
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4021 4022 4023 4024 4025 4026
","
CALL FORMATDATETIME(TIMESTAMP '2001-02-03 04:05:06',
    'EEE, d MMM yyyy HH:mm:ss z', 'en', 'GMT')
"

"Functions (Time and Date)","HOUR","
4027
HOUR(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4028
","
4029
Returns the hour (0-23) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4030 4031 4032 4033 4034
","
HOUR(CREATED)
"

"Functions (Time and Date)","MINUTE","
4035
MINUTE(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4036
","
4037
Returns the minute (0-59) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4038 4039 4040 4041 4042
","
MINUTE(CREATED)
"

"Functions (Time and Date)","MONTH","
4043
MONTH(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4044
","
4045
Returns the month (1-12) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4046 4047 4048 4049 4050
","
MONTH(CREATED)
"

"Functions (Time and Date)","MONTHNAME","
4051
MONTHNAME(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4052 4053 4054 4055 4056 4057 4058
","
Returns the name of the month (in English).
","
MONTHNAME(CREATED)
"

"Functions (Time and Date)","PARSEDATETIME","
4059
PARSEDATETIME(string, formatString
4060
[, localeString [, timeZoneString]])
Thomas Mueller's avatar
Thomas Mueller committed
4061
","
4062 4063 4064
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.
4065
For details of the format, see ""java.text.SimpleDateFormat"".
Thomas Mueller's avatar
Thomas Mueller committed
4066 4067 4068 4069 4070 4071
","
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","
4072
QUARTER(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4073
","
4074
Returns the quarter (1-4) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4075 4076 4077 4078 4079
","
QUARTER(CREATED)
"

"Functions (Time and Date)","SECOND","
4080
SECOND(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4081
","
4082
Returns the second (0-59) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4083 4084 4085 4086 4087
","
SECOND(CREATED)
"

"Functions (Time and Date)","WEEK","
4088
WEEK(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4089
","
4090
Returns the week (1-53) from a date/time value.
4091
This method uses the current system locale.
Thomas Mueller's avatar
Thomas Mueller committed
4092 4093 4094 4095
","
WEEK(CREATED)
"

4096
"Functions (Time and Date)","ISO_WEEK","
4097
ISO_WEEK(dateAndTime)
4098
","
4099
Returns the ISO week (1-53) from a date/time value.
4100
This function uses the ISO definition when
4101 4102 4103 4104 4105 4106
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
4107
"Functions (Time and Date)","YEAR","
4108
YEAR(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4109
","
4110
Returns the year from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4111 4112 4113 4114
","
YEAR(CREATED)
"

4115
"Functions (Time and Date)","ISO_YEAR","
4116
ISO_YEAR(dateAndTime)
4117
","
4118
Returns the ISO week year from a date/time value.
4119 4120 4121 4122
","
ISO_YEAR(CREATED)
"

Thomas Mueller's avatar
Thomas Mueller committed
4123
"Functions (System)","ARRAY_GET","
4124
ARRAY_GET(arrayExpression, indexExpression)
Thomas Mueller's avatar
Thomas Mueller committed
4125 4126
","
Returns one element of an array.
4127
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4128 4129 4130 4131 4132
","
CALL ARRAY_GET(('Hello', 'World'), 2)
"

"Functions (System)","ARRAY_LENGTH","
Thomas Mueller's avatar
Thomas Mueller committed
4133
ARRAY_LENGTH(arrayExpression)
Thomas Mueller's avatar
Thomas Mueller committed
4134 4135 4136 4137 4138 4139
","
Returns the length of an array.
","
CALL ARRAY_LENGTH(('Hello', 'World'))
"

4140 4141 4142 4143 4144 4145 4146 4147
"Functions (System)","ARRAY_CONTAINS","
ARRAY_CONTAINS(arrayExpression, value)
","
Returns a boolean true if the array contains the value.
","
CALL ARRAY_CONTAINS(('Hello', 'World'), 'Hello')
"

Thomas Mueller's avatar
Thomas Mueller committed
4148
"Functions (System)","AUTOCOMMIT","
4149
AUTOCOMMIT()
Thomas Mueller's avatar
Thomas Mueller committed
4150 4151 4152 4153 4154 4155 4156
","
Returns true if auto commit is switched on for this session.
","
AUTOCOMMIT()
"

"Functions (System)","CANCEL_SESSION","
4157
CANCEL_SESSION(sessionInt)
Thomas Mueller's avatar
Thomas Mueller committed
4158
","
4159 4160 4161
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
4162 4163

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4164 4165 4166 4167 4168
","
CANCEL_SESSION(3)
"

"Functions (System)","CASEWHEN Function","
4169
CASEWHEN(boolean, aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
4170 4171
","
Returns 'a' if the boolean expression is true, otherwise 'b'.
4172
Returns the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
4173 4174 4175 4176 4177
","
CASEWHEN(ID=1, 'A', 'B')
"

"Functions (System)","CAST","
4178
CAST(value AS dataType)
Thomas Mueller's avatar
Thomas Mueller committed
4179
","
4180 4181 4182 4183 4184 4185 4186 4187 4188 4189 4190 4191
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
4192 4193 4194
"

"Functions (System)","COALESCE","
4195
{ COALESCE | NVL } (aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4196 4197 4198 4199 4200 4201 4202
","
Returns the first value that is not null.
","
COALESCE(A, B, C)
"

"Functions (System)","CONVERT","
4203
CONVERT(value, dataType)
Thomas Mueller's avatar
Thomas Mueller committed
4204 4205 4206 4207 4208 4209 4210
","
Converts a value to another data type.
","
CONVERT(NAME, INT)
"

"Functions (System)","CURRVAL","
4211
CURRVAL( [ schemaName, ] sequenceString )
Thomas Mueller's avatar
Thomas Mueller committed
4212
","
4213 4214 4215 4216 4217
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
4218 4219 4220 4221 4222
","
CURRVAL('TEST_SEQ')
"

"Functions (System)","CSVREAD","
4223
CSVREAD(fileNameString [, columnsString [, csvOptions ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4224
","
4225 4226
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
4227 4228

If the column names are specified (a list of column names separated with the
4229
fieldSeparator), those are used, otherwise (or if they are set to NULL) the first line of
4230 4231 4232 4233 4234
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
4235 4236 4237 4238 4239

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.

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

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

Thomas Mueller's avatar
Thomas Mueller committed
4244
Instead of a file, an URL may be used, for example
4245 4246
""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
4247
To read from HTTP, use the prefix ""http:"" (as in a browser).
4248

Thomas Mueller's avatar
Thomas Mueller committed
4249 4250 4251
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
4252 4253 4254 4255
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
4256 4257 4258 4259
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
4260
SELECT ""Last Name"" FROM CSVREAD('address.csv');
4261
SELECT ""Last Name"" FROM CSVREAD('classpath:/org/acme/data/address.csv');
Thomas Mueller's avatar
Thomas Mueller committed
4262 4263 4264
"

"Functions (System)","CSVWRITE","
4265
CSVWRITE ( fileNameString, queryString [, csvOptions [, lineSepString] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4266
","
4267
Writes a CSV (comma separated values). The file is overwritten if it exists.
Thomas Mueller's avatar
Thomas Mueller committed
4268
If only a file name is specified, it will be written to the current working directory.
4269
For each parameter, NULL means the default value should be used.
Thomas Mueller's avatar
Thomas Mueller committed
4270
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
4271 4272 4273 4274 4275

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
4276
system (system property ""line.separator"").
Thomas Mueller's avatar
Thomas Mueller committed
4277

Thomas Mueller's avatar
Thomas Mueller committed
4278 4279
The returned value is the number or rows written.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4280
","
Thomas Mueller's avatar
Thomas Mueller committed
4281 4282 4283 4284
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
4285 4286 4287
"

"Functions (System)","DATABASE","
4288
DATABASE()
Thomas Mueller's avatar
Thomas Mueller committed
4289 4290 4291 4292 4293 4294 4295
","
Returns the name of the database.
","
CALL DATABASE();
"

"Functions (System)","DATABASE_PATH","
4296
DATABASE_PATH()
Thomas Mueller's avatar
Thomas Mueller committed
4297
","
Thomas Mueller's avatar
Thomas Mueller committed
4298 4299
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
4300 4301 4302 4303
","
CALL DATABASE_PATH();
"

4304
"Functions (System)","DECODE","
Thomas Mueller's avatar
Thomas Mueller committed
4305
DECODE(value, whenValue, thenValue [,...])
4306 4307 4308 4309 4310 4311 4312 4313
","
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');
"

4314
"Functions (System)","DISK_SPACE_USED","
Thomas Mueller's avatar
Thomas Mueller committed
4315
DISK_SPACE_USED(tableNameString)
4316 4317 4318 4319 4320 4321 4322 4323
","
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');
"

4324
"Functions (System)","SIGNAL","
4325
SIGNAL(sqlStateString, messageString)
4326 4327 4328 4329 4330 4331
","
Throw an SQLException with the passed SQLState and reason.
","
CALL SIGNAL('23505', 'Duplicate user ID: ' || user_id);
"

Thomas Mueller's avatar
Thomas Mueller committed
4332
"Functions (System)","FILE_READ","
4333
FILE_READ(fileNameString [,encodingString])
Thomas Mueller's avatar
Thomas Mueller committed
4334 4335 4336 4337
","
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
4338
default character set for this system.
4339 4340 4341 4342

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

Thomas Mueller's avatar
Thomas Mueller committed
4343
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4344 4345 4346 4347 4348
","
SELECT LENGTH(FILE_READ('~/.h2.server.properties')) LEN;
SELECT FILE_READ('http://localhost:8182/stylesheet.css', NULL) CSS;
"

4349
"Functions (System)","FILE_WRITE","
4350
FILE_WRITE(blobValue, fileNameString)
4351 4352 4353 4354 4355 4356 4357 4358
","
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
4359
"Functions (System)","GREATEST","
4360
GREATEST(aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4361 4362 4363 4364 4365 4366 4367
","
Returns the largest value that is not NULL, or NULL if all values are NULL.
","
CALL GREATEST(1, 2, 3);
"

"Functions (System)","IDENTITY","
4368
IDENTITY()
Thomas Mueller's avatar
Thomas Mueller committed
4369 4370
","
Returns the last inserted identity value for this session.
4371
This value changes whenever a new sequence number was generated,
4372
even within a trigger or Java function. See also SCOPE_IDENTITY.
4373
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
4374 4375 4376 4377 4378
","
CALL IDENTITY();
"

"Functions (System)","IFNULL","
4379
IFNULL(aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
4380 4381 4382 4383 4384 4385 4386
","
Returns the value of 'a' if it is not null, otherwise 'b'.
","
CALL IFNULL(NULL, '');
"

"Functions (System)","LEAST","
4387
LEAST(aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4388 4389 4390 4391 4392 4393 4394
","
Returns the smallest value that is not NULL, or NULL if all values are NULL.
","
CALL LEAST(1, 2, 3);
"

"Functions (System)","LOCK_MODE","
4395
LOCK_MODE()
Thomas Mueller's avatar
Thomas Mueller committed
4396 4397
","
Returns the current lock mode. See SET LOCK_MODE.
4398
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
4399 4400 4401 4402 4403
","
CALL LOCK_MODE();
"

"Functions (System)","LOCK_TIMEOUT","
4404
LOCK_TIMEOUT()
Thomas Mueller's avatar
Thomas Mueller committed
4405 4406 4407 4408 4409 4410 4411 4412
","
Returns the lock timeout of the current session (in milliseconds).
","
LOCK_TIMEOUT()
"

"Functions (System)","LINK_SCHEMA","
LINK_SCHEMA(targetSchemaString, driverString, urlString,
4413
userString, passwordString, sourceSchemaString)
Thomas Mueller's avatar
Thomas Mueller committed
4414
","
4415 4416 4417 4418 4419
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
4420
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4421 4422 4423 4424 4425
","
CALL LINK_SCHEMA('TEST2', '', 'jdbc:h2:test2', 'sa', 'sa', 'PUBLIC');
"

"Functions (System)","MEMORY_FREE","
4426
MEMORY_FREE()
Thomas Mueller's avatar
Thomas Mueller committed
4427
","
Thomas Mueller's avatar
Thomas Mueller committed
4428
Returns the free memory in KB (where 1024 bytes is a KB).
4429
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
4430 4431
The garbage is run before returning the value.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4432 4433 4434 4435 4436
","
MEMORY_FREE()
"

"Functions (System)","MEMORY_USED","
4437
MEMORY_USED()
Thomas Mueller's avatar
Thomas Mueller committed
4438
","
Thomas Mueller's avatar
Thomas Mueller committed
4439
Returns the used memory in KB (where 1024 bytes is a KB).
4440
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
4441 4442
The garbage is run before returning the value.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4443 4444 4445 4446 4447
","
MEMORY_USED()
"

"Functions (System)","NEXTVAL","
4448
NEXTVAL ( [ schemaName, ] sequenceString )
Thomas Mueller's avatar
Thomas Mueller committed
4449
","
4450 4451 4452 4453
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
4454 4455 4456 4457 4458
","
NEXTVAL('TEST_SEQ')
"

"Functions (System)","NULLIF","
4459
NULLIF(aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
4460 4461 4462 4463 4464 4465
","
Returns NULL if 'a' is equals to 'b', otherwise 'a'.
","
NULLIF(A, B)
"

4466 4467 4468 4469
"Functions (System)","NVL2","
NVL2(testValue, aValue, bValue)
","
If the test value is null, then 'b' is returned. Otherwise, 'a' is returned.
4470
The data type of the returned value is the data type of 'a' if this is a text type.
4471 4472 4473 4474
","
NVL2(X, 'not null', 'null')
"

Thomas Mueller's avatar
Thomas Mueller committed
4475
"Functions (System)","READONLY","
4476
READONLY()
Thomas Mueller's avatar
Thomas Mueller committed
4477 4478 4479 4480 4481 4482 4483
","
Returns true if the database is read-only.
","
READONLY()
"

"Functions (System)","ROWNUM","
Thomas Mueller's avatar
Thomas Mueller committed
4484
{ ROWNUM() } | { ROW_NUMBER() OVER() }
Thomas Mueller's avatar
Thomas Mueller committed
4485
","
4486
Returns the number of the current row.
4487 4488
This method returns a long.
It is supported for SELECT statements, as well as for DELETE and UPDATE.
4489
The first row has the row number 1, and is calculated before ordering and grouping the result set,
4490
but after evaluating index conditions (even when the index conditions are specified in an outer query).
4491
To get the row number after ordering and grouping, use a subquery.
Thomas Mueller's avatar
Thomas Mueller committed
4492
","
4493 4494
SELECT ROWNUM(), * FROM TEST;
SELECT ROWNUM(), * FROM (SELECT * FROM TEST ORDER BY NAME);
Thomas Mueller's avatar
Thomas Mueller committed
4495
SELECT ID FROM (SELECT T.*, ROWNUM AS R FROM TEST T) WHERE R BETWEEN 2 AND 3;
Thomas Mueller's avatar
Thomas Mueller committed
4496 4497 4498
"

"Functions (System)","SCHEMA","
4499
SCHEMA()
Thomas Mueller's avatar
Thomas Mueller committed
4500
","
4501
Returns the name of the default schema for this session.
Thomas Mueller's avatar
Thomas Mueller committed
4502 4503 4504 4505
","
CALL SCHEMA()
"

4506 4507 4508
"Functions (System)","SCOPE_IDENTITY","
SCOPE_IDENTITY()
","
4509
Returns the last inserted identity value for this session for the current scope
4510
(the current statement).
4511 4512 4513 4514 4515 4516
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
4517
"Functions (System)","SESSION_ID","
4518
SESSION_ID()
Thomas Mueller's avatar
Thomas Mueller committed
4519
","
4520 4521 4522 4523
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
4524 4525 4526 4527 4528
","
CALL SESSION_ID()
"

"Functions (System)","SET","
4529
SET(@variableName, value)
Thomas Mueller's avatar
Thomas Mueller committed
4530
","
4531 4532 4533
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
4534
When used in a subquery, not all rows might be read depending on the query plan.
Thomas Mueller's avatar
Thomas Mueller committed
4535
This can be used to implement running totals / cumulative sums.
Thomas Mueller's avatar
Thomas Mueller committed
4536 4537 4538 4539 4540
","
SELECT X, SET(@I, IFNULL(@I, 0)+X) RUNNING_TOTAL FROM SYSTEM_RANGE(1, 10)
"

"Functions (System)","TABLE","
4541
{ TABLE | TABLE_DISTINCT } ( { name dataType = expression } [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
4542 4543 4544 4545 4546 4547 4548
","
Returns the result set. TABLE_DISTINCT removes duplicate rows.
","
SELECT * FROM TABLE(ID INT=(1, 2), NAME VARCHAR=('Hello', 'World'))
"

"Functions (System)","TRANSACTION_ID","
4549
TRANSACTION_ID()
Thomas Mueller's avatar
Thomas Mueller committed
4550
","
4551 4552
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
4553
Otherwise a value of the following form is returned:
4554
""logFileId-position-sessionId"".
4555 4556
This method returns a string.
The value is unique across database restarts (values are not re-used).
Thomas Mueller's avatar
Thomas Mueller committed
4557 4558 4559 4560
","
CALL TRANSACTION_ID()
"

4561 4562 4563 4564 4565 4566 4567 4568 4569 4570 4571 4572
"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);
"

Thomas Mueller's avatar
Thomas Mueller committed
4573
"Functions (System)","USER","
4574
{ USER | CURRENT_USER } ()
Thomas Mueller's avatar
Thomas Mueller committed
4575 4576 4577 4578 4579 4580
","
Returns the name of the current user of this session.
","
CURRENT_USER()
"

4581 4582 4583 4584 4585 4586 4587 4588
"Functions (System)","H2VERSION","
H2VERSION()
","
Returns the H2 version as a String.
","
H2VERSION()
"

Thomas Mueller's avatar
Thomas Mueller committed
4589 4590 4591 4592 4593 4594 4595 4596 4597 4598 4599 4600 4601 4602 4603
"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
4604