1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591
1592
1593
1594
1595
1596
1597
1598
1599
1600
1601
1602
1603
1604
1605
1606
1607
1608
1609
1610
1611
1612
1613
1614
1615
1616
1617
1618
1619
1620
1621
1622
1623
1624
1625
1626
1627
1628
1629
1630
1631
1632
1633
1634
1635
1636
1637
1638
1639
1640
1641
1642
1643
1644
1645
1646
1647
1648
1649
1650
1651
1652
1653
1654
1655
1656
1657
1658
1659
1660
1661
1662
1663
1664
1665
1666
1667
1668
1669
1670
1671
1672
1673
1674
1675
1676
1677
1678
1679
1680
1681
1682
1683
1684
1685
1686
1687
1688
1689
1690
1691
1692
1693
1694
1695
1696
1697
1698
1699
1700
1701
1702
1703
1704
1705
1706
1707
1708
1709
1710
1711
1712
1713
1714
1715
1716
1717
1718
1719
1720
1721
1722
1723
1724
1725
1726
1727
1728
1729
1730
1731
1732
1733
1734
1735
1736
1737
1738
1739
1740
1741
1742
1743
1744
1745
1746
1747
1748
1749
1750
1751
1752
1753
1754
1755
1756
1757
1758
1759
1760
1761
1762
1763
1764
1765
1766
1767
1768
1769
1770
1771
1772
1773
1774
1775
1776
1777
1778
1779
1780
1781
1782
1783
1784
1785
1786
1787
1788
1789
1790
1791
1792
1793
1794
1795
1796
1797
1798
1799
1800
1801
1802
1803
1804
1805
1806
1807
1808
1809
1810
1811
1812
1813
1814
1815
1816
1817
1818
1819
1820
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
1955
1956
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
1988
1989
1990
1991
1992
1993
1994
1995
1996
1997
1998
1999
2000
2001
2002
2003
2004
2005
2006
2007
2008
2009
2010
2011
2012
2013
2014
2015
2016
2017
2018
2019
2020
2021
2022
2023
2024
2025
2026
2027
2028
2029
2030
2031
2032
2033
2034
2035
2036
2037
2038
2039
2040
2041
2042
2043
2044
2045
2046
2047
2048
2049
2050
2051
2052
2053
2054
2055
2056
2057
2058
2059
2060
2061
2062
2063
2064
2065
2066
2067
2068
2069
2070
2071
2072
2073
2074
2075
2076
2077
2078
2079
2080
2081
2082
2083
2084
2085
2086
2087
2088
2089
2090
2091
2092
2093
2094
2095
2096
2097
2098
2099
2100
2101
2102
2103
2104
2105
2106
2107
2108
2109
2110
2111
2112
2113
2114
2115
2116
2117
2118
2119
2120
2121
2122
2123
2124
2125
2126
2127
2128
2129
2130
2131
2132
2133
2134
2135
2136
2137
2138
2139
2140
2141
2142
2143
2144
2145
2146
2147
2148
2149
2150
2151
2152
2153
2154
2155
2156
2157
2158
2159
2160
2161
2162
2163
2164
2165
2166
2167
2168
2169
2170
2171
2172
2173
2174
2175
2176
2177
2178
2179
2180
2181
2182
2183
2184
2185
2186
2187
2188
2189
2190
2191
2192
2193
2194
2195
2196
2197
2198
2199
2200
2201
2202
2203
2204
2205
2206
2207
2208
2209
2210
2211
2212
2213
2214
2215
2216
2217
2218
2219
2220
2221
2222
2223
2224
2225
2226
2227
2228
2229
2230
2231
2232
2233
2234
2235
2236
2237
2238
2239
2240
2241
2242
2243
2244
2245
2246
2247
2248
2249
2250
2251
2252
2253
2254
2255
2256
2257
2258
2259
2260
2261
2262
2263
2264
2265
2266
2267
2268
2269
2270
2271
2272
2273
2274
2275
2276
2277
2278
2279
2280
2281
2282
2283
2284
2285
2286
2287
2288
2289
2290
2291
2292
2293
2294
2295
2296
2297
2298
2299
2300
2301
2302
2303
2304
2305
2306
2307
2308
2309
2310
2311
2312
2313
2314
2315
2316
2317
2318
2319
2320
2321
2322
2323
2324
2325
2326
2327
2328
2329
2330
2331
2332
2333
2334
2335
2336
2337
2338
2339
2340
2341
2342
2343
2344
2345
2346
2347
2348
2349
2350
2351
2352
2353
2354
2355
2356
2357
2358
2359
2360
2361
2362
2363
2364
2365
2366
2367
2368
2369
2370
2371
2372
2373
2374
2375
2376
2377
2378
2379
2380
2381
2382
2383
2384
2385
2386
2387
2388
2389
2390
2391
2392
2393
2394
2395
2396
2397
2398
2399
2400
2401
2402
2403
2404
2405
2406
2407
2408
2409
2410
2411
2412
2413
2414
2415
2416
2417
2418
2419
2420
2421
2422
2423
2424
2425
2426
2427
2428
2429
2430
2431
2432
2433
2434
2435
2436
2437
2438
2439
2440
2441
2442
2443
2444
2445
2446
2447
2448
2449
2450
2451
2452
2453
2454
2455
2456
2457
2458
2459
2460
2461
2462
2463
2464
2465
2466
2467
2468
2469
2470
2471
2472
2473
2474
2475
2476
2477
2478
2479
2480
2481
2482
2483
2484
2485
2486
2487
2488
2489
2490
2491
2492
2493
2494
2495
2496
2497
2498
2499
2500
2501
2502
2503
2504
2505
2506
2507
2508
2509
2510
2511
2512
2513
2514
2515
2516
2517
2518
2519
2520
2521
2522
2523
2524
2525
2526
2527
2528
2529
2530
2531
2532
2533
2534
2535
2536
2537
2538
2539
2540
2541
2542
2543
2544
2545
2546
2547
2548
2549
2550
2551
2552
2553
2554
2555
2556
2557
2558
2559
2560
2561
2562
2563
2564
2565
2566
2567
2568
2569
2570
2571
2572
2573
2574
2575
2576
2577
2578
2579
2580
2581
2582
2583
2584
2585
2586
2587
2588
2589
2590
2591
2592
2593
2594
2595
2596
2597
2598
2599
2600
2601
2602
2603
2604
2605
2606
2607
2608
2609
2610
2611
2612
2613
2614
2615
2616
2617
2618
2619
2620
2621
2622
2623
2624
2625
2626
2627
2628
2629
2630
2631
2632
2633
2634
2635
2636
2637
2638
2639
2640
2641
2642
2643
2644
2645
2646
2647
2648
2649
2650
2651
2652
2653
2654
2655
2656
2657
2658
2659
2660
2661
2662
2663
2664
2665
2666
2667
2668
2669
2670
2671
2672
2673
2674
2675
2676
2677
2678
2679
2680
2681
2682
2683
2684
2685
2686
2687
2688
2689
2690
2691
2692
2693
2694
2695
2696
2697
2698
2699
2700
2701
2702
2703
2704
2705
2706
2707
2708
2709
2710
2711
2712
2713
2714
2715
2716
2717
2718
2719
2720
2721
2722
2723
2724
2725
2726
2727
2728
2729
2730
2731
2732
2733
2734
2735
2736
2737
2738
2739
2740
2741
2742
2743
2744
2745
2746
2747
2748
2749
2750
2751
2752
2753
2754
2755
2756
2757
2758
2759
2760
2761
2762
2763
2764
2765
2766
2767
2768
2769
2770
2771
2772
2773
2774
2775
2776
2777
2778
2779
2780
2781
2782
2783
2784
2785
2786
2787
2788
2789
2790
2791
2792
2793
2794
2795
2796
2797
2798
2799
2800
2801
2802
2803
2804
2805
2806
2807
2808
2809
2810
2811
2812
2813
2814
2815
2816
2817
2818
2819
2820
2821
2822
2823
2824
2825
2826
2827
2828
2829
2830
2831
2832
2833
2834
2835
2836
2837
2838
2839
2840
2841
2842
2843
2844
2845
2846
2847
2848
2849
2850
2851
2852
2853
2854
2855
2856
2857
2858
2859
2860
2861
2862
2863
2864
2865
2866
2867
2868
2869
2870
2871
2872
2873
2874
2875
2876
2877
2878
2879
2880
2881
2882
2883
2884
2885
2886
2887
2888
2889
2890
2891
2892
2893
2894
2895
2896
2897
2898
2899
2900
2901
2902
2903
2904
2905
2906
2907
2908
2909
2910
2911
2912
2913
2914
2915
2916
2917
2918
2919
2920
2921
2922
2923
2924
2925
2926
2927
2928
2929
2930
2931
2932
2933
2934
2935
2936
2937
2938
2939
2940
2941
2942
2943
2944
2945
2946
2947
2948
2949
2950
2951
2952
2953
2954
2955
2956
2957
2958
2959
2960
2961
2962
2963
2964
2965
2966
2967
2968
2969
2970
2971
2972
2973
2974
2975
2976
2977
2978
2979
2980
2981
2982
2983
2984
2985
2986
2987
2988
2989
2990
2991
2992
2993
2994
2995
2996
2997
2998
2999
3000
3001
3002
3003
3004
3005
3006
3007
3008
3009
3010
3011
3012
3013
3014
3015
3016
3017
3018
3019
3020
3021
3022
3023
3024
3025
3026
3027
3028
3029
3030
3031
3032
3033
3034
3035
3036
3037
3038
3039
3040
3041
3042
3043
3044
3045
3046
3047
3048
3049
3050
3051
3052
3053
3054
3055
3056
3057
3058
3059
3060
3061
3062
3063
3064
3065
3066
3067
3068
3069
3070
3071
3072
3073
3074
3075
3076
3077
3078
3079
3080
3081
3082
3083
3084
3085
3086
3087
3088
3089
3090
3091
3092
3093
3094
3095
3096
3097
3098
3099
3100
3101
3102
3103
3104
3105
3106
3107
3108
3109
3110
3111
3112
3113
3114
3115
3116
3117
3118
3119
3120
3121
3122
3123
3124
3125
3126
3127
3128
3129
3130
3131
3132
3133
3134
3135
3136
3137
3138
3139
3140
3141
3142
3143
3144
3145
3146
3147
3148
3149
3150
3151
3152
3153
3154
3155
3156
3157
3158
3159
3160
3161
3162
3163
3164
3165
3166
3167
3168
3169
3170
3171
3172
3173
3174
3175
3176
3177
3178
3179
3180
3181
3182
3183
3184
3185
3186
3187
3188
3189
3190
3191
3192
3193
3194
3195
3196
3197
3198
3199
3200
3201
3202
3203
3204
3205
3206
3207
3208
3209
3210
3211
3212
3213
3214
3215
3216
3217
3218
3219
3220
3221
3222
3223
3224
3225
3226
3227
3228
3229
3230
3231
3232
3233
3234
3235
3236
3237
3238
3239
3240
3241
3242
3243
3244
3245
3246
3247
3248
3249
3250
3251
3252
3253
3254
3255
3256
3257
3258
3259
3260
3261
3262
3263
3264
3265
3266
3267
3268
3269
3270
3271
3272
3273
3274
3275
3276
3277
3278
3279
3280
3281
3282
3283
3284
3285
3286
3287
3288
3289
3290
3291
3292
3293
3294
3295
3296
3297
3298
3299
3300
3301
3302
3303
3304
3305
3306
3307
3308
3309
3310
3311
3312
3313
3314
3315
3316
3317
3318
3319
3320
3321
3322
3323
3324
3325
3326
3327
3328
3329
3330
3331
3332
3333
3334
3335
3336
3337
3338
3339
3340
3341
3342
3343
3344
3345
3346
3347
3348
3349
3350
3351
3352
3353
3354
3355
3356
3357
3358
3359
3360
3361
3362
3363
3364
3365
3366
3367
3368
3369
3370
3371
3372
3373
3374
3375
3376
3377
3378
3379
3380
3381
3382
3383
3384
3385
3386
3387
3388
3389
3390
3391
3392
3393
3394
3395
3396
3397
3398
3399
3400
3401
3402
3403
3404
3405
3406
3407
3408
3409
3410
3411
3412
3413
3414
3415
3416
3417
3418
3419
3420
3421
3422
3423
3424
3425
3426
3427
3428
3429
3430
3431
3432
3433
3434
3435
3436
3437
3438
3439
3440
3441
3442
3443
3444
3445
3446
3447
3448
3449
3450
3451
3452
3453
3454
3455
3456
3457
3458
3459
3460
3461
3462
3463
3464
3465
3466
3467
3468
3469
3470
3471
3472
3473
3474
3475
3476
3477
3478
3479
3480
3481
3482
3483
3484
3485
3486
3487
3488
3489
3490
3491
3492
3493
3494
3495
3496
3497
3498
3499
3500
3501
3502
3503
3504
3505
3506
3507
3508
3509
3510
3511
3512
3513
3514
3515
3516
3517
3518
3519
3520
3521
3522
3523
3524
3525
3526
3527
3528
3529
3530
3531
3532
3533
3534
3535
3536
3537
3538
3539
3540
3541
3542
3543
3544
3545
3546
3547
3548
3549
3550
3551
3552
3553
3554
3555
3556
3557
3558
3559
3560
3561
3562
3563
3564
3565
3566
3567
3568
3569
3570
3571
3572
3573
3574
3575
3576
3577
3578
3579
3580
3581
3582
3583
3584
3585
3586
3587
3588
3589
3590
3591
3592
3593
3594
3595
3596
3597
3598
3599
3600
3601
3602
3603
3604
3605
3606
3607
3608
3609
3610
3611
3612
3613
3614
# Copyright 2004-2011 H2 Group. Multiple-Licensed under the H2 License,
# Version 1.0, and under the Eclipse Public License, Version 1.0
# (http://h2database.com/html/license.html).
# Initial Developer: H2 Group
"SECTION","TOPIC","SYNTAX","TEXT","EXAMPLE"
"Commands (DML)","SELECT","
SELECT [ TOP term ] [ DISTINCT | ALL ] selectExpression [,...]
FROM tableExpression [,...] [ WHERE expression ]
[ GROUP BY expression [,...] ] [ HAVING expression ]
[ { UNION [ ALL ] | MINUS | EXCEPT | INTERSECT } select ] [ ORDER BY order [,...] ]
[ LIMIT expression [ OFFSET expression ] [ SAMPLE_SIZE rowCountInt ] ]
[ FOR UPDATE ]
","
Selects data from a table or multiple tables.
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.
LIMIT limits the number of rows returned by the query, OFFSET specified
how many rows to skip. SAMPLE_SIZE limits the number of rows read for
aggregate queries.
Multiple set operators (UNION, INTERSECT, MINUS, EXPECT) are evaluated
from left to right. For compatibility with other databases and future versions
of H2 please use parentheses.
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.
In this case, aggregate, GROUP BY, DISTINCT queries or joins
are not allowed in this case.
","
SELECT * FROM TEST;
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;
SELECT * FROM (SELECT ID, COUNT(*) FROM TEST
GROUP BY ID UNION SELECT NULL, COUNT(*) FROM TEST)
ORDER BY 1 NULLS LAST;
"
"Commands (DML)","INSERT","
INSERT INTO tableName [ ( columnName [,...] ) ]
{ VALUES { ( { DEFAULT | expression } [,...] ) } [,...] | [ DIRECT ] [ SORTED ] select }
","
Inserts a new row / new rows into a table.
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.
","
INSERT INTO TEST VALUES(1, 'Hello')
"
"Commands (DML)","UPDATE","
UPDATE tableName [ [ AS ] newTableAlias ]
SET { columnName= { DEFAULT | expression } } [,...]
[ WHERE expression ]
","
Updates data in a table.
","
UPDATE TEST SET NAME='Hi' WHERE ID=1;
UPDATE PERSON P SET NAME=(SELECT A.NAME FROM ADDRESS A WHERE A.ID=P.ID);
"
"Commands (DML)","DELETE","
DELETE FROM tableName [ WHERE expression ]
","
Deletes rows form a table.
","
DELETE FROM TEST WHERE ID=2
"
"Commands (DML)","BACKUP","
BACKUP TO fileNameString
","
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.
Admin rights are required to execute this command.
","
BACKUP TO 'backup.zip'
"
"Commands (DML)","CALL","
CALL expression
","
Calculates a simple expression.
","
CALL 15*25
"
"Commands (DML)","EXPLAIN","
EXPLAIN { [ PLAN FOR ] | ANALYZE } { select | insert | update | delete | merge }
","
Shows the execution plan for a statement.
When using EXPLAIN ANALYZE, the statement is actually executed, and the query plan
will include the actual row scan count for each table.
","
EXPLAIN SELECT * FROM TEST WHERE ID=1
"
"Commands (DML)","MERGE","
MERGE INTO tableName [ ( columnName [,...] ) ]
[ KEY ( columnName [,...] ) ]
{ VALUES { ( { DEFAULT | expression } [,...] ) } [,...] | select }
","
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
row per new row is affected, an exception is thrown. If the table contains an
auto-incremented key or identity column, and the row was updated, the generated
key is set to 0; otherwise it is set to the new key.
","
MERGE INTO TEST KEY(ID) VALUES(2, 'World')
"
"Commands (DML)","RUNSCRIPT","
RUNSCRIPT FROM fileNameString [ scriptCompression ]
[ CIPHER cipher PASSWORD string ] [ CHARSET charsetString ]
","
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.
Instead of a file name, an URL may be used.
To read a stream from the classpath, use the prefix 'classpath:'.
The compression algorithm must match the one used when creating the script. When
using encryption, only DEFLATE and LZF are supported (LZF is faster but uses more space).
Instead of a file, an URL may be used.
Admin rights are required to execute this command.
","
RUNSCRIPT FROM 'backup.sql'
"
"Commands (DML)","SCRIPT","
SCRIPT [ SIMPLE ] [ NODATA ] [ NOPASSWORDS ] [ NOSETTINGS ]
[ DROP ] [ BLOCKSIZE blockSizeInt ]
[ TO fileNameString [ scriptCompression ]
[ CIPHER cipher PASSWORD string ] ]
[ CHARSET charsetString ]
","
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.
If no file name is specified, the
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.
If a file name is specified, then the whole
script (including insert statements) is written to this file, and a result set
without the insert statements is returned. When using encryption, only DEFLATE
and LZF are supported (LZF is faster but uses more space).
The password must be in single quotes; it is case sensitive and can contain spaces.
This command locks objects while it is running.
","
SCRIPT NODATA
"
"Commands (DML)","SHOW","
SHOW { SCHEMAS | TABLES [ FROM schemaName ] |
COLUMNS FROM tableName [ FROM schemaName ] }
","
Lists the schemas, tables, or the columns of a table.
","
SHOW TABLES
"
"Commands (DDL)","ALTER INDEX RENAME","
ALTER INDEX indexName RENAME TO newIndexName
","
Renames an index.
This command commits an open transaction.
","
ALTER INDEX IDXNAME RENAME TO IDX_TEST_NAME
"
"Commands (DDL)","ALTER SCHEMA RENAME","
ALTER SCHEMA schema RENAME TO newSchemaName
","
Renames a schema.
This command commits an open transaction.
","
ALTER SCHEMA TEST RENAME TO PRODUCTION
"
"Commands (DDL)","ALTER SEQUENCE","
ALTER SEQUENCE sequenceName [ RESTART WITH long ] [ INCREMENT BY long ]
","
Changes the next value and the increment of a sequence.
This command does not commit the current transaction; however the new value is used by other
transactions immediately, and rolling back this command has no effect.
","
ALTER SEQUENCE SEQ_ID RESTART WITH 1000
"
"Commands (DDL)","ALTER TABLE ADD","
ALTER TABLE tableName ADD name dataType [ DEFAULT expression ]
[ [ NOT ] NULL ] [ AUTO_INCREMENT | IDENTITY ] [ BEFORE columnName ]
","
Adds a new column to a table.
This command commits an open transaction.
","
ALTER TABLE TEST ADD CREATEDATE TIMESTAMP
"
"Commands (DDL)","ALTER TABLE ADD CONSTRAINT","
ALTER TABLE tableName ADD constraint [ CHECK | NOCHECK ]
","
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).
The required indexes are automatically created if they don't exist yet.
It is not possible to disable checking for unique constraints.
This command commits an open transaction.
","
ALTER TABLE TEST ADD CONSTRAINT NAME_UNIQUE UNIQUE(NAME)
"
"Commands (DDL)","ALTER TABLE ALTER","
ALTER TABLE tableName ALTER COLUMN columnName
{ { dataType [ DEFAULT expression ] [ [ NOT ] NULL ] [ AUTO_INCREMENT | IDENTITY ] }
| { RENAME TO name }
| { RESTART WITH long }
| { SELECTIVITY int }
| { SET DEFAULT expression }
| { SET NULL }
| { SET NOT NULL } }
","
Changes the data type of a column, rename a column,
change the identity value, or change the selectivity.
Changing the data type fails if the data can not be converted.
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.
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.
SET DEFAULT changes the default value of a column.
SET NULL sets a column to allow NULL. The row may not be part of a primary key.
Single column indexes on this column are dropped.
SET NOT NULL sets a column to not allow NULL. Rows may not contains NULL in this column.
This command commits an open transaction.
","
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;
"
"Commands (DDL)","ALTER TABLE DROP COLUMN","
ALTER TABLE tableName DROP COLUMN columnName
","
Removes a column from a table.
This command commits an open transaction.
","
ALTER TABLE TEST DROP COLUMN NAME
"
"Commands (DDL)","ALTER TABLE DROP CONSTRAINT","
ALTER TABLE tableName DROP { CONSTRAINT [ IF EXISTS ] constraintName | PRIMARY KEY }
","
Removes a constraint or a primary key from a table.
This command commits an open transaction.
","
ALTER TABLE TEST DROP CONSTRAINT UNIQUE_NAME
"
"Commands (DDL)","ALTER TABLE SET","
ALTER TABLE tableName SET REFERENTIAL_INTEGRITY
{ FALSE | TRUE [ CHECK | NOCHECK ] }
","
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.
This command commits an open transaction.
","
ALTER TABLE TEST SET REFERENTIAL_INTEGRITY FALSE
"
"Commands (DDL)","ALTER TABLE RENAME","
ALTER TABLE tableName RENAME TO newName
","
Renames a table.
This command commits an open transaction.
","
ALTER TABLE TEST RENAME TO MY_DATA
"
"Commands (DDL)","ALTER USER ADMIN","
ALTER USER userName ADMIN { TRUE | FALSE }
","
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.
This command commits an open transaction.
","
ALTER USER TOM ADMIN TRUE
"
"Commands (DDL)","ALTER USER RENAME","
ALTER USER userName RENAME TO newUserName
","
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.
Admin rights are required to execute this command.
This command commits an open transaction.
","
ALTER USER TOM RENAME TO THOMAS
"
"Commands (DDL)","ALTER USER SET PASSWORD","
ALTER USER userName SET { PASSWORD string | SALT bytes HASH bytes }
","
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.
This command commits an open transaction.
","
ALTER USER SA SET PASSWORD 'rioyxlgt'
"
"Commands (DDL)","ALTER VIEW","
ALTER VIEW viewName RECOMPILE
","
Recompiles a view after the underlying tables have been changed or created.
This command is used for views created using CREATE FORCE VIEW.
This command commits an open transaction.
","
ALTER VIEW ADDRESS_VIEW RECOMPILE
"
"Commands (DDL)","ANALYZE","
ANALYZE [ SAMPLE_SIZE rowCountInt ]
","
Updates the selectivity statistics of all tables. The selectivity is used by the
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.
This command commits an open transaction.
","
ANALYZE SAMPLE_SIZE 1000
"
"Commands (DDL)","COMMENT","
COMMENT ON
{ { COLUMN [ schemaName. ] tableName.columnName }
| { { TABLE | VIEW | CONSTANT | CONSTRAINT | ALIAS | INDEX | ROLE
| SCHEMA | SEQUENCE | TRIGGER | USER | DOMAIN } [ schemaName. ] objectName } }
IS expression
","
Sets the comment of a database object. Use NULL to remove the comment.
Admin rights are required to execute this command.
This command commits an open transaction.
","
COMMENT ON TABLE TEST IS 'Table used for testing'
"
"Commands (DDL)","CREATE AGGREGATE","
CREATE AGGREGATE [ IF NOT EXISTS ] newAggregateName FOR className
","
Creates a new user-defined aggregate function. The method name must be the full
qualified class name. The class must implement the interface
""org.h2.api.AggregateFunction"".
Admin rights are required to execute this command.
This command commits an open transaction.
","
CREATE AGGREGATE MEDIAN FOR ""com.acme.db.Median""
"
"Commands (DDL)","CREATE ALIAS","
CREATE ALIAS [ IF NOT EXISTS ] newFunctionAliasName [ DETERMINISTIC ]
{ FOR classAndMethodName | AS sourceCodeString }
","
Creates a new function alias. Deterministic functions must always return the
same value for the same parameters. The result of such functions is cached if possible.
The method name must be the full qualified class and method name,
and may optionally include the parameter classes as in
""java.lang.Integer.parseInt(java.lang.String, int)"". The class and the method
must both be public, and the method must be static. 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).
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.
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
as dollar quoted text to avoid escaping problems. If import statements are used,
then the tag @CODE must be added before the method.
If the method throws an SQLException, it is directly re-thrown to the calling application;
all other exceptions are first converted to a SQLException.
If the first parameter of the Java function is a ""java.sql.Connection"", then a
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.
Admin rights are required to execute this command.
This command commits an open transaction.
","
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');
CREATE ALIAS REVERSE AS $$ String reverse(String s) { return new StringBuilder(s).reverse().toString(); } $$;
CALL REVERSE('Test');
"
"Commands (DDL)","CREATE CONSTANT","
CREATE CONSTANT [ IF NOT EXISTS ] newConstantName VALUE expression
","
Creates a new constant.
This command commits an open transaction.
","
CREATE CONSTANT ONE VALUE 1
"
"Commands (DDL)","CREATE DOMAIN","
CREATE DOMAIN [ IF NOT EXISTS ] newDomainName AS dataType
[ DEFAULT expression ] [ [ NOT ] NULL ] [ SELECTIVITY selectivity ]
[ CHECK condition ]
","
Creates a new data type (domain). The check condition must evaluate to true or
to NULL (to prevent NULL, use NOT NULL). In the condition, the term VALUE refers
to the value being tested.
Domains are usable within the whole database. They can not be created in a specific schema.
This command commits an open transaction.
","
CREATE DOMAIN EMAIL AS VARCHAR(255) CHECK (POSITION('@', VALUE) > 1)
"
"Commands (DDL)","CREATE INDEX","
CREATE { [ UNIQUE ] [ HASH ] INDEX [ IF NOT EXISTS ] newIndexName
| PRIMARY KEY [ HASH ] }
ON tableName ( indexColumn [,...] )
","
Creates a new index.
This command commits an open transaction.
Hash indexes are meant for in-memory databases and memory tables (CREATE MEMORY TABLE).
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).
Non-unique keys are supported.
","
CREATE INDEX IDXNAME ON TEST(NAME)
"
"Commands (DDL)","CREATE LINKED TABLE","
CREATE [ [ GLOBAL | LOCAL ] TEMPORARY ] LINKED TABLE [ IF NOT EXISTS ]
name ( driverString, urlString, userString, passwordString,
[ originalSchemaString, ] originalTableString ) [ EMIT UPDATES | READONLY ]
","
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.
Usually, for update statements, the old rows are deleted first and then the new
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
work. Linked tables to the same database share one connection.
If a query is used instead of the original table name, the table is read only.
Queries must be enclosed in parenthesis: ""(SELECT * FROM ORDERS)"".
To use JNDI to get the connection, the driver class must be a
javax.naming.Context (for example ""javax.naming.InitialContext""), and the URL must
be the resource name (for example ""java:comp/env/jdbc/Test"").
Admin rights are required to execute this command.
This command commits an open transaction.
","
CREATE LINKED TABLE LINK('org.h2.Driver', 'jdbc:h2:test2', 'sa', 'sa', 'TEST');
CREATE LINKED TABLE LINK('', 'jdbc:h2:test2', 'sa', 'sa',
'(SELECT * FROM TEST WHERE ID>0)');
CREATE LINKED TABLE LINK('javax.naming.InitialContext',
'java:comp/env/jdbc/Test', NULL, NULL, '(SELECT * FROM TEST WHERE ID>0)');
"
"Commands (DDL)","CREATE ROLE","
CREATE ROLE [ IF NOT EXISTS ] newRoleName
","
Creates a new role.
This command commits an open transaction.
","
CREATE ROLE READONLY
"
"Commands (DDL)","CREATE SCHEMA","
CREATE SCHEMA [ IF NOT EXISTS ] name [ AUTHORIZATION ownerUserName ]
","
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.
Specifying the owner currently has no effect.
This command commits an open transaction.
","
CREATE SCHEMA TEST_SCHEMA AUTHORIZATION SA
"
"Commands (DDL)","CREATE SEQUENCE","
CREATE SEQUENCE [ IF NOT EXISTS ] newSequenceName [ START WITH long ]
[ INCREMENT BY long ] [ CACHE long ]
","
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. 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.
This command commits an open transaction.
","
CREATE SEQUENCE SEQ_ID
"
"Commands (DDL)","CREATE TABLE","
CREATE [ CACHED | MEMORY ] [ TEMP | [ GLOBAL | LOCAL ] TEMPORARY ]
TABLE [ IF NOT EXISTS ] name
{ { ( { columnDefinition | constraint } [,...] ) [ AS select ] }
| { AS select } }
[ ENGINE tableEngineName ] [ TRANSACTIONAL ] [ NOT PERSISTENT ]
","
Creates a new table.
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,
that means memory tables should not get too large.
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,
unless the temporary table is created using CREATE CACHED TABLE.
The ENGINE option is only required when custom table implementations are used.
The table engine class must implement the interface ""org.h2.api.TableEngine"".
Tables with the NOT PERSISTENT modifier are kept fully in memory, and all
rows are lost when the database is closed.
This command commits an open transaction, except when using
TRANSACTIONAL (only supported for temporary tables).
","
CREATE TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR(255))
"
"Commands (DDL)","CREATE TRIGGER","
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
","
Creates a new trigger. The trigger class must be public. 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).
BEFORE triggers are called after data conversion is made, default values are set,
null and length constraint checks have been made;
but before other constraints have been checked.
If there are multiple triggers, the order in which they are called is undefined.
Only row based AFTER trigger can be called on rollback.
Exceptions that occur within such triggers are ignored.
INSTEAD OF triggers are implicitly row based and behave like BEFORE triggers.
Only the first such trigger is called. Such triggers on views are supported.
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.
Committing or rolling back a transaction within a trigger is not allowed, except for SELECT triggers.
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.
This command commits an open transaction.
","
CREATE TRIGGER TRIG_INS BEFORE INSERT ON TEST FOR EACH ROW CALL ""MyTrigger""
"
"Commands (DDL)","CREATE USER","
CREATE USER [ IF NOT EXISTS ] newUserName
{ PASSWORD string | SALT bytes HASH bytes } [ ADMIN ]
","
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.
Admin rights are required to execute this command.
This command commits an open transaction.
","
CREATE USER GUEST PASSWORD 'abc'
"
"Commands (DDL)","CREATE VIEW","
CREATE [ OR REPLACE ] [ FORCE ] VIEW [ IF NOT EXISTS ] newViewName
[ ( columnName [,...] ) ] AS select
","
Creates a new view. If the force option is used, then the view is created even
if the underlying table(s) don't exist.
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.
Admin rights are required to execute this command.
This command commits an open transaction.
","
CREATE VIEW TEST_VIEW AS SELECT * FROM TEST WHERE ID < 100
"
"Commands (DDL)","DROP AGGREGATE","
DROP AGGREGATE [ IF EXISTS ] aggregateName
","
Drops an existing user-defined aggregate function.
Admin rights are required to execute this command.
This command commits an open transaction.
","
CREATE AGGREGATE MEDIAN
"
"Commands (DDL)","DROP ALIAS","
DROP ALIAS [ IF EXISTS ] existingFunctionAliasName
","
Drops an existing function alias.
Admin rights are required to execute this command.
This command commits an open transaction.
","
CREATE ALIAS MY_SQRT
"
"Commands (DDL)","DROP ALL OBJECTS","
DROP ALL OBJECTS [ DELETE FILES ]
","
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
back.
Admin rights are required to execute this command.
","
DROP ALL OBJECTS
"
"Commands (DDL)","DROP CONSTANT","
DROP CONSTANT [ IF EXISTS ] constantName
","
Drops a constant.
This command commits an open transaction.
","
DROP CONSTANT ONE
"
"Commands (DDL)","DROP DOMAIN","
DROP DOMAIN [ IF EXISTS ] domainName
","
Drops a data type (domain).
This command commits an open transaction.
","
DROP DOMAIN EMAIL
"
"Commands (DDL)","DROP INDEX","
DROP INDEX [ IF EXISTS ] indexName
","
Drops an index.
This command commits an open transaction.
","
DROP INDEX IF EXISTS IDXNAME
"
"Commands (DDL)","DROP ROLE","
DROP ROLE [ IF EXISTS ] roleName
","
Drops a role.
This command commits an open transaction.
","
DROP ROLE READONLY
"
"Commands (DDL)","DROP SCHEMA","
DROP SCHEMA [ IF EXISTS ] schemaName
","
Drops a schema.
This command commits an open transaction.
","
DROP SCHEMA TEST_SCHEMA
"
"Commands (DDL)","DROP SEQUENCE","
DROP SEQUENCE [ IF EXISTS ] sequenceName
","
Drops a sequence.
This command commits an open transaction.
","
DROP SEQUENCE SEQ_ID
"
"Commands (DDL)","DROP TABLE","
DROP TABLE [ IF EXISTS ] tableName [,...] [ CASCADE | RESTRICT ]
","
Drops an existing table, or a list of tables.
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.
This command commits an open transaction.
","
DROP TABLE TEST
"
"Commands (DDL)","DROP TRIGGER","
DROP TRIGGER [ IF EXISTS ] triggerName
","
Drops an existing trigger.
This command commits an open transaction.
","
DROP TRIGGER TRIG_INS
"
"Commands (DDL)","DROP USER","
DROP USER [ IF EXISTS ] userName
","
Drops a user. The current user cannot be dropped.
For compatibility, only unquoted or uppercase user names are allowed.
Admin rights are required to execute this command.
This command commits an open transaction.
","
DROP USER TOM
"
"Commands (DDL)","DROP VIEW","
DROP VIEW [ IF EXISTS ] viewName [ RESTRICT | CASCADE ]
","
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.
This command commits an open transaction.
","
DROP VIEW TEST_VIEW
"
"Commands (DDL)","TRUNCATE TABLE","
TRUNCATE TABLE tableName
","
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).
Linked tables can't be truncated.
This command commits an open transaction.
","
TRUNCATE TABLE TEST
"
"Commands (Other)","CHECKPOINT","
CHECKPOINT
","
Flushes the data to disk and switches to a new transaction log if possible.
Admin rights are required to execute this command.
","
CHECKPOINT
"
"Commands (Other)","CHECKPOINT SYNC","
CHECKPOINT SYNC
","
Flushes the data to disk and and forces all system buffers be written
to the underlying device.
Admin rights are required to execute this command.
","
CHECKPOINT SYNC
"
"Commands (Other)","COMMIT","
COMMIT [ WORK ]
","
Commits a transaction.
","
COMMIT
"
"Commands (Other)","COMMIT TRANSACTION","
COMMIT TRANSACTION transactionName
","
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.
","
COMMIT TRANSACTION XID_TEST
"
"Commands (Other)","GRANT RIGHT","
GRANT { SELECT | INSERT | UPDATE | DELETE | ALL } [,...] ON
tableName [,...] TO { PUBLIC | userName | roleName }
","
Grants rights for a table to a user or role.
Admin rights are required to execute this command.
This command commits an open transaction.
","
GRANT SELECT ON TEST TO READONLY
"
"Commands (Other)","GRANT ROLE","
GRANT roleName TO { PUBLIC | userName | roleName }
","
Grants a role to a user or role.
Admin rights are required to execute this command.
This command commits an open transaction.
","
GRANT READONLY TO PUBLIC
"
"Commands (Other)","HELP","
HELP [ anything [...] ]
","
Displays the help pages of SQL commands or keywords.
","
HELP SELECT
"
"Commands (Other)","PREPARE COMMIT","
PREPARE COMMIT newTransactionName
","
Prepares committing a transaction.
This command is part of the 2-phase-commit protocol.
","
PREPARE COMMIT XID_TEST
"
"Commands (Other)","REVOKE RIGHT","
REVOKE { SELECT | INSERT | UPDATE | DELETE | ALL } [,...] ON
tableName [,...] FROM { PUBLIC | userName | roleName }
","
Removes rights for a table from a user or role.
Admin rights are required to execute this command.
This command commits an open transaction.
","
REVOKE SELECT ON TEST FROM READONLY
"
"Commands (Other)","REVOKE ROLE","
REVOKE roleName FROM { PUBLIC | userName | roleName }
","
Removes a role from a user or role.
Admin rights are required to execute this command.
This command commits an open transaction.
","
REVOKE READONLY FROM TOM
"
"Commands (Other)","ROLLBACK","
ROLLBACK [ TO SAVEPOINT savepointName ]
","
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
","
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.
","
ROLLBACK TRANSACTION XID_TEST
"
"Commands (Other)","SAVEPOINT","
SAVEPOINT savepointName
","
Create a new savepoint. See also ROLLBACK.
Savepoints are only valid until the transaction is committed or rolled back.
","
SAVEPOINT HALF_DONE
"
"Commands (Other)","SET @","
SET @variableName [ = ] expression
","
Updates a user-defined variable.
This command does not commit a transaction, and rollback does not affect it.
","
SET @TOTAL=0
"
"Commands (Other)","SET ALLOW_LITERALS","
SET ALLOW_LITERALS { NONE | ALL | NUMBERS }
","
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).
See also CREATE CONSTANT.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
This setting can be appended to the database URL: ""jdbc:h2:test;ALLOW_LITERALS=NONE""
","
SET ALLOW_LITERALS NONE
"
"Commands (Other)","SET AUTOCOMMIT","
SET AUTOCOMMIT { TRUE | ON | FALSE | OFF }
","
Switches auto commit on or off.
This setting can be appended to the database URL: ""jdbc:h2:test;AUTOCOMMIT=OFF"" -
however this will not work as expected when using a connection pool
(the connection pool manager will re-enable autocommit when returning
the connection to the pool, so autocommit will only be disabled the first
time the connection is used.
","
SET AUTOCOMMIT OFF
"
"Commands (Other)","SET CACHE_SIZE","
SET CACHE_SIZE int
","
Sets the size of the cache in KB (each KB being 1024 bytes) for the current database.
The default value is 16384 (16 MB). The value is rounded to the next higher power of two.
Depending on the virtual machine, the actual memory required may be higher.
This setting is persistent and affects all connections as there is only one cache per database.
Using a very small value (specially 0) will reduce performance a lot.
This setting only affects the database engine (the server in a client/server environment).
It has no effect for in-memory databases.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
This setting can be appended to the database URL: ""jdbc:h2:test;CACHE_SIZE=8192""
","
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
server is not responding).
This command is effective immediately, but does not commit an open transaction.
","
SET CLUSTER ''
"
"Commands (Other)","SET COLLATION","
SET [ DATABASE ] COLLATION
{ OFF | collationName [ STRENGTH { PRIMARY | SECONDARY | TERTIARY | IDENTICAL } ] }
","
Sets the collation used for comparing strings. This command can only be executed
if there are no tables defined. See ""java.text.Collator"" for details about
STRENGTH.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
","
SET COLLATION ENGLISH
"
"Commands (Other)","SET COMPRESS_LOB","
SET COMPRESS_LOB { NO | LZF | DEFLATE }
","
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.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
","
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
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).
This setting can be appended to the database URL: ""jdbc:h2:test;DATABASE_EVENT_LISTENER='sample.MyListener'""
","
SET DATABASE_EVENT_LISTENER 'sample.MyListener'
"
"Commands (Other)","SET DB_CLOSE_DELAY","
SET DB_CLOSE_DELAY int
","
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. 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.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
This setting can be appended to the database URL: ""jdbc:h2:test;DB_CLOSE_DELAY=-1""
","
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
for the new sessions. The default value for this setting is 1000 (one second).
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
","
SET DEFAULT_LOCK_TIMEOUT 5000
"
"Commands (Other)","SET DEFAULT_TABLE_TYPE","
SET DEFAULT_TABLE_TYPE { MEMORY | CACHED }
","
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
the data is still stored in the database file. The size of memory tables is
limited by the memory. The default is CACHED.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
It has no effect for in-memory databases.
","
SET DEFAULT_TABLE_TYPE MEMORY
"
"Commands (Other)","SET EXCLUSIVE","
SET EXCLUSIVE { 0 | 1 | 2 }
","
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.
Admin rights are required to execute this command.
This command commits an open transaction.
","
SET EXCLUSIVE 1
"
"Commands (Other)","SET IGNORECASE","
SET IGNORECASE { TRUE | FALSE }
","
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.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
","
SET IGNORECASE TRUE
"
"Commands (Other)","SET LOG","
SET LOG int
","
Sets the transaction log mode. The values 0, 1, and 2 are supported, the default is 2.
This setting affects all connections.
LOG 0 means the transaction log is disabled completely. It is the fastest mode,
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.
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
against power failure is required, but the data must be protected against killing the process.
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
file system, this will also protect against power failure in the majority if cases.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is not persistent.
This setting can be appended to the database URL: ""jdbc:h2:test;LOG=0""
","
SET LOG 1
"
"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
(READ_COMMITTED). This setting affects all connections.
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).
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
This setting can be appended to the database URL: ""jdbc:h2:test;LOCK_MODE=3""
","
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
value for this setting is 1000 (one second).
This command does not commit a transaction, and rollback does not affect it.
This setting can be appended to the database URL: ""jdbc:h2:test;LOCK_TIMEOUT=10000""
","
SET LOCK_TIMEOUT 1000
"
"Commands (Other)","SET MAX_LENGTH_INPLACE_LOB","
SET MAX_LENGTH_INPLACE_LOB int
","
Sets the maximum size of an in-place LOB object. LOB objects larger that this
size are stored in a separate file, otherwise stored directly in the database
(in-place). The default max size is 1024.
This setting has no effect for in-memory databases.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
","
SET MAX_LENGTH_INPLACE_LOB 128
"
"Commands (Other)","SET MAX_LOG_SIZE","
SET MAX_LOG_SIZE int
","
Sets the maximum size of the transaction log, in megabytes. If the log exceeds the
limit, a new stream is created. Old streams (that are not used for recovery) are
freed automatically. The default max size is 16 MB.
This setting has no effect for in-memory databases.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
","
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
are read, then the rows are buffered to disk. The default value is 10000.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
It has no effect for in-memory databases.
","
SET MAX_MEMORY_ROWS 1000
"
"Commands (Other)","SET MAX_MEMORY_UNDO","
SET MAX_MEMORY_UNDO int
","
The maximum number of undo records per a session that are kept in-memory.
If a transaction is larger, the records are buffered to disk.
The default value is 50000.
Changes to tables without a primary key can not be buffered to disk.
This setting is not supported when using multi-version concurrency.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting is persistent.
It has no effect for in-memory databases.
","
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
operation. The default max size is 100000. 0 means no limit.
This setting is not persistent.
Admin rights are required to execute this command.
It has no effect for in-memory databases.
This setting can be appended to the database URL: ""jdbc:h2:test;MAX_OPERATION_MEMORY=10000""
","
SET MAX_OPERATION_MEMORY 0
"
"Commands (Other)","SET MODE","
SET MODE { REGULAR | DB2 | DERBY | HSQLDB | MSSQLSERVER | MYSQL | ORACLE | POSTGRESQL }
","
Changes to another database compatibility mode. For details, see Compatibility
Modes in the feature section.
This setting is not persistent.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting can be appended to the database URL: ""jdbc:h2:test;MODE=MYSQL""
","
SET MODE HSQLDB
"
"Commands (Other)","SET MULTI_THREADED","
SET MULTI_THREADED { 0 | 1 }
","
Enabled (1) or disabled (0) multi-threading inside the database engine. By
default, this setting is disabled. Currently, enabling this is experimental
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.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting can be appended to the database URL: ""jdbc:h2:test;MULTI_THREADED=1""
","
SET MULTI_THREADED 1
"
"Commands (Other)","SET OPTIMIZE_REUSE_RESULTS","
SET OPTIMIZE_REUSE_RESULTS { 0 | 1 }
","
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
the tables was changed. This option is enabled by default.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting can be appended to the database URL: ""jdbc:h2:test;OPTIMIZE_REUSE_RESULTS=0""
","
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.
This command commits an open transaction.
","
SET PASSWORD 'abcstzri!.5'
"
"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
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.
","
SET QUERY_TIMEOUT 10000
"
"Commands (Other)","SET REFERENTIAL_INTEGRITY","
SET REFERENTIAL_INTEGRITY { TRUE | FALSE }
","
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
for one table.
This setting is not persistent.
This command commits an open transaction.
Admin rights are required to execute this command.
","
SET REFERENTIAL_INTEGRITY FALSE
"
"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.
This command commits an open transaction.
","
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
connections is PUBLIC.
This command does not commit a transaction, and rollback does not affect it.
This setting can be appended to the database URL: ""jdbc:h2:test;SCHEMA=ABC""
","
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
connections is PUBLIC.
This command does not commit a transaction, and rollback does not affect it.
This setting can be appended to the database URL: ""jdbc:h2:test;SCHEMA_SEARCH_PATH=ABC,DEF""
","
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
disabled).
This command does not commit a transaction, and rollback does not affect it.
This setting can be appended to the database URL: ""jdbc:h2:test;THROTTLE=50""
","
SET THROTTLE 200
"
"Commands (Other)","SET TRACE_LEVEL","
SET { TRACE_LEVEL_FILE | TRACE_LEVEL_SYSTEM_OUT } int
","
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.
To use SLF4J, append "";TRACE_LEVEL_FILE=4"" to the database URL when opening the database.
This setting is not persistent.
Admin rights are required to execute this command.
This command does not commit a transaction, and rollback does not affect it.
This setting can be appended to the database URL: ""jdbc:h2:test;TRACE_LEVEL_SYSTEM_OUT=3""
","
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.
This setting is persistent.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting can be appended to the database URL: ""jdbc:h2:test;TRACE_MAX_FILE_SIZE=3""
","
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.
This command commits an open transaction.
","
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.
This setting is persistent. The default is 500 ms.
Admin rights are required to execute this command.
This command commits an open transaction.
This setting can be appended to the database URL: ""jdbc:h2:test;WRITE_DELAY=0""
","
SET WRITE_DELAY 2000
"
"Commands (Other)","SHUTDOWN","
SHUTDOWN [ IMMEDIATELY | COMPACT | DEFRAG ]
","
This statement closes all open connections to the database and closes the
database. This command is usually not required, as the database is
closed automatically when the last connection to it is closed.
If no option is used, then the database is closed normally.
All connections are closed, open transactions are rolled back.
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,
but only for at most the time defined by the system property ""h2.maxCompactTime"" (see there).
SHUTDOWN IMMEDIATELY closes the database files without any cleanup and without compacting.
SHUTDOWN DEFRAG re-orders the pages when closing the database so that table scans are faster.
Admin rights are required to execute this command.
","
SHUTDOWN COMPACT
"
"Other Grammar","Alias","
name
","
An alias is a name that is only valid in the context of the statement.
","
A
"
"Other Grammar","And Condition","
condition [ { AND condition } [...] ]
","
Value or condition.
","
ID=1 AND NAME='Hi'
"
"Other Grammar","Array","
( expression [,...] )
","
An array of values.
","
(1, 2)
"
"Other Grammar","Boolean","
TRUE | FALSE
","
A boolean value.
","
TRUE
"
"Other Grammar","Bytes","
X'hex'
","
A binary value. The hex value is not case sensitive.
","
X'01FF'
"
"Other Grammar","Case","
CASE expression { WHEN expression THEN expression } [...]
[ ELSE expression ] END
","
Returns the first expression where the value is equal to the test expression. If
no else part is specified, return NULL.
","
CASE CNT WHEN 0 THEN 'No' WHEN 1 THEN 'One' ELSE 'Some' END
"
"Other Grammar","Case When","
CASE { WHEN expression THEN expression} [...]
[ ELSE expression ] END
","
Returns the first expression where the condition is true. If no else part is
specified, return NULL.
","
CASE WHEN CNT<10 THEN 'Low' ELSE 'High' END
"
"Other Grammar","Cipher","
{ AES | XTEA }
","
Two algorithms are supported: AES (AES-128) and XTEA (using 32 rounds).
XTEA is a bit faster than AES in some environments, but AES is more secure.
","
AES
"
"Other Grammar","Column Definition","
columnName dataType { DEFAULT expression | AS computedColumnExpression } [ [ NOT ] NULL ]
[ { AUTO_INCREMENT | IDENTITY } [ ( startInt [, incrementInt ] ) ] ]
[ SELECTIVITY selectivity ] [ COMMENT expression ]
[ PRIMARY KEY [ HASH ] | UNIQUE ] [ CHECK condition ]
","
Default expressions are used if no explicit value was used when adding a row.
The computed column expression is evaluated and assigned whenever the row changes.
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).
","
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);
"
"Other Grammar","Comments","
-- anythingUntilEndOfLine | // anythingUntilEndOfLine | /* anythingUntilEndComment */
","
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.
","
// This is a comment
"
"Other Grammar","Compare","
<> | <= | >= | = | < | > | !=
","
Comparison operator. The operator != is the same as <>.
","
<>
"
"Other Grammar","Condition","
operand [ conditionRightHandSide ] | NOT condition | EXISTS ( select )
","
Boolean value or condition.
","
ID<>2
"
"Other Grammar","Condition Right Hand Side","
compare { { { ALL | ANY | SOME } ( select ) } | operand }
| IS [ NOT ] NULL
| IS [ NOT ] [ DISTINCT FROM ] operand
| BETWEEN operand AND operand
| IN ( { select | expression [,...] } )
| [ NOT ] LIKE operand [ ESCAPE string ]
| [ NOT ] REGEXP operand
","
The right hand side of a condition.
The conditions IS [ NOT ] and IS [ NOT ] DISTINCT FROM are NULL-safe, meaning
NULL is considered the same as NULL, and the condition never evaluates to NULL.
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).
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.
When comparing with REGEXP, regular expression matching is used.
See Java ""Matcher.find"" for details.
","
LIKE 'Jo%'
"
"Other Grammar","Constraint","
[ constraintNameDefinition ] {
CHECK expression | UNIQUE ( columnName [,...] )
| referentialConstraint }
| PRIMARY KEY [ HASH ] ( columnName [,...] )
","
Defines a constraint.
The check condition must evaluate to TRUE, FALSE or NULL.
TRUE and NULL mean the operation is to be permitted,
and FALSE means the operation is to be rejected.
To prevent NULL in a column, use NOT NULL instead of a check constraint.
","
PRIMARY KEY(ID, NAME)
"
"Other Grammar","Constraint Name Definition","
CONSTRAINT [ IF NOT EXISTS ] newConstraintName
","
Defines a constraint name.
","
CONSTRAINT CONST_ID
"
"Other Grammar","Csv Options","
charsetString [, fieldSepString [, fieldDelimString [, escString [, nullString]]]]]
| optionString
","
Optional parameters for CSVREAD and CSVWRITE.
Instead of setting the options one by one, all options can be
combined into a space separated key-value pairs, as follows:
'charset=UTF-8 escape="" fieldDelimiter="" fieldSeparator=, ' ||
'lineComment=# lineSeparator=\n null= rowSeparator='.
The following options are supported:
charset, escape, fieldDelimiter, fieldSeparator,
lineComment (# for H2 version 1.2, disabled for H2 version 1.3),
lineSeparator, null, rowSeparator (not set by default).
The options text is encoded like a Java string.
","
CALL CSVWRITE('test2.csv', 'SELECT * FROM TEST', 'UTF-8', '|');
CALL CSVWRITE('test2.csv', 'SELECT * FROM TEST', 'charset=UTF-8 fieldSeparator=|');
"
"Other Grammar","Data Type","
intType | booleanType | tinyintType | smallintType | bigintType | identityType
| decimalType | doubleType | realType | dateType | timeType | timestampType
| binaryType | otherType | varcharType | varcharIgnorecaseType | charType
| blobType | clobType | uuidType | arrayType
","
A data type definition.
","
INT
"
"Other Grammar","Date","
DATE 'yyyy-MM-dd'
","
A date literal. The limitations are the same as for the Java data type
""java.sql.Date"", but for compatibility with other databases the suggested minimum
and maximum years are 0001 and 9999.
","
DATE '2004-12-31'
"
"Other Grammar","Decimal","
[ + | - ] number [ . number ]
","
Number with fixed precision and scale.
","
-1600.05
"
"Other Grammar","Digit","
0-9
","
A digit.
","
0
"
"Other Grammar","Dollar Quoted String","
$$anythingExceptTwoDollarSigns$$
","
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.
","
$$John's car$$
"
"Other Grammar","Double","
[ + | - ] { { number [ . number ] } | { . number } } [ E [ + | - ] expNumber [...] ] ]
","
The limitations are the same as for the Java data type Double.
","
-1.4e-10
"
"Other Grammar","Expression","
andCondition [ { OR andCondition } [...] ]
","
Value or condition.
","
ID=1 OR NAME='Hi'
"
"Other Grammar","Factor","
term [ { { * | / } term } [...] ]
","
A value or a numeric factor.
","
ID * 10
"
"Other Grammar","Hex","
{ { digit | a-f | A-F } { digit | a-f | A-F } } [...]
","
The hexadecimal representation of a number or of bytes. Two characters are one
byte.
","
cafe
"
"Other Grammar","Hex Number","
[ + | - ] 0x hex
","
A number written in hexadecimal notation.
","
0xff
"
"Other Grammar","Index Column","
columnName [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
","
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.
","
NAME
"
"Other Grammar","Int","
[ + | - ] number
","
The maximum integer number is 2147483647, the minimum is -2147483648.
","
10
"
"Other Grammar","Long","
[ + | - ] number
","
Long numbers are between -9223372036854775808 and 9223372036854775807.
","
100000
"
"Other Grammar","Name","
{ { A-Z|_ } [ { A-Z|_|0-9 } [...] ] } | quotedName
","
Names are not case sensitive. There is no maximum name length.
","
TEST
"
"Other Grammar","Null","
NULL
","
NULL is a value without data type and means 'unknown value'.
","
NULL
"
"Other Grammar","Number","
digit [...]
","
The maximum length of the number depends on the data type used.
","
100
"
"Other Grammar","Operand","
summand [ { || summand } [...] ]
","
A value or a concatenation of values.
","
'Hi' || ' Eva'
"
"Other Grammar","Order","
{ int | expression } [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
","
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.
","
NAME DESC NULLS LAST
"
"Other Grammar","Quoted Name","
""anythingExceptDoubleQuote""
","
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.
","
""FirstName""
"
"Other Grammar","Referential Constraint","
FOREIGN KEY ( columnName [,...] )
REFERENCES [ refTableName ] [ ( refColumnName [,...] ) ]
[ ON DELETE { CASCADE | RESTRICT | NO ACTION | SET { DEFAULT | NULL } } ]
[ ON UPDATE { CASCADE | SET { DEFAULT | NULL } } ]
","
Defines a referential constraint. If the table name is not specified, then the
same table is referenced. 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.
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.
","
FOREIGN KEY(ID) REFERENCES TEST(ID)
"
"Other Grammar","Script Compression","
COMPRESSION { DEFLATE | LZF | ZIP | GZIP }
","
The compression algorithm to use for script files.
LZF is faster but uses more space.
","
COMPRESSION LZF
"
"Other Grammar","Select Expression","
* | expression [ [ AS ] columnAlias ] | tableAlias.*
","
An expression in a SELECT statement.
","
ID AS VALUE
"
"Other Grammar","String","
'anythingExceptSingleQuote'
","
A string starts and ends with a single quote. Two single quotes can be used to
create a single quote inside a string.
","
'John''s car'
"
"Other Grammar","Summand","
factor [ { { + | - } factor } [...] ]
","
A value or a numeric sum.
Please note the text concatenation operator is ||.
","
ID + 20
"
"Other Grammar","Table Expression","
{ [ schemaName. ] tableName | ( select ) } [ [ AS ] newTableAlias ]
[ { { LEFT | RIGHT } [ OUTER ] | [ INNER ] | CROSS | NATURAL }
JOIN tableExpression [ ON expression ] ]
","
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.
","
TEST AS T LEFT JOIN TEST AS T1 ON T.ID = T1.ID
"
"Other Grammar","Term","
value
| columnName
| ?[ int ]
| NEXT VALUE FOR sequenceName
| function
| { - | + } term
| ( expression )
| select
| case
| caseWhen
| tableAlias.columnName
","
A value. Parameters can be indexed, for example ""?1"" meaning the first parameter.
Each table has a pseudo-column named ""_ROWID_"" that contains the unique row identifier.
","
'Hello'
"
"Other Grammar","Time","
TIME 'hh:mm:ss'
","
A time literal.
","
TIME '23:59:59'
"
"Other Grammar","Timestamp","
TIMESTAMP 'yyyy-MM-dd hh:mm:ss[.nnnnnnnnn]'
","
A timestamp literal. The limitations are the same as for the Java data type
""java.sql.Timestamp"", but for compatibility with other databases the suggested
minimum and maximum years are 0001 and 9999.
","
TIMESTAMP '2005-12-31 23:59:59'
"
"Other Grammar","Value","
string | dollarQuotedString | hexNumber | int | long | decimal | double
| date | time | timestamp | boolean | bytes | array | null
","
A value of any data type, or null.
","
10
"
"Data Types","INT Type","
INT | INTEGER | MEDIUMINT | INT4 | SIGNED
","
Possible values: -2147483648 to 2147483647.
Mapped to ""java.lang.Integer"".
","
INT
"
"Data Types","BOOLEAN Type","
BOOLEAN | BIT | BOOL
","
Possible values: TRUE and FALSE.
Mapped to ""java.lang.Boolean"".
","
BOOLEAN
"
"Data Types","TINYINT Type","
TINYINT
","
Possible values are: -128 to 127.
Mapped to ""java.lang.Byte"".
","
TINYINT
"
"Data Types","SMALLINT Type","
SMALLINT | INT2 | YEAR
","
Possible values: -32768 to 32767.
Mapped to ""java.lang.Short"".
","
SMALLINT
"
"Data Types","BIGINT Type","
BIGINT | INT8
","
Possible values: -9223372036854775808 to 9223372036854775807.
Mapped to ""java.lang.Long"".
","
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.
Mapped to ""java.lang.Long"".
","
IDENTITY
"
"Data Types","DECIMAL Type","
{ DECIMAL | NUMBER | DEC | NUMERIC } ( precisionInt [ , scaleInt ] )
","
Data type with fixed precision and scale. This data type is recommended for
storing currency values.
Mapped to ""java.math.BigDecimal"".
","
DECIMAL(20, 2)
"
"Data Types","DOUBLE Type","
{ DOUBLE [ PRECISION ] | FLOAT | FLOAT4 | FLOAT8 }
","
Floating point number. Should not be used to represent currency values, because
of rounding problems.
Mapped to ""java.lang.Double"".
","
DOUBLE
"
"Data Types","REAL Type","
REAL
","
Single precision floating point number. Should not be used to represent currency
values, because of rounding problems.
Mapped to ""java.lang.Float"".
","
REAL
"
"Data Types","TIME Type","
TIME
","
The format is hh:mm:ss.
Mapped to ""java.sql.Time"". When converted to a ""java.sql.Date"", the date is set to ""1970-01-01"".
","
TIME
"
"Data Types","DATE Type","
DATE
","
The format is yyyy-MM-dd.
Mapped to ""java.sql.Date"", with the time set to ""00:00:00""
(or to the next possible time if midnight doesn't exist for the given date and timezone due to a daylight saving change).
","
DATE
"
"Data Types","TIMESTAMP Type","
{ TIMESTAMP | DATETIME | SMALLDATETIME }
","
The format is yyyy-MM-dd hh:mm:ss[.nnnnnnnnn].
Mapped to ""java.sql.Timestamp"" (""java.util.Date"" is also supported).
","
TIMESTAMP
"
"Data Types","BINARY Type","
{ BINARY | VARBINARY | LONGVARBINARY | RAW | BYTEA } [ ( precisionInt ) ]
","
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.
Mapped to byte[].
","
BINARY(1000)
"
"Data Types","OTHER Type","
OTHER
","
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 get ""getObject"" is called. Java operations cannot be
executed inside the database engine for security reasons. Use
""PreparedStatement.setObject"" to store values.
Mapped to ""java.lang.Object"" (or any subclass).
","
OTHER
"
"Data Types","VARCHAR Type","
{ VARCHAR | LONGVARCHAR | VARCHAR2 | NVARCHAR
| NVARCHAR2 | VARCHAR_CASESENSITIVE} [ ( precisionInt ) ]
","
Unicode String. 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 kept in memory when using this data type. For large text data CLOB
should be used; see there for details.
Mapped to ""java.lang.String"".
","
VARCHAR(255)
"
"Data Types","VARCHAR_IGNORECASE Type","
VARCHAR_IGNORECASE [ ( precisionInt ) ]
","
Same as VARCHAR, but not case sensitive when comparing. Stored in mixed case.
The maximum precision is ""Integer.MAX_VALUE"" characters, but the whole text is kept in
memory when using this data type. For large text data CLOB should be used;
see there for details.
Mapped to ""java.lang.String"".
","
VARCHAR_IGNORECASE
"
"Data Types","CHAR Type","
{ CHAR | CHARACTER | NCHAR } [ ( precisionInt ) ]
","
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. Unicode String. 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 kept in memory when using
this data type. For large text data CLOB should be used; see there for details.
Mapped to ""java.lang.String"".
","
CHAR(10)
"
"Data Types","BLOB Type","
{ BLOB | TINYBLOB | MEDIUMBLOB | LONGBLOB | IMAGE | OID } [ ( precisionInt ) ]
","
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
""PreparedStatement.setBinaryStream"" to store values. See also CLOB and
Advanced / Large Objects.
Mapped to ""java.sql.Blob"" (""java.io.InputStream"" is also supported).
","
BLOB
"
"Data Types","CLOB Type","
{ CLOB | TINYTEXT | TEXT | MEDIUMTEXT | LONGTEXT | NTEXT | NCLOB } [ ( precisionInt ) ]
","
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
""PreparedStatement.setCharacterStream"" to store values. See also Advanced / Large Objects.
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.
Mapped to ""java.sql.Clob"" (""java.io.Reader"" is also supported).
","
CLOB
"
"Data Types","UUID Type","
UUID
","
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"".
For details, see the documentation of ""java.util.UUID"".
","
UUID
"
"Data Types","ARRAY Type","
ARRAY
","
An array of values. Use a value list (1, 2) or ""PreparedStatement.setObject(.., new Object[] {..})"" to store values.
Mapped to ""java.lang.Object[]"" (arrays of any non-primitive type are also supported).
","
ARRAY
"
"Functions (Aggregate)","AVG","
AVG ( [ DISTINCT ] { int | long | decimal | double } )
","
The average (mean) 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.
","
AVG(X)
"
"Functions (Aggregate)","BOOL_AND","
BOOL_AND(boolean)
","
Returns true if all expressions are true.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
BOOL_AND(ID>10)
"
"Functions (Aggregate)","BOOL_OR","
BOOL_OR(boolean)
","
Returns true if any expression is true.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
BOOL_OR(NAME LIKE 'W%')
"
"Functions (Aggregate)","COUNT","
COUNT( { * | { [ DISTINCT ] expression } } )
","
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.
","
COUNT(*)
"
"Functions (Aggregate)","GROUP_CONCAT","
GROUP_CONCAT ( [ DISTINCT ] string
[ ORDER BY { expression [ ASC | DESC ] } [,...] ]
[ SEPARATOR expression ] )
","
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.
","
GROUP_CONCAT(NAME ORDER BY ID SEPARATOR ', ')
"
"Functions (Aggregate)","MAX","
MAX(value)
","
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.
","
MAX(NAME)
"
"Functions (Aggregate)","MIN","
MIN(value)
","
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.
","
MIN(NAME)
"
"Functions (Aggregate)","SUM","
SUM( [ DISTINCT ] { int | long | decimal | double } )
","
The sum of all values.
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.
","
SUM(X)
"
"Functions (Aggregate)","SELECTIVITY","
SELECTIVITY(value)
","
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.
","
SELECT SELECTIVITY(FIRSTNAME), SELECTIVITY(NAME) FROM TEST WHERE ROWNUM()<20000
"
"Functions (Aggregate)","STDDEV_POP","
STDDEV_POP( [ DISTINCT ] double )
","
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.
","
STDDEV_POP(X)
"
"Functions (Aggregate)","STDDEV_SAMP","
STDDEV_SAMP( [ DISTINCT ] double )
","
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.
","
STDDEV(X)
"
"Functions (Aggregate)","VAR_POP","
VAR_POP( [ DISTINCT ] double )
","
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.
","
VAR_POP(X)
"
"Functions (Aggregate)","VAR_SAMP","
VAR_SAMP( [ DISTINCT ] double )
","
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.
","
VAR_SAMP(X)
"
"Functions (Numeric)","ABS","
ABS ( { int | long | decimal | double } )
","
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"".
The returned value is of the same data type as the parameter.
","
ABS(ID)
"
"Functions (Numeric)","ACOS","
ACOS(double)
","
See also Java ""Math.*"" functions.
This method returns a double.
","
ACOS(D)
"
"Functions (Numeric)","ASIN","
ASIN(double)
","
See also Java ""Math.*"" functions.
This method returns a double.
","
ASIN(D)
"
"Functions (Numeric)","ATAN","
ATAN(double)
","
See also Java ""Math.*"" functions.
This method returns a double.
","
ATAN(D)
"
"Functions (Numeric)","COS","
COS(double)
","
See also Java ""Math.*"" functions.
This method returns a double.
","
COS(ANGLE)
"
"Functions (Numeric)","COT","
COT(double)
","
See also Java ""Math.*"" functions.
This method returns a double.
","
COT(ANGLE)
"
"Functions (Numeric)","SIN","
SIN(double)
","
See also Java ""Math.*"" functions.
This method returns a double.
","
SIN(ANGLE)
"
"Functions (Numeric)","TAN","
TAN(double)
","
See also Java ""Math.*"" functions.
This method returns a double.
","
TAN(ANGLE)
"
"Functions (Numeric)","ATAN2","
ATAN2(double, double)
","
See also Java ""Math.atan2"".
This method returns a double.
","
ATAN2(X, Y)
"
"Functions (Numeric)","BITAND","
BITAND(long, long)
","
The bitwise AND operation.
This method returns a long.
See also Java operator &.
","
BITAND(A, B)
"
"Functions (Numeric)","BITOR","
BITOR(long, long)
","
The bitwise OR operation.
This method returns a long.
See also Java operator |.
","
BITOR(A, B)
"
"Functions (Numeric)","BITXOR","
BITXOR(long, long)
","
The bitwise XOR operation.
This method returns a long.
See also Java operator ^.
","
BITXOR(A, B)
"
"Functions (Numeric)","MOD","
MOD(long, long)
","
The modulo operation.
This method returns a long.
See also Java operator %.
","
MOD(A, B)
"
"Functions (Numeric)","CEILING","
CEILING(double)
","
See also Java ""Math.ceil"".
This method returns a double.
","
LOG(A)
"
"Functions (Numeric)","DEGREES","
DEGREES(double)
","
See also Java ""Math.toDegrees"".
This method returns a double.
","
DEGREES(A)
"
"Functions (Numeric)","EXP","
EXP(double)
","
See also Java ""Math.exp"".
This method returns a double.
","
EXP(A)
"
"Functions (Numeric)","FLOOR","
FLOOR(double)
","
See also Java ""Math.floor"".
This method returns a double.
","
FLOOR(A)
"
"Functions (Numeric)","LOG","
LOG(double)
","
See also Java ""Math.log"".
This method returns a double.
","
LOG(A)
"
"Functions (Numeric)","LOG10","
LOG10(double)
","
See also Java ""Math.log10"" (in Java 5).
This method returns a double.
","
LOG10(A)
"
"Functions (Numeric)","RADIANS","
RADIANS(double)
","
See also Java ""Math.toRadians"".
This method returns a double.
","
RADIANS(A)
"
"Functions (Numeric)","SQRT","
SQRT(double)
","
See also Java ""Math.sqrt"".
This method returns a double.
","
SQRT(A)
"
"Functions (Numeric)","PI","
PI()
","
See also Java ""Math.PI"".
This method returns a double.
","
PI()
"
"Functions (Numeric)","POWER","
POWER(double, double)
","
See also Java ""Math.pow"".
This method returns a double.
","
POWER(A, B)
"
"Functions (Numeric)","RAND","
RAND( [ int ] )
","
Calling the function without parameter returns the next a pseudo random number.
Calling it with an parameter seeds the session's random number generator.
This method returns a double between 0 (including) and 1 (excluding).
","
RAND()
"
"Functions (Numeric)","RANDOM_UUID","
RANDOM_UUID()
","
Returns a new UUID with 122 pseudo random bits.
","
RANDOM_UUID()
"
"Functions (Numeric)","ROUND","
ROUND(double, digitsInt)
","
Rounds to a number of digits.
This method returns a double.
","
ROUND(VALUE, 2)
"
"Functions (Numeric)","ROUNDMAGIC","
ROUNDMAGIC(double)
","
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.
","
ROUNDMAGIC(VALUE/3*3)
"
"Functions (Numeric)","SECURE_RAND","
SECURE_RAND(int)
","
Generates a number of cryptographically secure random numbers.
This method returns bytes.
","
CALL SECURE_RAND(16)
"
"Functions (Numeric)","SIGN","
SIGN ( { int | long | decimal | double } )
","
Returns -1 if the value is smaller 0, 0 if zero, and otherwise 1.
","
SIGN(VALUE)
"
"Functions (Numeric)","ENCRYPT","
ENCRYPT(algorithmString, keyBytes, dataBytes)
","
Encrypts data using a key.
Supported algorithms are XTEA and AES.
The block size is 16 bytes.
This method returns bytes.
","
CALL ENCRYPT('AES', '00', STRINGTOUTF8('Test'))
"
"Functions (Numeric)","DECRYPT","
DECRYPT(algorithmString, keyBytes, dataBytes)
","
Decrypts data using a key.
Supported algorithms are XTEA and AES.
The block size is 16 bytes.
This method returns bytes.
","
CALL TRIM(CHAR(0) FROM UTF8TOSTRING(
DECRYPT('AES', '00', '3fabb4de8f1ee2e97d7793bab2db1116')))
"
"Functions (Numeric)","HASH","
HASH(algorithmString, dataBytes, iterationInt)
","
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.
","
CALL HASH('SHA256', STRINGTOUTF8('Password'), 1000)
"
"Functions (Numeric)","TRUNCATE","
TRUNCATE(double, digitsInt)
","
Truncates to a number of digits (to the next value closer to 0).
This method returns a double.
","
TRUNCATE(VALUE, 2)
"
"Functions (Numeric)","COMPRESS","
COMPRESS(dataBytes [, algorithmString])
","
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.
","
COMPRESS(STRINGTOUTF8('Test'))
"
"Functions (Numeric)","EXPAND","
EXPAND(bytes)
","
Expands data that was compressed using the COMPRESS function.
This method returns bytes.
","
UTF8TOSTRING(EXPAND(COMPRESS(STRINGTOUTF8('Test'))))
"
"Functions (Numeric)","ZERO","
ZERO()
","
Returns the value 0. This function can be used even if numeric literals are disabled.
","
ZERO()
"
"Functions (String)","ASCII","
ASCII(string)
","
Returns the ASCII value of the first character in the string.
This method returns an int.
","
ASCII('Hi')
"
"Functions (String)","BIT_LENGTH","
BIT_LENGTH(string)
","
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.
","
BIT_LENGTH(NAME)
"
"Functions (String)","LENGTH","
{ LENGTH | CHAR_LENGTH | CHARACTER_LENGTH } ( string )
","
Returns the number of characters in a string.
This method returns a long.
For BLOB, CLOB, BYTES and JAVA_OBJECT, the precision is used.
","
LENGTH(NAME)
"
"Functions (String)","OCTET_LENGTH","
OCTET_LENGTH(string)
","
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.
","
OCTET_LENGTH(NAME)
"
"Functions (String)","CHAR","
{ CHAR | CHR } ( int )
","
Returns the character that represents the ASCII value.
This method returns a string.
","
CHAR(65)
"
"Functions (String)","CONCAT","
CONCAT(string, string [,...])
","
Combines strings.
This method returns a string.
","
CONCAT(NAME, '!')
"
"Functions (String)","DIFFERENCE","
DIFFERENCE(string, string)
","
Returns the difference between the sounds of two strings.
This method returns an int.
","
DIFFERENCE(T1.NAME, T2.NAME)
"
"Functions (String)","HEXTORAW","
HEXTORAW(string)
","
Converts a hex representation of a string to a string.
4 hex characters per string character are used.
","
HEXTORAW(DATA)
"
"Functions (String)","RAWTOHEX","
RAWTOHEX(string)
","
Converts a string to the hex representation.
4 hex characters per string character are used.
This method returns a string.
","
RAWTOHEX(DATA)
"
"Functions (String)","INSTR","
INSTR(string, searchString, [, startInt])
","
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.
","
INSTR(EMAIL,'@')
"
"Functions (String)","INSERT Function","
INSERT(originalString, startInt, lengthInt, addString)
","
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.
","
INSERT(NAME, 1, 1, ' ')
"
"Functions (String)","LOWER","
{ LOWER | LCASE } ( string )
","
Converts a string to lowercase.
","
LOWER(NAME)
"
"Functions (String)","UPPER","
{ UPPER | UCASE } ( string )
","
Converts a string to uppercase.
","
UPPER(NAME)
"
"Functions (String)","LEFT","
LEFT(string, int)
","
Returns the leftmost number of characters.
","
LEFT(NAME, 3)
"
"Functions (String)","RIGHT","
RIGHT(string, int)
","
Returns the rightmost number of characters.
","
RIGHT(NAME, 3)
"
"Functions (String)","LOCATE","
LOCATE(searchString, string [, startInt])
","
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.
","
LOCATE('.', NAME)
"
"Functions (String)","POSITION","
POSITION(searchString, string)
","
Returns the location of a search string in a string. See also LOCATE.
","
POSITION('.', NAME)
"
"Functions (String)","LPAD","
LPAD(string, int[, paddingString])
","
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.
","
LPAD(AMOUNT, 10, '*')
"
"Functions (String)","RPAD","
RPAD(string, int[, paddingString])
","
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.
","
RPAD(TEXT, 10, '-')
"
"Functions (String)","LTRIM","
LTRIM(string)
","
Removes all leading spaces from a string.
","
LTRIM(NAME)
"
"Functions (String)","RTRIM","
RTRIM(string)
","
Removes all trailing spaces from a string.
","
RTRIM(NAME)
"
"Functions (String)","TRIM","
TRIM ( [ { LEADING | TRAILING | BOTH } [ string ] FROM ] string )
","
Removes all leading spaces, trailing spaces, or spaces at both ends, from a string.
Other characters can be removed as well.
","
TRIM(BOTH '_' FROM NAME)
"
"Functions (String)","REGEXP_REPLACE","
REGEXP_REPLACE(inputString, regexString, replacementString)
","
Replaces each substring that matches a regular expression.
For details, see the Java ""String.replaceAll()"" method.
If any parameter is null, the result is null.
","
REGEXP_REPLACE('Hello World', ' +', ' ')
"
"Functions (String)","REPEAT","
REPEAT(string, int)
","
Returns a string repeated some number of times.
","
REPEAT(NAME || ' ', 10)
"
"Functions (String)","REPLACE","
REPLACE(string, searchString [, replacementString])
","
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.
If any parameter is null, the result is null.
","
REPLACE(NAME, ' ')
"
"Functions (String)","SOUNDEX","
SOUNDEX(string)
","
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.
","
SOUNDEX(NAME)
"
"Functions (String)","SPACE","
SPACE(int)
","
Returns a string consisting of a number of spaces.
","
SPACE(80)
"
"Functions (String)","STRINGDECODE","
STRINGDECODE(string)
","
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.
","
CALL STRINGENCODE(STRINGDECODE('Lines 1\nLine 2'))
"
"Functions (String)","STRINGENCODE","
STRINGENCODE(string)
","
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.
","
CALL STRINGENCODE(STRINGDECODE('Lines 1\nLine 2'))
"
"Functions (String)","STRINGTOUTF8","
STRINGTOUTF8(string)
","
Encodes a string to a byte array using the UTF8 encoding format.
This method returns bytes.
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"
"Functions (String)","SUBSTRING","
{ SUBSTRING | SUBSTR } ( string, startInt [, lengthInt ] )
","
Returns a substring of a string starting at a position.
The length is optional.
Also supported is: ""SUBSTRING(string FROM start [FOR length])"".
","
SUBSTR(NAME, 1)
"
"Functions (String)","UTF8TOSTRING","
UTF8TOSTRING(bytes)
","
Decodes a byte array in the UTF8 format to a string.
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"
"Functions (String)","XMLATTR","
XMLATTR(nameString, valueString)
","
Creates an XML attribute element of the form ""name=value"".
The value is encoded as XML text.
This method returns a string.
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'))
"
"Functions (String)","XMLNODE","
XMLNODE(elementString [, attributesString [, contentString]])
","
Create an XML node element.
This method returns a string.
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'), 'H2')
"
"Functions (String)","XMLCOMMENT","
XMLCOMMENT(commentString)
","
Creates an XML comment.
Two dashes (""--"") are converted to ""- -"".
This method returns a string.
","
CALL XMLCOMMENT('Test')
"
"Functions (String)","XMLCDATA","
XMLCDATA(valueString)
","
Creates an XML CDATA element.
If the value contains ""]]>"", an XML text element is created instead.
This method returns a string.
","
CALL XMLCDATA('data')
"
"Functions (String)","XMLSTARTDOC","
XMLSTARTDOC()
","
The string ""<?xml version='1.0'?>"" is returned.
","
CALL XMLSTARTDOC()
"
"Functions (String)","XMLTEXT","
XMLTEXT(valueString)
","
Creates an XML text element.
This method returns a string.
","
CALL XMLTEXT('test')
"
"Functions (Time and Date)","CURRENT_DATE","
{ CURRENT_DATE [ () ] | CURDATE() | SYSDATE | TODAY }
","
Returns the current date.
","
CURRENT_DATE()
"
"Functions (Time and Date)","CURRENT_TIME","
{ CURRENT_TIME [ () ] | CURTIME() }
","
Returns the current time.
","
CURRENT_TIME()
"
"Functions (Time and Date)","CURRENT_TIMESTAMP","
{ CURRENT_TIMESTAMP [ ( [ int ] ) ] | NOW( [ int ] ) }
","
Returns the current timestamp.
The precision parameter for nanoseconds precision is optional.
","
CURRENT_TIMESTAMP()
"
"Functions (Time and Date)","DATEADD","
DATEADD(unitString, addInt, timestamp)
","
Adds units to a timestamp. The string indicates the unit.
Use negative values to subtract units.
The same units as in the EXTRACT function are supported.
This method returns a timestamp.
","
DATEADD('MONTH', 1, DATE '2001-01-31')
"
"Functions (Time and Date)","DATEDIFF","
{ DATEDIFF | TIMESTAMPDIFF } (unitString, aTimestamp, bTimestamp)
","
Returns the the number of crossed unit boundaries between two timestamps.
This method returns a long.
The string indicates the unit.
The same units as in the EXTRACT function are supported.
TIMESTAMPDIFF is supported for MySQL compatibility.
","
DATEDIFF('YEAR', T1.CREATED, T2.CREATED)
"
"Functions (Time and Date)","DAYNAME","
DAYNAME(date)
","
Returns the name of the day (in English).
","
DAYNAME(CREATED)
"
"Functions (Time and Date)","DAY_OF_MONTH","
DAY_OF_MONTH(date)
","
Returns the day of the month (1-31).
","
DAY_OF_MONTH(CREATED)
"
"Functions (Time and Date)","DAY_OF_WEEK","
DAY_OF_WEEK(date)
","
Returns the day of the week (1 means Sunday).
","
DAY_OF_WEEK(CREATED)
"
"Functions (Time and Date)","DAY_OF_YEAR","
DAY_OF_YEAR(date)
","
Returns the day of the year (1-366).
","
DAY_OF_YEAR(CREATED)
"
"Functions (Time and Date)","EXTRACT","
EXTRACT ( { YEAR | YY | MONTH | MM | DAY | DD | DAY_OF_YEAR
| DOY | HOUR | HH | MINUTE | MI | SECOND | SS | MILLISECOND | MS }
FROM timestamp )
","
Returns a specific value from a timestamps.
This method returns an int.
","
EXTRACT(SECOND FROM CURRENT_TIMESTAMP)
"
"Functions (Time and Date)","FORMATDATETIME","
FORMATDATETIME ( timestamp, formatString
[ , localeString [ , timeZoneString ] ] )
","
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.
For details of the format, see ""java.text.SimpleDateFormat"".
This method returns a string.
","
CALL FORMATDATETIME(TIMESTAMP '2001-02-03 04:05:06',
'EEE, d MMM yyyy HH:mm:ss z', 'en', 'GMT')
"
"Functions (Time and Date)","HOUR","
HOUR(timestamp)
","
Returns the hour (0-23) from a timestamp.
","
HOUR(CREATED)
"
"Functions (Time and Date)","MINUTE","
MINUTE(timestamp)
","
Returns the minute (0-59) from a timestamp.
","
MINUTE(CREATED)
"
"Functions (Time and Date)","MONTH","
MONTH(timestamp)
","
Returns the month (1-12) from a timestamp.
","
MONTH(CREATED)
"
"Functions (Time and Date)","MONTHNAME","
MONTHNAME(date)
","
Returns the name of the month (in English).
","
MONTHNAME(CREATED)
"
"Functions (Time and Date)","PARSEDATETIME","
PARSEDATETIME(string, formatString
[, localeString [, timeZoneString]])
","
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.
For details of the format, see ""java.text.SimpleDateFormat"".
","
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","
QUARTER(timestamp)
","
Returns the quarter (1-4) from a timestamp.
","
QUARTER(CREATED)
"
"Functions (Time and Date)","SECOND","
SECOND(timestamp)
","
Returns the second (0-59) from a timestamp.
","
SECOND(CREATED)
"
"Functions (Time and Date)","WEEK","
WEEK(timestamp)
","
Returns the week (1-53) from a timestamp.
This method uses the current system locale.
","
WEEK(CREATED)
"
"Functions (Time and Date)","YEAR","
YEAR(timestamp)
","
Returns the year from a timestamp.
","
YEAR(CREATED)
"
"Functions (System)","ARRAY_GET","
ARRAY_GET(arrayExpression, indexExpression)
","
Returns one element of an array.
This method returns a string.
","
CALL ARRAY_GET(('Hello', 'World'), 2)
"
"Functions (System)","ARRAY_LENGTH","
ARRAY_GET(arrayExpression)
","
Returns the length of an array.
","
CALL ARRAY_LENGTH(('Hello', 'World'))
"
"Functions (System)","AUTOCOMMIT","
AUTOCOMMIT()
","
Returns true if auto commit is switched on for this session.
","
AUTOCOMMIT()
"
"Functions (System)","CANCEL_SESSION","
CANCEL_SESSION(sessionInt)
","
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.
Admin rights are required to execute this command.
","
CANCEL_SESSION(3)
"
"Functions (System)","CASEWHEN Function","
CASEWHEN(boolean, aValue, bValue)
","
Returns 'a' if the boolean expression is true, otherwise 'b'.
Returns the same data type as the parameter.
","
CASEWHEN(ID=1, 'A', 'B')
"
"Functions (System)","CAST","
CAST(value AS dataType)
","
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);
"
"Functions (System)","COALESCE","
COALESCE(aValue, bValue [,...])
","
Returns the first value that is not null.
","
COALESCE(A, B, C)
"
"Functions (System)","CONVERT","
CONVERT(value, dataType)
","
Converts a value to another data type.
","
CONVERT(NAME, INT)
"
"Functions (System)","CURRVAL","
CURRVAL( [ schemaName, ] sequenceString )
","
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.
","
CURRVAL('TEST_SEQ')
"
"Functions (System)","CSVREAD","
CSVREAD(fileNameString [, columnsString [, csvOptions ] ] )
","
Returns the result set of reading the CSV (comma separated values) file.
For each parameter, NULL means the default value should be used.
If the column names are specified (a list of column names separated with the
fieldSeparator), those are used, otherwise (or if they are set to NULL) the first line of
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).
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.
The BOM (the byte-order-mark) character 0xfeff at the beginning of the file is ignored.
This function can be used like a table: ""SELECT * FROM CSVREAD(...)"".
Instead of a file, an URL may be used, for example
""jar:file:///c:/temp/example.zip!/org/example/nested.csv"".
To read a stream from the classpath, use the prefix ""classpath:"".
Admin rights are required to execute this command.
","
CALL CSVREAD('test.csv');
-- Read a file containing the columns ID, NAME with
-- UTF-8 encoding and the pipe (|) as field separator
CALL CSVREAD('test2.csv', 'ID|NAME', 'UTF-8', '|');
-- Read a semicolon-separated file
SELECT * FROM CSVREAD('data/test.csv', NULL, NULL, ';');
SELECT ""Last Name"" FROM CSVREAD('address.csv');
SELECT ""Last Name"" FROM CSVREAD('classpath:/org/acme/data/address.csv');
"
"Functions (System)","CSVWRITE","
CSVWRITE ( fileNameString, queryString [, csvOptions [, lineSepString] ] )
","
Writes a CSV (comma separated values). The file is overwritten if it exists.
If only a file name is specified, it will be written to the current working directory.
For each parameter, NULL means the default value should be used.
The default charset is the default value for this system, and the default field separator is a comma.
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
system (system property ""line.separator"").
The returned value is the number or rows written.
Admin rights are required to execute this command.
","
CALL CSVWRITE('test.csv', 'SELECT * FROM TEST');
-- Write a file with UTF-8 encoding and the pipe (|) as field separator
CALL CSVWRITE('test2.csv', 'SELECT * FROM TEST', 'UTF-8', '|');
"
"Functions (System)","DATABASE","
DATABASE()
","
Returns the name of the database.
","
CALL DATABASE();
"
"Functions (System)","DATABASE_PATH","
DATABASE_PATH()
","
Returns the directory of the database files and the database name, if it is file
based. Returns NULL otherwise.
","
CALL DATABASE_PATH();
"
"Functions (System)","FILE_READ","
FILE_READ(fileNameString [,encodingString])
","
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
default character set for this system.
File names and URLs are supported.
To read a stream from the classpath, use the prefix ""classpath:"".
Admin rights are required to execute this command.
","
SELECT LENGTH(FILE_READ('~/.h2.server.properties')) LEN;
SELECT FILE_READ('http://localhost:8182/stylesheet.css', NULL) CSS;
"
"Functions (System)","GREATEST","
GREATEST(aValue, bValue [,...])
","
Returns the largest value that is not NULL, or NULL if all values are NULL.
","
CALL GREATEST(1, 2, 3);
"
"Functions (System)","IDENTITY","
IDENTITY()
","
Returns the last inserted identity value for this session.
This value changes whenever a new sequence number was generated,
even within a trigger or Java function. See also SCOPE_IDENTITY.
This method returns a long.
","
CALL IDENTITY();
"
"Functions (System)","IFNULL","
IFNULL(aValue, bValue)
","
Returns the value of 'a' if it is not null, otherwise 'b'.
","
CALL IFNULL(NULL, '');
"
"Functions (System)","LEAST","
LEAST(aValue, bValue [,...])
","
Returns the smallest value that is not NULL, or NULL if all values are NULL.
","
CALL LEAST(1, 2, 3);
"
"Functions (System)","LOCK_MODE","
LOCK_MODE()
","
Returns the current lock mode. See SET LOCK_MODE.
This method returns an int.
","
CALL LOCK_MODE();
"
"Functions (System)","LOCK_TIMEOUT","
LOCK_TIMEOUT()
","
Returns the lock timeout of the current session (in milliseconds).
","
LOCK_TIMEOUT()
"
"Functions (System)","LINK_SCHEMA","
LINK_SCHEMA(targetSchemaString, driverString, urlString,
userString, passwordString, sourceSchemaString)
","
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.
Admin rights are required to execute this command.
","
CALL LINK_SCHEMA('TEST2', '', 'jdbc:h2:test2', 'sa', 'sa', 'PUBLIC');
"
"Functions (System)","MEMORY_FREE","
MEMORY_FREE()
","
Returns the free memory in KB (where 1024 bytes is a KB).
This method returns an int.
The garbage is run before returning the value.
Admin rights are required to execute this command.
","
MEMORY_FREE()
"
"Functions (System)","MEMORY_USED","
MEMORY_USED()
","
Returns the used memory in KB (where 1024 bytes is a KB).
This method returns an int.
The garbage is run before returning the value.
Admin rights are required to execute this command.
","
MEMORY_USED()
"
"Functions (System)","NEXTVAL","
NEXTVAL ( [ schemaName, ] sequenceString )
","
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.
","
NEXTVAL('TEST_SEQ')
"
"Functions (System)","NULLIF","
NULLIF(aValue, bValue)
","
Returns NULL if 'a' is equals to 'b', otherwise 'a'.
","
NULLIF(A, B)
"
"Functions (System)","READONLY","
READONLY()
","
Returns true if the database is read-only.
","
READONLY()
"
"Functions (System)","ROWNUM","
ROWNUM()
","
Returns the number of the current row.
This method returns an int.
This function is supported for SELECT statements, as well as for DELETE and UPDATE.
The first row has the row number 1, and is calculated before ordering and grouping the result set,
but after evaluating index conditions (even when the index conditions are specified in an outer query).
To get the row number after ordering and grouping, use a subquery.
","
SELECT ROWNUM(), * FROM TEST;
SELECT ROWNUM(), * FROM (SELECT * FROM TEST ORDER BY NAME);
SELECT ID FROM (SELECT T.*, ROWNUM AS R FROM TEST T) WHERE R BETWEEN 2 AND 3;
"
"Functions (System)","SCHEMA","
SCHEMA()
","
Returns the name of the default schema for this session.
","
CALL SCHEMA()
"
"Functions (System)","SCOPE_IDENTITY","
SCOPE_IDENTITY()
","
Returns the last inserted identity value for this session for the current scope.
Changes within triggers and Java functions are ignored. See also IDENTITY().
This method returns a long.
","
CALL SCOPE_IDENTITY();
"
"Functions (System)","SESSION_ID","
SESSION_ID()
","
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.
","
CALL SESSION_ID()
"
"Functions (System)","SET","
SET(@variableName, value)
","
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.
This can be used to implement running totals / cumulative sums.
","
SELECT X, SET(@I, IFNULL(@I, 0)+X) RUNNING_TOTAL FROM SYSTEM_RANGE(1, 10)
"
"Functions (System)","TABLE","
{ TABLE | TABLE_DISTINCT } ( { name dataType = expression } [,...] )
","
Returns the result set. TABLE_DISTINCT removes duplicate rows.
","
SELECT * FROM TABLE(ID INT=(1, 2), NAME VARCHAR=('Hello', 'World'))
"
"Functions (System)","TRANSACTION_ID","
TRANSACTION_ID()
","
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.
Otherwise a value of the following form is returned:
""logFileId-position-sessionId"".
This method returns a string.
The value is unique across database restarts (values are not re-used).
","
CALL TRANSACTION_ID()
"
"Functions (System)","USER","
{ USER | CURRENT_USER } ()
","
Returns the name of the current user of this session.
","
CURRENT_USER()
"
"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)
"