File: sqlsyntax.xml

package info (click to toggle)
hsqldb 1.8.0.7-1etch1
  • links: PTS
  • area: main
  • in suites: etch
  • size: 11,824 kB
  • ctags: 11,226
  • sloc: java: 71,953; xml: 10,832; sql: 1,038; sh: 875; makefile: 58
file content (3077 lines) | stat: -rw-r--r-- 110,040 bytes parent folder | download | duplicates (2)
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
<?xml version="1.0" encoding="UTF-8"?>
<!-- $Id: sqlsyntax.xml,v 1.48 2005/11/06 22:13:26 unsaved Exp $ -->
<chapter id="sqlsyntax-chapter">
  <title id="sqlsyntax-title">SQL Syntax</title>

  <chapterinfo>
    <authorgroup>
      <corpauthor>The Hypersonic SQL Group</corpauthor>

      <author>
        <firstname>Fred</firstname>

        <surname>Toussi</surname>

        <affiliation>
          <orgname>HSQLDB Development Group</orgname>
        </affiliation>

        <email>ft@cluedup.com</email>
      </author>

      <author>
        <firstname>Peter</firstname>

        <surname>Hudson</surname>

        <affiliation>
          <orgname>HSQLDB Development Group</orgname>
        </affiliation>
      </author>

      <author>
        <firstname>Joe</firstname>

        <surname>Maher</surname>

        <affiliation>
          <orgname>HSQLDB Development Group</orgname>
        </affiliation>

        <email>jrmaher@ameritech.net</email>
      </author>

      <editor>
        <firstname>Blaine</firstname>

        <surname>Simpson</surname>

        <affiliation>
          <orgname>HSQLDB Development Group</orgname>
        </affiliation>

        <email>blaine.simpson@admc.com</email>
      </editor>
    </authorgroup>

    <edition>$Revision: 1.48 $</edition>

    <pubdate>$Date: 2005/11/06 22:13:26 $</pubdate>

    <keywordset>
      <keyword>Hsqldb</keyword>

      <keyword>Syntax</keyword>

      <keyword>SQL</keyword>
    </keywordset>
  </chapterinfo>

  <para>HSQLDB version 1.8.0 supports the SQL statements and syntax described
  in this chapter.</para>

  <section>
    <title>Notational Conventions Used in this Chapter</title>

    <para><literal>[A]</literal> means A is optional.</para>

    <para><literal>{ B | C }</literal> means either B or C must be
    used.</para>

    <para><literal>[{ B | C }]</literal> means either B or C may optionally be
    used, or nothing at all.</para>

    <para><literal>(</literal> and <literal>)</literal> are the actual
    characters '(' and ')' used in statements.</para>

    <para>UPPERCASE words are keywords</para>
  </section>

  <section>
    <title>SQL Commands</title>

    <!-- The first items using footnotes must define them.
         That's why this one has "<footnode id=" instead of "<footnoteref..."
     -->

    <section id="alter_index-section">
      <title id="alter_index-title">ALTER INDEX<footnote id="posthyper">
          <para>These features were added by HSQL Development Group since
          April 2001</para>
        </footnote></title>

      <programlisting>ALTER INDEX &lt;indexname&gt; RENAME TO &lt;newname&gt;;</programlisting>

      <para>Index names can be changed so long as they do not conflict with
      other user-defined or sytem-defined names.</para>
    </section>

    <!-- Template for new items:  (Put new items into alphabetical position)
    <section id="@-section">
        <title id="@-title">@<footnoteref linkend="posthyper"/></title>
        <programlisting>
        </programlisting>
        <para>
        </para> <para>
        </para>
    </section>
    -->

    <section id="alter_sequence-section">
      <title id="alter_sequence-title">ALTER SEQUENCE<footnoteref
      linkend="posthyper" /></title>

      <programlisting>ALTER SEQUENCE &lt;sequencename&gt; RESTART WITH &lt;value&gt;;</programlisting>

      <para>Resets the next value to be returned from the sequence.</para>
    </section>

    <section>
      <title>ALTER SCHEMA<footnoteref linkend="posthyper" /></title>

      <programlisting>ALTER SCHEMA &lt;schemaname&gt; RENAME TO &lt;newname&gt;;</programlisting>

      <para>Renames the schema as specified. All objects of the schema will
      hereafter be accessible only with the new schema name.</para>

      <para>Requires Administrative privileges.</para>
    </section>

    <section id="alter_table-section">
      <title id="alter_table-title">ALTER TABLE<footnoteref
      linkend="posthyper" /></title>

      <programlisting>ALTER TABLE &lt;tablename&gt; ADD [COLUMN] &lt;columnname&gt; <link
          linkend="datatypes-section">Datatype</link>
    [(columnSize[,precision])] [{DEFAULT &lt;defaultValue&gt; |
    GENERATED BY DEFAULT AS IDENTITY (START WITH &lt;n&gt;[, INCREMENT BY &lt;m&gt;])}] |
    [[NOT] NULL] [IDENTITY] [PRIMARY KEY]
    [BEFORE &lt;existingcolumn&gt;];</programlisting>

      <para>Adds the column to the end of the column list. The optional BEFORE
      &lt;existingcolumn&gt; can be used to specify the name of an existing
      column so that the new column is inserted in a position just before the
      &lt;existingcolumn&gt;.</para>

      <para>It accepts a <link endterm="columnDef-title"
      linkend="columnDef-entry" /> as in a CREATE TABLE command. If NOT NULL
      is specified and the table is not empty, then a default value must be
      specified. In all other respects, this command is the equivalent of a
      column definition statement in a CREATE TABLE statement.</para>

      <para>If an SQL view includes a SELECT * FROM &lt;tablename&gt; in its
      select statement, the new column is added to the view. This is a
      non-standard feature which is likely to change in the future.</para>

      <programlisting>ALTER TABLE &lt;tablename&gt; DROP [COLUMN] &lt;columnname&gt;;</programlisting>

      <para>Drops the column from the table. Will drop any single-column
      primary key or unique constraint on the column as well. The command will
      not work if there is any multiple key constraint on the column or the
      column is referenced in a check constraint or a foreign key.</para>

      <para>It will also fail if an SQL view includes the column.</para>

      <programlisting>ALTER TABLE &lt;tablename&gt; ALTER COLUMN &lt;columnname&gt; RENAME TO &lt;newname&gt; </programlisting>

      <para>Changes a column name.</para>

      <programlisting>ALTER TABLE &lt;tablename&gt; ALTER COLUMN &lt;columnname&gt; SET DEFAULT &lt;defaultvalue&gt;};</programlisting>

      <para>Adds the specified default value to the column. Use NULL to remove
      a default.</para>

      <programlisting>ALTER TABLE &lt;tablename&gt; ALTER COLUMN &lt;columnname&gt; SET [NOT] NULL</programlisting>

      <para>Sets or removes a NOT NULL constraint for the column.</para>

      <programlisting>ALTER TABLE &lt;tablename&gt; ALTER COLUMN &lt;columnDefinition&gt;;</programlisting>

      <para>This form of ALTER TABLE ALTER COLUMN accepts a <link
      endterm="columnDef-title" linkend="columnDef-entry" /> as in a CREATE
      TABLE command, with the following restrictions.</para>

      <itemizedlist>
        <title>Restrictions</title>

        <listitem>The column must be already be a PK column to accept an
        IDENTITY definition.</listitem>

        <listitem>If the column is already an IDENTITY column and there is no
        IDENTITY definition, the existing IDENTITY attribute is
        removed.</listitem>

        <listitem>The default expression will be that of the new definition,
        meaning an existing default can be dropped by ommission, or a new
        default added.</listitem>

        <listitem>The NOT NULL attribute will be that of the new definition
        (similar to previous item).</listitem>

        <listitem>Depending on the type of change, the table may have to be
        empty for the command to work. It always works when the type of change
        is possible in general and the individual existing values can all be
        converted.</listitem>
      </itemizedlist>

      <programlisting>ALTER TABLE &lt;tablename&gt; ALTER COLUMN &lt;columnname&gt;
    RESTART WITH &lt;new sequence value&gt;</programlisting>

      <para>This form is used exclusively for IDENTITY columns and changes the
      next automatic value for the identity sequence.</para>

      <programlisting>ALTER TABLE &lt;tablename&gt; ADD [CONSTRAINT &lt;constraintname&gt;]
    CHECK (&lt;search condition&gt;);</programlisting>

      <para>Adds a check constraint to the table. In the current version, a
      check constraint can reference only the row being inserted or
      updated.</para>

      <programlisting>ALTER TABLE &lt;tablename&gt; ADD [CONSTRAINT &lt;constraintname&gt;] UNIQUE (&lt;column list&gt;);</programlisting>

      <para>Adds a unique constraint to the table. This will not work if there
      is already a unique constraint covering exactly the same &lt;column
      list&gt;.</para>

      <para>This will work only if the values of the column list for the
      existing rows are unique or include a null value.</para>

      <programlisting>ALTER TABLE &lt;tablename&gt; ADD [CONSTRAINT &lt;constraintname&gt;]
    PRIMARY KEY (&lt;column list&gt;);</programlisting>

      <para>Adds a primary key constraint to the table, using the same
      constraint syntax as when the primary key is specified in a table
      definition.</para>

      <programlisting>ALTER TABLE &lt;tablename&gt;
    ADD [CONSTRAINT &lt;constraintname&gt;] FOREIGN KEY (&lt;column list&gt;)
    REFERENCES &lt;exptablename&gt; (&lt;column list&gt;)
    [ON {DELETE | UPDATE} {CASCADE | SET DEFAULT | SET NULL}];</programlisting>

      <para>Adds a foreign key constraint to the table, using the same
      constraint syntax as when the foreign key is specified in a table
      definition.</para>

      <para>This will fail if for each existing row in the referring table, a
      matching row (with equal values for the column list) is not found in the
      referenced tables.</para>

      <programlisting>ALTER TABLE &lt;tablename&gt; DROP CONSTRAINT &lt;constraintname&gt;;</programlisting>

      <para>Drop a named unique, check or foreign key constraint from the
      table.</para>

      <programlisting>ALTER TABLE &lt;tablename&gt; RENAME TO &lt;newname&gt;;</programlisting>
    </section>

    <section id="alter_user-section">
      <title id="alter_user-title">ALTER USER<footnoteref
      linkend="posthyper" /></title>

      <programlisting>ALTER USER &lt;username&gt; SET PASSWORD &lt;password&gt;;</programlisting>

      <para>Changes the password for an existing user. Password must be double
      quoted. Use "" for an empty password.</para>

      <para>DBA's may change users' base default schema name with the comand
      <programlisting>ALTER USER &lt;username&gt; SET INITIAL SCHEMA &lt;schemaname&gt;;</programlisting>
      This is the schema which database object names will resolve to for this
      user, unless overridden as explained in <link
      endterm="schemanaming-title" linkend="schemanaming-section" />. For
      reasons of backwards compatibility, the initial schema value will not be
      persisted across database shutdowns until HSQLDB version 1.8.1. (I.e.,
      INITIAL SCHEMA settings will be lost upon database shutdown with HSQLDB
      versions lower than version 1.8.1).</para>

      <para>Only an administrator may use these commands.</para>
    </section>

    <section id="call-section">
      <title id="call-title">CALL</title>

      <programlisting>CALL <link linkend="expression-section">Expression</link>;</programlisting>

      <para>Any expression can be called like a stored procedure, including,
      but not only Java stored procedures or functions. This command returns a
      ResultSet with one column and one row (the result) just like a SELECT
      statement with one row and one column.</para>

      <para>See also: <link endterm="stored-title"
      linkend="stored-section" />, <link endterm="expression-title"
      linkend="expression-section" />.</para>
    </section>

    <section id="checkpoint-section">
      <title id="checkpoint-title">CHECKPOINT</title>

      <programlisting>CHECKPOINT [DEFRAG<footnoteref linkend="posthyper" />];</programlisting>

      <para>Closes the database files, rewrites the script file, deletes the
      log file and opens the database.</para>

      <para>If DEFRAG is specified, this command also shrinks the .data file
      to its minimal size.</para>

      <para>See also: <link endterm="shutdown-title"
      linkend="shutdown-section" />, <link endterm="set_logsize-title"
      linkend="set_logsize-section" />.</para>
    </section>

    <section id="commit-section">
      <title id="commit-title">COMMIT</title>

      <programlisting>COMMIT [WORK];</programlisting>

      <para>Ends a transaction and makes the changes permanent.</para>

      <para>See also: <link endterm="rollback-title"
      linkend="rollback-section" />, <link endterm="set_autocommit-title"
      linkend="set_autocommit-section" />, <link endterm="set_logsize-title"
      linkend="set_logsize-section" />.</para>
    </section>

    <section id="connect-section">
      <title id="connect-title">CONNECT</title>

      <programlisting>CONNECT USER &lt;username&gt; PASSWORD &lt;password&gt;;</programlisting>

      <para>Connects to the database as a different user. Password should be
      double quoted. Use "" for an empty password.</para>

      <para>See also: <link endterm="grant-title" linkend="grant-section" />,
      <link endterm="revoke-title" linkend="revoke-section" />.</para>
    </section>

    <section id="create_alias-section">
      <title id="create_alias-title">CREATE ALIAS</title>

      <programlisting>CREATE ALIAS &lt;function&gt; FOR &lt;javaFunction&gt;;</programlisting>

      <para>Creates an alias for a static Java function to be used as a
          <link linkend="stored-section">Stored Procedure</link>.
          The function must be accessible from the JVM in which the database 
          runs. Example:</para>

      <informalexample>
        <programlisting>    CREATE ALIAS ABS FOR "java.lang.Math.abs";</programlisting>
      </informalexample>
      <note><simpara>
          The CREATE ALIAS command just defines the alias.
          It does not validate existence of the target method or its 
          containing class.
          To validate the alias, use it.
      </simpara></note>

      <para>See also: <link endterm="call-title" linkend="call-section" />,
      <link endterm="stored-title" linkend="stored-section" />.</para>
    </section>

    <section id="create_index-section">
      <title id="create_index-title">CREATE INDEX</title>

      <programlisting>CREATE [UNIQUE] INDEX &lt;index&gt; ON &lt;table&gt; (&lt;column&gt; [DESC] [, ...]) [DESC];</programlisting>

      <para>Creates an index on one or more columns in a table.</para>

      <para>Creating an index on searched columns may improve performance. The
      qualifier DESC can be present for command compatibility with other
      databases but it has no effect. Unique indexes can be defined but this
      is deprecated. Use UNIQUE constraints instead. The name of an index must
      be unique within the whole database.</para>

      <para>See also: <link endterm="create_table-title"
      linkend="create_table-section" />, <link endterm="drop_index-title"
      linkend="drop_index-section" />.</para>
    </section>

    <section id="create_role-section">
      <title id="create_role-title">CREATE ROLE<footnoteref
      linkend="posthyper" /></title>

      <programlisting>CREATE ROLE &lt;rolename&gt;;</programlisting>

      <para>Creates the named role with no members. Requires Administrative
      privileges.</para>
    </section>

    <section>
      <title>CREATE SCHEMA<footnoteref linkend="posthyper" /></title>

      <programlisting>CREATE SCHEMA &lt;schemaname&gt; AUTHORIZATION &lt;grantee&gt;
    [&lt;createStatement&gt; [&lt;grantStatement&gt;] [...];</programlisting>

      <para>Creates the named schema, with ownership of the specified
      <emphasis>authorization</emphasis>. The authorization grantee may be a
      database user or a role.</para>

      <para>Optional (nested) CREATE and GRANT statements can be given only
      for new objects in this new schema. Only the last nested statement
      should be terminated with a semicolon, because the first semicolon
      encountered after "CREATE SCHEMA" will end the CREATE SCHEMA command. In
      the example below, a new schema, ACCOUNTS, is created, then two tables
      and a view are added to this schma and some rights on these objects are
      granted.<informalexample>
          <programlisting>    CREATE SCHEMA ACCOUNTS AUTHORIZATION DBA
        CREATE TABLE AB(A INTEGER, ...)
        CREATE TABLE CD(C CHAHR, ...)
        CREATE VIEW VI AS SELECT ...
        GRANT SELECT TO PUBLIC ON AB
        GRANT SELECT TO JOE ON CD;
</programlisting>
        </informalexample>
        Note that this example consists of one CREATE SCHEMA statement which
        is terminated by a semicolon.
    </para>

      <simpara>Requires Administrative privileges.</simpara>
    </section>

    <section id="create_sequence-section">
      <title id="create_sequence-title">CREATE SEQUENCE<footnoteref
      linkend="posthyper" /></title>

      <programlisting>CREATE SEQUENCE &lt;sequencename&gt; [AS {INTEGER | BIGINT}]
    [START WITH &lt;startvalue&gt;] [INCREMENT BY &lt;incrementvalue&gt;];</programlisting>

      <para>Creates a sequence. The default type is INTEGER. The default start
      value is 0 and the increment 1. Negative values are not allowed. If a
      sequence goes beyond Integer.MAXVALUE or Long.MAXVALUE, the next result
      is determined by 2's complement arithmetic.</para>

      <para>The next value for a sequence can be included in SELECT, INSERT
      and UPDATE statements as in the following example:</para>

      <para>
        <informalexample>
          <programlisting>SELECT [...,] NEXT VALUE FOR &lt;sequencename&gt; [, ...] FROM &lt;tablename&gt;;</programlisting>
        </informalexample>
      </para>

      <para>In the proposed SQL 200n and in the current version, there is no
      way of retreiving the last returned value of a sequence.</para>
    </section>

    <section id="create_table-section">
      <title id="create_table-title">CREATE TABLE</title>

      <programlisting>CREATE [MEMORY | CACHED | [GLOBAL] TEMPORARY | TEMP <footnoteref
          linkend="posthyper" /> | TEXT<footnoteref linkend="posthyper" />] TABLE &lt;name&gt;
    ( &lt;columnDefinition&gt; [, ...] [, &lt;constraintDefinition&gt;...] )
    [ON COMMIT {DELETE | PRESERVE} ROWS];</programlisting>

      <para>Creates a tables in memory (default) or on disk and only cached in
      memory. If the database is all-in-memory, both MEMORY and CACHED forms
      of CREATE TABLE return a MEMORY table while the TEXT form is not
      allowed.</para>

      <variablelist>
        <title>Components of a CREATE TABLE command</title>

        <varlistentry id="columnDef-entry">
            <!-- N.b.!!!!  Put NO whitespace immediately after programlisting
               tags, because the way DocBook formats the itemlist in PDF, we
               have no whitespare to waste to fit the examples in the 
               horizontal space. -->
          <term id="columnDef-title">columnDefinition</term>

          <listitem>
              <programlisting>columnname <link linkend="datatypes-section">Datatype</link> [(columnSize[,precision])]
    [{DEFAULT &lt;defaultValue&gt; |
    GENERATED BY DEFAULT AS IDENTITY
    (START WITH &lt;n&gt;[, INCREMENT BY &lt;m&gt;])}] |
    [[NOT] NULL] [IDENTITY] [PRIMARY KEY]</programlisting>

            <para>Default values that are allowed are constant values or
            certain SQL datetime functions.</para>

            <itemizedlist>
              <title>Allowed Default Values in Column Definitions</title>

              <listitem>
                <para>For character column, a single-quoted string or NULL.
                The only SQL function that can be used is CURRENT_USER.</para>
              </listitem>

              <listitem>
                <para>For datetime columns, a single-quoted DATE, TIME or
                TIMESTAMP value or NULL. Or a datetime SQL function such as
                CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP, TODAY, NOW.
                Each function is allowed for a certain datetime type.</para>
              </listitem>

              <listitem>
                <para>For BOOLEAN columns, the literals FALSE, TRUE,
                NULL.</para>
              </listitem>

              <listitem>
                <para>For numeric columns, any valid number or NULL.</para>
              </listitem>

              <listitem>
                <para>For binary columns, any valid hex string or NULL.</para>
              </listitem>
            </itemizedlist>

            <para>Only one identity column is allowed in each table. Identity
            columns are autoincrement columns. They must be of INTEGER or
            BIGINT type and are automatically primary key columns (as a
            result, multi-column primary keys are not possible with an
            IDENTITY column present). Using the long SQL syntax the (START
            WITH &lt;n&gt;) clause specifies the first value that will be
            used. The last inserted value into an identity column for a
            connection is available using the function IDENTITY(), for example
            (where Id is the identity column):</para>

            <informalexample>
              <programlisting>INSERT INTO Test (Id, Name) VALUES (NULL,'Test');
    CALL IDENTITY();</programlisting>
            </informalexample>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>constraintDefinition</term>

          <listitem>
            <programlisting>[CONSTRAINT &lt;name&gt;]
    UNIQUE ( &lt;column&gt; [,&lt;column&gt;...] ) |
    PRIMARY KEY ( &lt;column&gt; [,&lt;column&gt;...] ) |
    FOREIGN KEY ( &lt;column&gt; [,&lt;column&gt;...] )
    REFERENCES &lt;refTable&gt; ( &lt;column&gt; [,&lt;column&gt;...]) 
    [ON {DELETE | UPDATE}
    {CASCADE | SET DEFAULT | SET NULL}]<footnoteref linkend="posthyper" /> |
    CHECK(&lt;search condition&gt;)<footnoteref linkend="posthyper" /></programlisting>

            <para>Both ON DELETE and ON UPDATE clauses can be used in a single
            foreign key definition.</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>search condition</term>

          <listitem>
            <para>A search condition is similar to the set of conditions in a
            WHERE clause. In the current version of HSQLDB, the conditions for
            a CHECK constraint can only reference the current row, meaning
            there should be no SELECT statement. Sample table definitions with
            CHECK constraints are in <!-- Would be nice to link to this, but there's no copy
                         under the doc directory. -->
            <literal>TestSelfCheckConstraints.txt</literal>. This file is in
            the /hsqldb/testrun/hsqldb/ directory of the zip.</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>General syntax limitations</term>

          <listitem>
            <para>HSQLDB databases are initially created in a legacy mode that
            does not enforce column size and precision. You can set the
            property: <code>sql.enforce_strict_size=true</code> to enable this
            feature. When this property has been set, Any supplied column size
            and precision for numeric and character types (CHARACTER and
            VARCHAR) are enforced. Use the command, <code>SET PROPERTY
            "sql.enforce_strict_size" TRUE</code> once before defining the
            tables.</para>

            <para>NOT NULL constraints can be part of the column definition
            only. Other constraints cannot be part of the column definition
            and must appear at the end of the column definition list.</para>

            <para>TEMPORARY TABLE contents for each session (connection) are
            emptied by default at each commit or rollback. The optional
            qualifier ON COMMIT PRESERVE ROWS can be used to keep the rows
            while the session is open. The default is ON COMMIT DELETE
            ROWS.</para>
          </listitem>
        </varlistentry>
      </variablelist>

      <para>See also: <link endterm="drop_table-title"
      linkend="drop_table-section" />.</para>
    </section>

    <section id="create_trigger-section">
      <title id="create_trigger-title">CREATE TRIGGER<footnoteref
      linkend="posthyper" /></title>

      <programlisting>CREATE TRIGGER &lt;name&gt; {BEFORE | AFTER} {INSERT | UPDATE | DELETE} ON &lt;table&gt;
    [FOR EACH ROW] [QUEUE n] [NOWAIT] CALL &lt;TriggerClass&gt;;</programlisting>

      <para>TriggerClass is an application-supplied class that implements the
      <classname>org.hsqldb.Trigger</classname> interface e.g.
      "mypackage.TrigClass". It is the fire method of this class that is
      invoked when the trigger event occurs. You should provide this class,
      which can have any name, and ensure that this TriggerClass is present in
      the classpath which you use to start hsqldb.</para>

      <para>Since 1.7.2 the implementation has been changed and enhanced. When
      the 'fire' method is called, it is passed the following
      arguments:</para>

      <informalexample>
        <programlisting>    fire (String name, String table, Object row1[], Object row2[])
</programlisting>
      </informalexample>

      <para>where 'row1' and 'row2' represent the 'before' and 'after' states
      of the row acted on, with each column being a member of the array. The
      mapping of members of the row arrays to database types is specified in
      <link endterm="datatypes-title" linkend="datatypes-section" />. For
      example, BIGINT is represented by a <filename>java.lang.Long
      Object</filename>. Note that the number of elements in the row arrays
      could be larger than the number of columns by one or two elements. Never
      modify the last elements of the array, which are not part of the actual
      row.</para>

      <para>If the trigger method wants to access the database, it must
      establish its own JDBC connection. This can cause data inconsistency and
      other problems so it is not recommended. The
      <literal>jdbc:default:connection:</literal> URL is not currently
      supported.</para>

      <para>Implementation note:</para>

      <para>If QUEUE 0 is specified, the fire method is execued in the same
      thread as the database engine. This allows trigger action to alter the
      data that is about to be stored in the database. Data can be checked or
      modified in BEFORE INSERT / UPDATE + FOR EACH ROW triggers. All table
      constraints are then enforced by the database engine and if there is a
      violation, the action is rejected for the SQL command that initiated the
      INSERT or UPDATE. There is an exception to this rule, that is with
      UPDATE queries, referential integrity and cascading actions resulting
      from ON UPDATE CASCASE / SET NULL / SET DEFAULT are all performed prior
      to the invocation of the trigger method. If an invalid value that breaks
      referential integrity is inserted in the row by the trigger method, this
      action is not checked and results in inconsistent data in the
      table.</para>

      <para>Alternatively, if the trigger is used for external communications
      and not for checking or altering the data, a queue size larger than zero
      can be specified. This is in the interests of not blocking the
      database's main thread as each trigger will run in a thread that will
      wait for its firing event to occur. When this happens, the trigger's
      thread calls TriggerClass.fire. There is a queue of events waiting to be
      run by each trigger thread. This is particularly useful for 'FOR EACH
      ROW' triggers, when a large number of trigger events occur in rapid
      succession, without the trigger thread getting a chance to run. If the
      queue becomes full, subsequent additions to it cause the database engine
      to suspend awaiting space in the queue. Take great care to avoid this
      situation if the trigger action involves accessing the database, as
      deadlock will occur. This can be avoided either by ensuring the QUEUE
      parameter makes a large enough queue, or by using the NOWAIT parameter,
      which causes a new trigger event to overwrite the most recent event in
      the queue. The default queue size is 1024. Note also that the timing of
      trigger method calls is not guaranteed, so applications should implement
      their own synchronization measures if necessary.</para>

      <para>With a non-zero QUEUE parameter, if the trigger methods modifies
      the 'row2' values, these changes may or may not affect the database and
      will almost certainly result in data inconsistency.</para>

      <para>Please refer to the code for <ulink
          url="../src/org/hsqldb/Trigger.html">
          <classname>org.hsqldb.sample.Trigger</classname>
        </ulink> and <ulink url="../src/org/hsqldb/sample/TriggerSample.html">
          <classname>org.hsqldb.sample.TriggerSample</classname>
        </ulink> for more information on how to write a trigger class.</para>

      <para>See also: <link endterm="drop_trigger-title"
      linkend="drop_trigger-section" />.</para>
    </section>

    <section id="create_user-section">
      <title id="create_user-title">CREATE USER</title>

      <programlisting>CREATE USER &lt;username&gt; PASSWORD &lt;password&gt; [ADMIN];</programlisting>

      <para>Creates a new user or new administrator in this database. Password
      must be double quoted. Empty password can be made using "". You can
      change a password afterwards using a <link endterm="alter_user-title"
      linkend="alter_user-section" /> command.</para>

      <para>Only an administrator can do this.</para>

      <para>See also: <link endterm="connect-title"
      linkend="connect-section" />, <link endterm="grant-title"
      linkend="grant-section" />, <link endterm="revoke-title"
      linkend="revoke-section" />. <link endterm="alter_user-title"
      linkend="alter_user-section" />,</para>
    </section>

    <section id="create_view-section">
      <title id="create_view-title">CREATE VIEW<footnoteref
      linkend="posthyper" /></title>

      <programlisting>CREATE VIEW &lt;viewname&gt;[(&lt;viewcolumn&gt;,..) AS SELECT ... FROM ... [WHERE Expression]
[ORDER BY orderExpression [, ...]]
[LIMIT &lt;limit&gt; [OFFSET &lt;offset&gt;]];</programlisting>

      <para>A view can be thought of as either a virtual table or a stored
      query. The data accessible through a view is not stored in the database
      as a distinct object. What is stored in the database is a SELECT
      statement. The result set of the SELECT statement forms the virtual
      table returned by the view. A user can use this virtual table by
      referencing the view name in SQL statements the same way a table is
      referenced. A view is used to do any or all of these functions:</para>

      <itemizedlist>
        <listitem>
          <para>Restrict a user to specific rows in a table. For example,
          allow an employee to see only the rows recording his or her work in
          a labor-tracking table.</para>
        </listitem>

        <listitem>
          <para>Restrict a user to specific columns. For example, allow
          employees who do not work in payroll to see the name, office, work
          phone, and department columns in an employee table, but do not allow
          them to see any columns with salary information or personal
          information.</para>
        </listitem>

        <listitem>
          <para>Join columns from multiple tables so that they look like a
          single table.</para>
        </listitem>

        <listitem>
          <para>Aggregate information instead of supplying details. For
          example, present the sum of a column, or the maximum or minimum
          value from a column.</para>
        </listitem>
      </itemizedlist>

      <para>Views are created by defining the SELECT statement that retrieves
      the data to be presented by the view. The data tables referenced by the
      SELECT statement are known as the base tables for the view. In this
      example, is a view that selects data from three base tables to present a
      virtual table of commonly needed data:</para>

      <informalexample>
        <programlisting>    CREATE VIEW mealsjv AS
      SELECT m.mid mid, m.name name, t.mealtype mt, a.aid aid,
             a.gname + ' ' + a.sname author, m.description description,
             m.asof asof
        FROM meals m, mealtypes t, authors a
       WHERE m.mealtype = t.mealtype
        AND m.aid = a.aid;</programlisting>
      </informalexample>

      <para>You can then reference mealsjv in statements in the same way you
      would reference a table:</para>

      <informalexample>
        <programlisting>    SELECT * FROM mealsjv;</programlisting>
      </informalexample>

      <para>A view can reference another view. For example, mealsjv presents
      information that is useful for long descriptions that contain
      identifiers, but a short list might be all a web page display needs. A
      view can be built that selects only specific mealsjv columns:</para>

      <informalexample>
        <programlisting>    CREATE VIEW mealswebv AS SELECT name, author FROM mealsjv;</programlisting>
      </informalexample>

      <para>The SELECT statement in a VIEW definition should return columns
      with distinct names. If the names of two columns in the SELECT statement
      are the same, use a column alias to distinguish between them. A list of
      new column names can always be defined for a view.</para>

      <informalexample>
        <programlisting>    CREATE VIEW aview (new_name, new_author) AS
      SELECT name, author
      FROM mealsjv</programlisting>
      </informalexample>

      <para>See also: <link endterm="expression-title"
      linkend="expression-section" />, <link endterm="select-title"
      linkend="select-section" />, <link endterm="drop_view-title"
      linkend="drop_view-section" />.</para>
    </section>

    <section id="delete-section">
      <title id="delete-title">DELETE</title>

      <programlisting>DELETE FROM table [WHERE Expression];</programlisting>

      <para>Removes rows in a table.</para>

      <para>See also: <link endterm="expression-title"
      linkend="expression-section" />, <link endterm="insert-title"
      linkend="insert-section" />, <link endterm="select-title"
      linkend="select-section" />.</para>
    </section>

    <section id="disconnect-section">
      <title id="disconnect-title">DISCONNECT</title>

      <programlisting>DISCONNECT;</programlisting>

      <para>Closes this connection. It is not required to call this command
      when using the JDBC interface: it is called automatically when the
      connection is closed. After disconnecting, it is not possible to execute
      other queries (including CONNECT) with this connection.</para>

      <para>See also: <link endterm="connect-title"
      linkend="connect-section" />.</para>
    </section>

    <section id="drop_index-section">
      <title id="drop_index-title">DROP INDEX</title>

      <programlisting>DROP INDEX index [IF EXISTS];</programlisting>

      <para>Removes the specified index from the database. Will not work if
      the index backs a UNIQUE of FOREIGN KEY constraint.</para>

      <para>See also: <link endterm="create_index-title"
      linkend="create_index-section" />.</para>
    </section>

    <section>
      <title>DROP ROLE<footnoteref linkend="posthyper" /></title>

      <programlisting>DROP ROLE &lt;rolename&gt;;</programlisting>

      <para>Removes all members from specified role, then removes the role
      itself.</para>
    </section>

    <section id="drop_sequence-section">
      <title id="drop_sequence-title">DROP SEQUENCE<footnoteref
      linkend="posthyper" /></title>

      <programlisting>DROP SEQUENCE &lt;sequencename&gt; [IF EXISTS] [RESTRICT | CASCADE];</programlisting>

      <para>Removes the specified sequence from the database. When IF EXIST is
      used, the statement returns without an error if the sequence does not
      exist. The RESTRICT option is in effect by default, meaning that DROP
      will fail if any view reference the sequence. Specify the
      <literal>CASCADE</literal> option to silently drop all dependent
      database objects.</para>
    </section>

    <section>
      <title>DROP SCHEMA<footnoteref linkend="posthyper" /></title>

      <programlisting>DROP SCHEMA &lt;schemaname&gt; [RESTRICT | CASCADE];</programlisting>

      <para>Removes the specified schema from the database. The RESTRICT
      option is in effect by default, meaning that DROP will fail if any
      objects such as tables or sequences have been defined in the schema.
      Specify the <literal>CASCADE</literal> option to silently drop all
      database objects in the schema.</para>

      <simpara>Requires Administrative privileges.</simpara>
    </section>

    <section id="drop_table-section">
      <title id="drop_table-title">DROP TABLE</title>

      <programlisting>DROP TABLE &lt;table&gt; [IF EXISTS] [RESTRICT | CASCADE];</programlisting>

      <para>Removes a table, the data and indexes from the database. When IF
      EXIST is used, the statement returns without an error even if the table
      does not exist.</para>

      <para>The RESTRICT option is in effect by default, meaning that DROP
      will fail if any tables or views refer to this table. Specify the
      <literal>CASCADE</literal> option to silently drop all dependent views,
      and to drop any foreign key constraint that links this table with other
      tables.</para>

      <simpara>See also:</simpara>

      <simpara><link endterm="create_table-title"
      linkend="create_table-section" />.</simpara>
    </section>

    <section id="drop_trigger-section">
      <title id="drop_trigger-title">DROP TRIGGER</title>

      <programlisting>DROP TRIGGER &lt;trigger&gt;;</programlisting>

      <para>Removes a trigger from the database.</para>

      <para>See also: <link endterm="create_trigger-title"
      linkend="create_trigger-section" />.</para>
    </section>

    <section id="drop_user-section">
      <title id="drop_user-title">DROP USER</title>

      <programlisting>DROP USER &lt;username&gt;;</programlisting>

      <para>Removes a user from the database.</para>

      <para>Only an administrator do this.</para>

      <para>See also: <link endterm="create_user-title"
      linkend="create_user-section" />.</para>
    </section>

    <section id="drop_view-section">
      <title id="drop_view-title">DROP VIEW<footnoteref
      linkend="posthyper" /></title>

      <programlisting>DROP VIEW &lt;viewname&gt; [IF EXISTS] [RESTRICT | CASCADE];</programlisting>

      <para>Removes a view from the database. When IF EXIST is used, the
      statement returns without an error if the view does not exist. The
      RESTRICT option is in effect by default, meaning that DROP will fail if
      any other view refers to this view. Specify the
      <literal>CASCADE</literal> option to silently drop all dependent
      views.</para>

      <para>See also: <link endterm="create_view-title"
      linkend="create_view-section" />.</para>
    </section>

    <section id="explain-section">
      <title id="explain-title">EXPLAIN PLAN</title>

      <programlisting>EXPLAIN PLAN FOR { SELECT ... | DELETE ... | INSERT ... | UPDATE ..};</programlisting>

      <para>EXPLAIN PLAN FOR can be used with any query to get a detailed list
      of the elements in the execution plan.</para>

      <para>This list includes the indexes used for performing the query and
      can be used to optimise the query or to add indexes to tables.</para>
    </section>

    <section id="grant-section">
      <title id="grant-title">GRANT</title>

      <programlisting>GRANT { SELECT | DELETE | INSERT | UPDATE | ALL } [,...]
ON { table | CLASS "package.class" } TO &lt;grantee&gt;;</programlisting>

      <programlisting>GRANT &lt;rolename&gt; [,...] TO &lt;grantee&gt;<footnoteref
          linkend="posthyper" />;</programlisting>

      <para>&lt;grantee&gt; is either a user name, a role name, or
      <literal>PUBLIC</literal>. <literal>PUBLIC</literal> means <emphasis>all
      users</emphasis>.</para>

      <para>The first form of the GRANT command assigns privileges to a
      grantee for a table or for a class. To allow a user to call a 
      <link linkend="stored-section">Store Procedure</link> static
      function, the right ALL must be used. Examples: <informalexample>
          <programlisting>    GRANT SELECT ON Test TO GUEST;
    GRANT ALL ON CLASS "java.lang.Math.abs" TO PUBLIC;</programlisting>
        </informalexample></para>
      <warning><simpara>
          Even though the command is GRANT ALL ON CLASS, you must
          specify a static <emphasis>method name</emphasis>.  You are actually
          granting access to a static method, not to a class.
      </simpara></warning>

      <para>The second form of the GRANT command gives the specified
      &lt;grantee&gt; membership in the specified role.</para>

      <simpara>Requires Administrative privileges.</simpara>

      <simpara>See also: <link endterm="revoke-title"
      linkend="revoke-section" />, <link endterm="create_user-title"
      linkend="create_user-section" />, <link endterm="create_role-title"
      linkend="create_role-section" />.</simpara>
    </section>

    <section id="insert-section">
      <title id="insert-title">INSERT</title>

      <programlisting>INSERT INTO table [( column [,...] )]
{ VALUES(<link linkend="expression-section">Expression</link> [,...]) | <link
          linkend="select-section">SelectStatement</link>};</programlisting>

      <para>Adds one or more new rows of data into a table.</para>
    </section>

    <section id="revoke-section">
      <title id="revoke-title">REVOKE</title>

      <programlisting>REVOKE { SELECT | DELETE | INSERT | UPDATE | ALL } [,...]
ON { table | CLASS "package.class" } FROM &lt;grantee&gt;;</programlisting>

      <programlisting>REVOKE &lt;rolename&gt; [,...] FROM &lt;grantee&gt;<footnoteref
          linkend="posthyper" />;</programlisting>

      <para>&lt;grantee&gt; is either a user name, a role name, or
      <literal>PUBLIC</literal>. <literal>PUBLIC</literal> means <emphasis>all
      users</emphasis>.</para>

      <para>The first form of the REVOKE command withdraws privileges from a
      grantee for a table or for a class.</para>

      <para>The second form of the REVOKE command withdraws membership of the
      specified &lt;grantee&gt; from the specified role.</para>

      <simpara>Both forms require Administrative privileges.</simpara>

      <simpara>See also: <link endterm="grant-title"
      linkend="grant-section" />.</simpara>
    </section>

    <section id="rollback-section">
      <title id="rollback-title">ROLLBACK</title>

      <programlisting>ROLLBACK [TO SAVEPOINT &lt;savepoint name&gt;<footnoteref
          linkend="posthyper" /> |  WORK}];</programlisting>

      <para>ROLLBACK used on its own, or with WORK, undoes changes made since
      the last COMMIT or ROLLBACK.</para>

      <para><literal>ROLLBACK TO SAVEPOINT &lt;savepoint name&gt;</literal>
      undoes the change since the named savepoint. It has no effect if the
      savepoint is not found.</para>

      <para>See also: <link endterm="commit-title"
      linkend="commit-section" />.</para>
    </section>

    <section id="savepoint-section">
      <title id="savepoint-title">SAVEPOINT<footnoteref
      linkend="posthyper" /></title>

      <programlisting>SAVEPOINT &lt;savepoint name&gt;;</programlisting>

      <para>Sets up a SAVEPOINT for use with ROLLBACK TO SAVEPOINT.</para>

      <para>See also: <link endterm="commit-title"
      linkend="commit-section" />.</para>
    </section>

    <section id="script-section">
      <title id="script-title">SCRIPT</title>

      <programlisting>SCRIPT ['file'];</programlisting>

      <para>Creates an SQL script describing the database. If the file is not
      specified, a result set containing only the DDL script is returned. If
      the file is specified then this file is saved with the path relative to
      the machine where the database engine is located.</para>

      <para>Only an administrator may do this.</para>
    </section>

    <section id="select-section">
      <title id="select-title">SELECT<footnoteref
      linkend="posthyper" /></title>

      <programlisting>SELECT [{LIMIT &lt;offset&gt; &lt;limit&gt; | TOP &lt;limit&gt;}<footnoteref
          linkend="posthyper" />][ALL | DISTINCT]
{ selectExpression | table.* | * } [, ...]
[INTO [CACHED | TEMP  | TEXT]<footnoteref linkend="posthyper" /> newTable]
FROM tableList
[WHERE <link linkend="expression-section">Expression</link>]
[GROUP BY Expression [, ...]]
[HAVING Expression]
[{ UNION [ALL | DISTINCT] | {MINUS [DISTINCT] | EXCEPT [DISTINCT] } |
INTERSECT [DISTINCT] } selectStatement]
[ORDER BY orderExpression [, ...]]
[LIMIT &lt;limit&gt; [OFFSET &lt;offset&gt;]];</programlisting>

      <para>Retrieves information from one or more tables in the
      database.</para>

      <variablelist>
        <title>Components of a SELECT command</title>

        <varlistentry>
            <!-- N.b.!!!!  Put NO whitespace immediately after programlisting
               tags, because the way DocBook formats the itemlist in PDF, we
               have no whitespare to waste to fit the examples in the 
               horizontal space. -->
          <term>tableList</term>

          <listitem>
              <programlisting>table [{CROSS | INNER | LEFT OUTER | RIGHT OUTER}
    JOIN table ON Expression] [, ...]</programlisting>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>table</term>

          <listitem>
            <programlisting>{ (selectStatement) [AS] label | tableName}</programlisting>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>selectExpression</term>

          <listitem>
              <programlisting>{ Expression | COUNT(*) | {
    COUNT | MIN | MAX | SUM | AVG | SOME | EVERY |
    VAR_POP | VAR_SAMP | STDDEV_POP | STDDEV_SAMP
} ([ALL | DISTINCT]<footnoteref
            linkend="posthyper" />] Expression) } [[AS] label]</programlisting>

            <para>If DISTINCT is specified, only one instance of several
            equivalent values is used in the aggregate function. Except
            COUNT(*), all aggregate functions exclude NULL values. The type of
            the returned value for SUM is subject to deterministic widenning
            to ensure lossless results. The returned value type for COUNT is
            INTEGER, for MIN, MAX and AVG it is the same type as the column,
            for SOME and EVERY it is BOOLEAN. For VAR_POP, VAR_SAMP,
            STDDEV_POP and STDDEV_SAMP statistical functions, the type is
            always DOUBLE. These statistical functions do not allow ALL or
            DISTINCT qualifiers.</para>

            <para>If CROSS JOIN is specified no ON expression is allowed for
            the join.</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>orderExpression</term>

          <listitem>
              <programlisting>{ columnNr | columnAlias | selectExpression }
    [ASC | DESC]</programlisting>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>LIMIT n m</term>

          <listitem>
            <para>Creates the result set for the SELECT statement first and
            then discards the first n rows (OFFSET) and returns the first m
            rows of the remaining result set (LIMIT). Special cases: LIMIT 0 m
            is equivalent to TOP m or FIRST m in other RDBMS's; LIMIT n 0
            discards the first n rows and returns the rest of the result
            set.</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>LIMIT m OFFSET n</term>

          <listitem>
            <para>This form is used at the end of the SELECT statement. The
            OFFSET term is optional.</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>TOP m</term>

          <listitem>
            <para>Equivalent to LIMIT 0 m.</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>UNION and other set operations</term>

          <listitem>
            <para>Multiple SELECT statements joined with UNION, EXCEPT and
            INTERSECT are possible. Each SELECT is then treated as a term, and
            the set operation as an operator in an expression. The expression
            is evaluated from left to right but INTERSECT takes precedence
            over the rest of the operators and is applied first. You can use
            parentheses around any number of SELECT statements to change the
            evaluation order.</para>
          </listitem>
        </varlistentry>
      </variablelist>

      <para>See also: <link endterm="insert-title"
      linkend="insert-section" />, <link endterm="update-title"
      linkend="update-section" />, <link endterm="delete-title"
      linkend="delete-section" />.</para>
    </section>

    <section id="set_autocommit-section">
      <title id="set_autocommit-title">SET AUTOCOMMIT</title>

      <programlisting>SET AUTOCOMMIT { TRUE | FALSE };</programlisting>

      <para>Switches on or off the connection's auto-commit mode. If switched
      on, then all statements will be committed as individual transactions.
      Otherwise, the statements are grouped into transactions that are
      terminated by either <link linkend="commit-section">COMMIT</link> or
      <link linkend="rollback-section">ROLLBACK</link>. By default, new
      connections are in auto-commit mode. This command should not be used
      directly. Use the JDBC equivalent method,
      Connection.setAutoCommit(boolean autocommit).</para>
    </section>

    <section id="collation-section">
      <title id="collation-title">SET DATABASE COLLATION<footnoteref
      linkend="posthyper" /></title>

      <programlisting>SET DATABASE COLLATION &lt;double quoted collation name&gt;;</programlisting>

      <para>Each database can have its own collation. Sets the collation from
      the set of collations in the source for org.hsqldb.Collation.
      </para>

      <para>Once this command has been issued, the database can be opened in
      any JVM and will retain its collation.</para>
    </section>

    <section>
      <title>SET CHECKPOINT DEFRAG<footnoteref linkend="posthyper" /></title>

      <programlisting>SET CHECKPOINT DEFRAG &lt;size&gt;;</programlisting>

      <para>The parameter <literal>size</literal> is the megabytes of
      abandoned space in the .data file. When a CHECKPOINT is performed either
      as a result of the .log file reaching the limit set by "SET LOGSIZE
      size", or by the user issuing a CHECKPOINT command, the amount of space
      abandoned during the session is checked and if it is larger than size, a
      CHECKPOINT DEFRAG is performed instead of a checkpoint.</para>
    </section>

    <section id="set_ignorecase-section">
      <title id="set_ignorecase-title">SET IGNORECASE</title>

      <programlisting>SET IGNORECASE { TRUE | FALSE };</programlisting>

      <para>Disables (ignorecase = true) or enables (ignorecase = false) the
      case sensitivity of text comparison and indexing for new tables. By
      default, character columns in new databases are case sensitive. The
      sensitivity must be switched before creating tables. Existing tables and
      their data are not affected. When switched on, the data type VARCHAR is
      set to <literal>VARCHAR_IGNORECASE</literal> in new tables.
      Alternatively, you can specify the <literal>VARCHAR_IGNORECASE</literal>
      type for the definition of individual columns. So it is possible to have
      some columns case sensitive and some not, even in the same table.</para>

      <para>Only an administrator may do this.</para>
    </section>

    <section id="set_initialschema-section">
      <title id="set_initialschema-title">SET INITIAL SCHEMA <footnoteref
      linkend="posthyper" /></title>

      <para>Users may change their base default schema name with the comand
      <programlisting>SET INITIAL SCHEMA &lt;schemaname&gt;;</programlisting>
      This is the schema which database object names will resolve to for the
      current user, unless overridden as explained in <link
      endterm="schemanaming-title" linkend="schemanaming-section" />. For
      reasons of backwards compatibility, the initial schema value will not be
      persisted across database shutdowns until HSQLDB version 1.8.1. (I.e.,
      INITIAL SCHEMA settings will be lost upon database shutdown with HSQLDB
      versions lower than version 1.8.1).</para>
    </section>

    <section id="set_logsize-section">
      <title id="set_logsize-title">SET LOGSIZE</title>

      <programlisting>SET LOGSIZE &lt;size&gt;;</programlisting>

      <para>Sets the maximum size in MB of the .log file. Default is 200 MB.
      The database will be closed and opened (just like using CHECKPOINT) if
      the .log file gets over this limit, and so the .log file will shrink. 0
      means no limit.</para>

      <para>See also: <link endterm="checkpoint-title"
      linkend="checkpoint-section" />.</para>
    </section>

    <section id="set_password-section">
      <title id="set_password-title">SET PASSWORD</title>

      <programlisting>SET PASSWORD &lt;password&gt;;</programlisting>

      <para>Changes the password of the currently connected user. Password
      must be double quotedEmpty password can be set using "".</para>
    </section>

    <section id="set_property-section">
      <title id="set_property-title">SET PROPERTY<footnoteref
      linkend="posthyper" /></title>

      <programlisting>SET PROPERTY &lt;double quoted name&gt; &lt;value&gt;;</programlisting>

      <para>Sets a database property. Properties that can be set using this
      command are either boolean or integral and are listed in the <link
      endterm="advanced-title" linkend="advanced-chapter" /> chapter.</para>
    </section>

    <section id="set_refint-section">
      <title id="set_refint-title">SET REFERENTIAL INTEGRITY</title>

      <programlisting>SET REFERENTIAL_INTEGRITY { TRUE | FALSE };</programlisting>

      <para>This commands enables / disables the referential integrity
      checking (foreign keys). Normally it should be switched on (this is the
      default) but when importing data (and the data is imported in the
      'wrong' order) the checking can be switched off.</para>

      <warning>
        <para>Note that when referential integrity is switched back on, no
        check is made that the changes to the data are consistent with the
        existing referential integrity constraints. You can verify consistency
        using SQL queries and take appropriate actions.</para>
      </warning>

      <para>Only an administrator may do this.</para>

      <para>See also: <link endterm="create_table-title"
      linkend="create_table-section" />.</para>
    </section>

    <section id="set_schema-section">
      <title id="set_schema-title">SET SCHEMA<footnoteref
      linkend="posthyper" /></title>

      <programlisting>SET SCHEMA &lt;schemaname&gt;;</programlisting>

      <para>Sets the current JDBC session's schema. The sole purpose for the
      session schema is to provide a default schema name for schema objects
      that do not have the schema name specified explicitly in the SQL
      command, or by association with another object of known schema. For
      example, if you run <literal>SELECT * FROM atbl;</literal>, HSQLDB will
      look for the table or view named <literal>atbl</literal> in the
      session's current schema.</para>

      <para>Session schemas last only for the duration of the current session.
      When a new JDBC session is obtained, the new session will have the
      default schema.</para>
    </section>

    <section id="set_scriptformat-section">
      <title id="set_scriptformat-title">SET SCRIPTFORMAT<footnoteref
      linkend="posthyper" /></title>

      <programlisting>SET SCRIPTFORMAT {TEXT | BINARY | COMPRESSED};</programlisting>

      <para>Changes the format of the script file. BINARY and COMPRESSED
      formats are slightly faster and more compact than the default TEXT.
      Recommended only for very large script files.</para>
    </section>

    <section id="set_table_index-section">
      <title id="set_table_index-title">SET TABLE INDEX</title>

      <programlisting>SET TABLE tableName INDEX 'index1rootPos index2rootPos ... ';</programlisting>

      <para>This command is only used internally to store the position of
      index roots in the .data file. It appears only in database script files;
      it should not be used directly.</para>
    </section>

    <section id="set_table_readonly-section">
      <title id="set_table_readonly-title">SET TABLE READONLY<footnoteref
      linkend="posthyper" /></title>

      <programlisting>SET TABLE &lt;tablename&gt; READONLY {TRUE | FALSE};</programlisting>

      <para>Sets the table as read only.</para>
    </section>

    <section id="set_table_source-section">
      <title id="set_table_source-title">SET TABLE SOURCE<footnoteref
      linkend="posthyper" /></title>

      <programlisting>SET TABLE &lt;tablename&gt; SOURCE &lt;file and options&gt; [DESC];</programlisting>

      <para>For details see the <link endterm="texttables-title"
      linkend="texttables-chapter" /> chapter.</para>

      <para>This command is used exclusively with TEXT tables to specify which
      file is used for storage of the data. The optional DESC qualifier
      results in the text file indexed from the end and opened as readonly.
      The &lt;file and options&gt; argument is a double quoted string that
      consists of:</para>

      <programlisting>    &lt;file and options&gt;::= &lt;doublequote&gt; &lt;filepath&gt;
        [&lt;semicolon&gt; &lt;option&gt;...] &lt;doublequote&gt;</programlisting>

      <para>Example:</para>

      <informalexample>
        <programlisting>    SET TABLE mytable SOURCE "myfile;fs=|;vs=.;lvs=~"</programlisting>
      </informalexample>

      <variablelist>
        <title>Supported Properties</title>

        <varlistentry>
          <term>quoted = { true | false }</term>

          <listitem>
            <para>default is true. If false, treats double quotes as normal
            characters</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>all_quoted = { true | false }</term>

          <listitem>
            <para>default is false. If true, adds double quotes around all
            fields.</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>encoding = &lt;encoding name&gt;</term>

          <listitem>
            <para>character encoding for text and character fields, for
            example, encoding=UTF-8</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>ignore_first = { true | false }</term>

          <listitem>
            <para>default is false. If true ignores the first line of the
            file</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>cache_scale= &lt;numeric value&gt;</term>

          <listitem>
            <para>exponent to calculate rows of the text file in cache.
            Default is 8, equivalent to nearly 800 rows</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>cache_size_scale = &lt;numeric value&gt;r</term>

          <listitem>
            <para>exponent to calculate average size of each row in cache.
            Default is 8, equivalent to 256 bytes per row.</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>fs = &lt;unquoted character&gt;</term>

          <listitem>
            <para>field separator</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>vs = &lt;unquoted character&gt;</term>

          <listitem>
            <para>varchar separator</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>lvs = &lt;unquoted character&gt;</term>

          <listitem>
            <para>long varchar separator</para>
          </listitem>
        </varlistentry>
      </variablelist>

      <variablelist>
        <title>Special indicators for Hsqldb Text Table separators</title>

        <varlistentry>
          <term>\semi</term>

          <listitem>
            <para>semicolon</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>\quote</term>

          <listitem>
            <para>quote</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>\space</term>

          <listitem>
            <para>space character</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>\apos</term>

          <listitem>
            <para>apostrophe</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>\n</term>

          <listitem>
            <para>newline - Used as an end anchor (like $ in regular
            expressions)</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>\r</term>

          <listitem>
            <para>carriage return</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>\t</term>

          <listitem>
            <para>tab</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>\\</term>

          <listitem>
            <para>backslash</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>\u####</term>

          <listitem>
            <para>a Unicode character specified in hexadecimal</para>
          </listitem>
        </varlistentry>
      </variablelist>

      <para>Only an administrator may do this.</para>
    </section>

    <section id="set_write_delay-section">
      <title id="set_write_delay-title">SET WRITE DELAY<footnoteref
      linkend="posthyper" /></title>

      <programlisting>SET WRITE_DELAY {{ TRUE | FALSE } | &lt;seconds&gt; | &lt;milliseconds&gt; MILLIS};</programlisting>

      <para>This controls the frequency of file sync for the log file. When
      WRITE_DELAY is set to FALSE or 0, the sync takes place immediately at
      each COMMIT. WRITE_DELAY TRUE performs the sync once every 20 seconds
      (which is the default). A numeric value can be specified instead.</para>

      <para>The purpose of this command is to control the amount of data loss
      in case of a total system crash. A delay of 1 second means at most the
      data written to disk during the last second before the crash is lost.
      All data written prior to this has been synced and should be
      recoverable.</para>

      <para>A write delay of 0 impacts performance in high load situations, as
      the engine has to wait for the file system to catch up.</para>

      <para>To avoid this, you can set write delay down to 10 milliseconds. In
      practice, a write delay of 100 milliseconds provides better than
      99.9999% reliability with an average one system crash per day, or
      99.99999% with an average one system crash per 6 days.</para>

      <para>Each time a SET WRITE_DELAY is issued with any value, a sync is
      immediately performed.</para>

      <para>Only an administrator may do this.</para>
    </section>

    <section id="shutdown-section">
      <title id="shutdown-title">SHUTDOWN</title>

      <programlisting>SHUTDOWN [IMMEDIATELY | COMPACT | SCRIPT<footnoteref
          linkend="posthyper" />];</programlisting>

      <para>Closes the current database.</para>

      <variablelist>
        <title>Varieties of the SHUTDOWN command</title>

        <varlistentry>
          <term>SHUTDOWN</term>

          <listitem>
            <para>Performs a checkpoint to creates a new .script file that has
            the minimum size and contains the data for memory tables only. It
            then backs up the .data file containing the CACHED TABLE data in
            zipped format to the .backup file and closes the database.</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>SHUTDOWN IMMEDIATELY</term>

          <listitem>
            <para>Just closes the database files (like when the Java process
            for the database is terminated); this command is used in tests of
            the recovery mechanism. This command should not be used as the
            routine method of closing the database.</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>SHUTDOWN COMPACT</term>

          <listitem>
            <para>Writes out a new .script file which contains the data for
            all the tables, including CACHED and TEXT tables. It then deletes
            the existing text table files and the .data file before rewriting
            them. After this, it backs up the .data file in the same way as
            normal SHUTDOWN. This operation shrinks all files to the minimum
            size.</para>
          </listitem>
        </varlistentry>

        <varlistentry>
          <term>SHUTDOWN SCRIPT</term>

          <listitem>
            <para>Similar to SHUTDOWN COMPACT but after writing the script and
            deleting the existing files, it does not rewrite the .data and
            text table files. After SHUTDOWN SCRIPT, only the .script and
            .properties file remain. At the next startup, these files are
            processed and the .data and .backup files are created. This
            command in effect performs part of the job of SHUTDOWN COMPACT,
            leaving the other part to be performed automatically at the next
            startup.</para>

            <para>This command produces a full script of the database which
            can be edited for special purposes prior to the next
            startup.</para>
          </listitem>
        </varlistentry>
      </variablelist>

      <simpara>Only an administrator may use the SHUTDOWN command.</simpara>
    </section>

    <section id="update-section">
      <title id="update-title">UPDATE</title>

      <programlisting>UPDATE table SET column = Expression [, ...] [WHERE Expression];</programlisting>

      <para>Modifies data of a table in the database.</para>

      <para>See also: <link endterm="select-title"
      linkend="select-section" />, <link endterm="insert-title"
      linkend="insert-section" />, <link endterm="delete-title"
      linkend="delete-section" />.</para>
    </section>
  </section>

  <section id="schemanaming-section">
    <title id="schemanaming-title">Schema object naming</title>

    <simpara><emphasis>Schema</emphasis> objects are database objects that are
    always scoped to a specific schema. Each schema has a namespace. There may
    be multiple schema objects of the same name, each in the namespace of a
    different schema. A particular schema object may nearly always be uniquely
    identified using the notation <literal>schemaname.objectname</literal>.
    All HSQLDB database objects are schema objects, other than the
    following.</simpara>

    <simplelist>
      <title>HSQLDB Non-Schema Object Types</title>

      <member>
        <simpara>Users</simpara>
      </member>

      <member>
        <simpara>Roles</simpara>
      </member>

      <member>
        <simpara>Store Procedure Java Classes</simpara>
      </member>

      <member>
        <simpara>HSQL Aliases</simpara>
      </member>
    </simplelist>

    <simpara>Our current Java-class-based Triggers are not fully schema
    objects. However, we are in the process of implementing SQL-conformant
    triggers which will encompass our Java-class-based triggers. When this
    work is completed, HSQLDB triggers will be schema objects.</simpara>

<simpara>Sequences are schema objects with creation and removal permission
    governed by schema authorization (as described hereafter), but GRANT
    and REVOKE command do not work yet for sequences.
    In a future version of HSQLDB, sequence GRANTs and REVOKEs will work 
    similarly to the current GRANT and REVOKE commands for table access.
    </simpara>

    <simpara>Most of the time, you do not need to specify the schema for the
    desired schema object, because the implicit schema is usually the only one
    that can be used. For example, when creating an index, the target schema
    will default to that of the table which is the target of the index. Named
    constraints are an extreme example of this. There is never a need to
    specify a schema name for a constraint, since constraint names are only
    specified in a CREATE or ALTER TABLE command, and the schema must be that
    of the target table. If the implicit schema is not determined by a related
    object, then the default comes from your JDBC session's current schema
    setting. The session schema value will be your login user's
    <emphasis>initial schema</emphasis>, or whatever you last set it to with
    <link endterm="set_schema-title" linkend="set_schema-section" /> in your
    <emphasis>current</emphasis> JDBC session with the SET SCHEMA command.
    (Your initial schema is "PUBLIC" unless changed with the <link
    linkend="alter_user-section"> ALTER USER SET INITIAL SCHEMA</link> or the
    <link endterm="set_initialschema-title"
    linkend="set_initialschema-section" /> command).</simpara>

    <simpara>In addition to namespace scoping, there are permission aspects to
    the schema of a database object. The <emphasis>authorization</emphasis> of
    a schema is a role or user that is basically the
    <emphasis>owner</emphasis> of the schema. Only a user with the DBA role
    (an admin user) or the owner of a schema may create objects, or modify the
    DDL of objects, in the namespace of that schema. In this way, a schema
    authorization is said to "own" the objects of that schema. A schema
    authorization/owner can be a role or a user (even a role with no members).
    The two schemas automatically created when a database is initialized are
    both owned by the role <emphasis>DBA</emphasis>.</simpara>

    <simpara>An important implication to database objects being
    <emphasis>owned</emphasis> by the schema owner is, if a non-DBA database
    user is to have permission to create any database object, they must have
    ownership of a schema. To allow a user to create (or modify DDL of)
    objects in their own personal schema, you would create a new schema with
    that user as the authorization. To allow a non-DBA user to share create
    and DDL privileges in some schema, you would create this schema with
    a role as the authorization, then GRANT this role to all of the desired
    users.</simpara>

    <simpara>The INFORMATION_SCHEMA is a system defined schema that contains
    the system tables for the database. This schema is read-only. When a
    database is created, a shema named PUBLIC is automatically created as the
    default schma. This schema has the authorization DBA. You can change the
    name of this schema. If all non-system schemas are dropped from a
    database, an empty PUBLIC schema is created again. So each database always
    has at least one non-system schema.</simpara>
  </section>

  <section id="datatypes-section">
    <title id="datatypes-title">Data Types</title>

    <table frame="all" pgwide="1" tocentry="1">
      <title>Data Types. The types on the same line are equivalent.</title>

      <titleabbrev>Data Types</titleabbrev>

      <tgroup align="left" cols="3">
        <thead>
          <row>
            <entry>Name</entry>

            <entry>Range</entry>

            <entry>Java Type</entry>
          </row>
        </thead>

        <tbody>
          <row>
            <entry>INTEGER | INT</entry>

            <entry>as Java type</entry>

            <entry><literal>int</literal> |
            <classname>java.lang.Integer</classname></entry>
          </row>

          <row>
            <entry>DOUBLE [PRECISION] | FLOAT</entry>

            <entry>as Java type</entry>

            <entry><literal>double</literal> |
            <classname>java.lang.Double</classname></entry>
          </row>

          <row>
            <entry>VARCHAR</entry>

            <entry>as Integer.MAXVALUE</entry>

            <entry>
              <classname>java.lang.String</classname>
            </entry>
          </row>

          <row>
            <entry>VARCHAR_IGNORECASE</entry>

            <entry>as Integer.MAXVALUE</entry>

            <entry>
              <classname>java.lang.String</classname>
            </entry>
          </row>

          <row>
            <entry>CHAR | CHARACTER</entry>

            <entry>as Integer.MAXVALUE</entry>

            <entry>
              <classname>java.lang.String</classname>
            </entry>
          </row>

          <row>
            <entry>LONGVARCHAR</entry>

            <entry>as Integer.MAXVALUE</entry>

            <entry>
              <classname>java.lang.String</classname>
            </entry>
          </row>

          <row>
            <entry>DATE</entry>

            <entry>as Java type</entry>

            <entry>
              <classname>java.sql.Date</classname>
            </entry>
          </row>

          <row>
            <entry>TIME</entry>

            <entry>as Java type</entry>

            <entry>
              <classname>java.sql.Time</classname>
            </entry>
          </row>

          <row>
            <entry>TIMESTAMP | DATETIME</entry>

            <entry>as Java type</entry>

            <entry>
              <classname>java.sql.Timestamp</classname>
            </entry>
          </row>

          <row>
            <entry>DECIMAL</entry>

            <entry>No limit</entry>

            <entry>
              <classname>java.math.BigDecimal</classname>
            </entry>
          </row>

          <row>
            <entry>NUMERIC</entry>

            <entry>No limit</entry>

            <entry>
              <classname>java.math.BigDecimal</classname>
            </entry>
          </row>

          <row>
            <entry>BOOLEAN | BIT</entry>

            <entry>as Java type</entry>

            <entry><literal>boolean</literal> |
            <classname>java.lang.Boolean</classname></entry>
          </row>

          <row>
            <entry>TINYINT</entry>

            <entry>as Java type</entry>

            <entry><literal>byte</literal> |
            <classname>java.lang.Byte</classname></entry>
          </row>

          <row>
            <entry>SMALLINT</entry>

            <entry>as Java type</entry>

            <entry><literal>short</literal> |
            <classname>java.lang.Short</classname></entry>
          </row>

          <row>
            <entry>BIGINT</entry>

            <entry>as Java type</entry>

            <entry><filename>long</filename> |
            <classname>java.lang.Long</classname></entry>
          </row>

          <row>
            <entry>REAL</entry>

            <entry>as Java type</entry>

            <entry><literal>double</literal> |
            <classname>java.lang.Double</classname><footnoteref
            linkend="posthyper" /></entry>
          </row>

          <row>
            <entry>BINARY</entry>

            <entry>as Integer.MAXVALUE</entry>

            <entry>
              <literal>byte[]</literal>
            </entry>
          </row>

          <row>
            <entry>VARBINARY</entry>

            <entry>as Integer.MAXVALUE</entry>

            <entry>
              <literal>byte[]</literal>
            </entry>
          </row>

          <row>
            <entry>LONGVARBINARY</entry>

            <entry>as Integer.MAXVALUE</entry>

            <entry>
              <literal>byte[]</literal>
            </entry>
          </row>

          <row>
            <entry>OTHER | OBJECT</entry>

            <entry>as Integer.MAXVALUE</entry>

            <entry>
              <classname>java.lang.Object</classname>
            </entry>
          </row>
        </tbody>
      </tgroup>
    </table>

    <para>The uppercase names are the data types names defined by the SQL
    standard or commonly used by RDMS's. The data types in quotes are the Java
    class names - if these type names are used then they must be enclosed in
    quotes because in Java names are case-sensitive. Range indicates the
    maximum size of the object that can be stored. Where Integer.MAXVALUE is
    stated, this is a theoretical limit and in practice the maximum size of a
    VARCHAR or BINARY object that can be stored is dictated by the amount of
    memory available. In practice, objects of up to a megabyte in size have
    been successfully used in production databases.</para>

    <para>The recommended Java mapping for the JDBC datatype FLOAT is as a
    Java type "double". Because of the potential confusion it is recommended
    that DOUBLE is used instead of FLOAT.</para>

    <para>VARCHAR_IGNORECASE is a special case-insensitive type of VARCHAR.
    This type is not portable.</para>

    <para>In table definition statements, HSQLDB accepts size, precision and
    scale qualifiers only for certain types: CHAR(s), VARCHAR(s), DOUBLE(p),
    NUMERIC(p), DECIMAL(p,s) and TIMESTAMP(p).</para>

    <para>TIMESTAMP(p) can take only 0 or 6 as precision. Zero indicates no
    subsecond part. Without the precision, the default is 6.</para>

    <para>By default specified precision and scale for the column is simply
    ignored by the engine. Instead, the values for the corresponding Java
    types are always used, which in the case of DECIMAL is an unlimited
    precision and scale. If a size is specified, it is stored in the database
    definition but is not enforeced by default. Once you have created the
    database (before adding data), you can add a database property value to
    enforce the sizes:</para>

    <programlisting>    SET PROPERTY "sql.enforce_strict_size" true</programlisting>

    <para>This will enforce the specified size and pad CHAR fields with spaces
    to fill the size. This complies with SQL standards by throwing an
    exception if an attempt is made to insert a string longer than the maximum
    size. It also results in all DECIMAL values conforming to the specified
    precision and scale.</para>

    <para>CHAR and VARCHAR and LONGVARCHAR columns are by default compared and
    sorted according to POSIX standards. See the <link
    endterm="collation-title" linkend="collation-section" /> section above to
    modify this behavior. The property
    <literal>sql.compare_in_locale</literal> is no longer supported. Instead,
    you can define a collation to be used for all character
    comparisons.</para>

    <para>Columns of the type OTHER or OBJECT contain the serialized form of a
    Java Object in binary format. To insert or update such columns, a binary
    format string (see below under Expression) should be used. Using
    PreparedStatements with JDBC automates this transformation.</para>
  </section>

  <section>
    <title>SQL Comments</title>

    <simplelist>
      <member>
        <literal>-- SQL style line comment</literal>
      </member>

      <member>
        <literal>// Java style line comment</literal>
      </member>

      <member>
        <literal>/* C style line comment */</literal>
      </member>
    </simplelist>

    <para>All these types of comments are ignored by the database.</para>
  </section>

  <section id="stored-section">
    <title id="stored-title">Stored Procedures / Functions</title>

    <para>Stored procedures are static Java functions that are called 
    directly from
    the SQL language or using an alias. Calling Java functions (directly or
    using the alias) requires that the Java class can be reached by the
    database (server). The syntax is:</para>

    <programlisting>    "java.lang.Math.sqrt"(2.0)</programlisting>

    <para>This means the package must be provided, and the name must be
    written as one word, and inside " because otherwise it is converted to
    uppercase (and not found).</para>

    <para>An alias can be created using the command CREATE ALIAS:</para>

    <programlisting>    CREATE ALIAS SQRT FOR "java.lang.Math.sqrt";</programlisting>

    <para>When an alias is defined, then the function can be called
    additionally using this alias:</para>

    <programlisting>    SELECT SQRT(A) , B FROM MYTABLE;</programlisting>

    <para>Only static java methods can be used as stored procedures. If,
    within the same class, there are overloaded methods with the same number
    of arguments, then the first one encountered by the program will be used.
    If you want to use Java library methods, it is recommended that you create
    your own class with static methods that act as wrappers around the Java
    library methods. This will allow you to control which method signature is
    used to call each Java library method.</para>
  </section>

  <section>
    <title>Built-in Functions and Stored Procedures</title>

    <variablelist>
      <title>Numerical built-in Functions / Stored Procedures</title>

      <varlistentry>
        <term>ABS(d)</term>

        <listitem>
          <para>returns the absolute value of a double value</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>ACOS(d)</term>

        <listitem>
          <para>returns the arc cosine of an angle</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>ASIN(d)</term>

        <listitem>
          <para>returns the arc sine of an angle</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>ATAN(d)</term>

        <listitem>
          <para>returns the arc tangent of an angle</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>ATAN2(a,b)</term>

        <listitem>
          <para>returns the tangent of a/b</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>BITAND(a,b)</term>

        <listitem>
          <para>return a &amp; b</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>BITOR(a,b)</term>

        <listitem>
          <para>returns a | b</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CEILING(d)</term>

        <listitem>
          <para>returns the smallest integer that is not less than d</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>COS(d)</term>

        <listitem>
          <para>returns the cosine of an angle</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>COT(d)</term>

        <listitem>
          <para>returns the cotangent of an angle</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>DEGREES(d)</term>

        <listitem>
          <para>converts radians to degrees</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>EXP(d)</term>

        <listitem>
          <para>returns e (2.718...) raised to the power of d</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>FLOOR(d)</term>

        <listitem>
          <para>returns the largest integer that is not greater than d</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>LOG(d)</term>

        <listitem>
          <para>returns the natural logarithm (base e)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>LOG10(d)</term>

        <listitem>
          <para>returns the logarithm (base 10)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>MOD(a,b)</term>

        <listitem>
          <para>returns a modulo b</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>PI()</term>

        <listitem>
          <para>returns pi (3.1415...)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>POWER(a,b)</term>

        <listitem>
          <para>returns a raised to the power of b</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>RADIANS(d)</term>

        <listitem>
          <para>converts degrees to radians</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>RAND()</term>

        <listitem>
          <para>returns a random number x bigger or equal to 0.0 and smaller
          than 1.0</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>ROUND(a,b)</term>

        <listitem>
          <para>rounds a to b digits after the decimal point</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>ROUNDMAGIC(d)</term>

        <listitem>
          <para>solves rounding problems such as 3.11-3.1-0.01</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>SIGN(d)</term>

        <listitem>
          <para>returns -1 if d is smaller than 0, 0 if d==0 and 1 if d is
          bigger than 0</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>SIN(d)</term>

        <listitem>
          <para>returns the sine of an angle</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>SQRT(d)</term>

        <listitem>
          <para>returns the square root</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>TAN(A)</term>

        <listitem>
          <para>returns the trigonometric tangent of an angle</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>TRUNCATE(a,b)</term>

        <listitem>
          <para>truncates a to b digits after the decimal point</para>
        </listitem>
      </varlistentry>
    </variablelist>

    <variablelist>
      <title>String built-in Functions / Stored Procedures</title>

      <varlistentry>
        <term>ASCII(s)</term>

        <listitem>
          <para>returns the ASCII code of the leftmost character of s</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>BIT_LENGTH(str)<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>returns the length of the string in bits</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CHAR(c)</term>

        <listitem>
          <para>returns a character that has the ASCII code c</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CHAR_LENGTH(str)<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>returns the length of the string in characters</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CONCAT(str1,str2)</term>

        <listitem>
          <para>returns str1 + str2</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>DIFFERENCE(s1,s2)</term>

        <listitem>
          <para>returns the difference between the sound of s1 and s2</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>HEXTORAW(s1)<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>returns translated string</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>INSERT(s,start,len,s2)</term>

        <listitem>
          <para>returns a string where len number of characters beginning at
          start has been replaced by s2</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>LCASE(s)</term>

        <listitem>
          <para>converts s to lower case</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>LEFT(s,count)</term>

        <listitem>
          <para>returns the leftmost count of characters of s) - requires
          double quoting - use SUBSTRING() instead</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>LENGTH(s)</term>

        <listitem>
          <para>returns the number of characters in s</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>LOCATE(search,s,[start])</term>

        <listitem>
          <para>returns the first index (1=left, 0=not found) where search is
          found in s, starting at start</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>LTRIM(s)</term>

        <listitem>
          <para>removes all leading blanks in s</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>OCTET_LENGTH(str)<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>returns the length of the string in bytes (twice the number of
          characters)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>RAWTOHEX(s1)<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>returns translated string</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>REPEAT(s,count)</term>

        <listitem>
          <para>returns s repeated count times</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>REPLACE(s,replace,s2)</term>

        <listitem>
          <para>replaces all occurrences of replace in s with s2</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>RIGHT(s,count)</term>

        <listitem>
          <para>returns the rightmost count of characters of s</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>RTRIM(s)</term>

        <listitem>
          <para>removes all trailing spaces</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>SOUNDEX(s)</term>

        <listitem>
          <para>returns a four character code representing the sound of
          s</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>SPACE(count)</term>

        <listitem>
          <para>returns a string consisting of count spaces</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>SUBSTR(s,start[,len])</term>

        <listitem>
          <para>alias for substring</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>SUBSTRING(s,start[,len])</term>

        <listitem>
          <para>returns the substring starting at start (1=left) with length
          len</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>UCASE(s)</term>

        <listitem>
          <para>converts s to upper case</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>LOWER(s)</term>

        <listitem>
          <para>converts s to lower case</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>UPPER(s)</term>

        <listitem>
          <para>converts s to upper case</para>
        </listitem>
      </varlistentry>
    </variablelist>

    <variablelist>
      <title>Date/Time built-in Functions / Stored Procedures</title>

      <varlistentry>
        <term>CURDATE()</term>

        <listitem>
          <para>returns the current date</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CURTIME()</term>

        <listitem>
          <para>returns the current time</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>DATEDIFF(string, datetime1, datetime2)<footnoteref
        linkend="posthyper" /></term>

        <listitem>
          <para>returns the count of units of time elapsed from datetime1 to
          datetime2. The string indicates the unit of time and can have the
          following values 'ms'='millisecond',
          'ss'='second','mi'='minute','hh'='hour', 'dd'='day', 'mm'='month',
          'yy' = 'year'. Both the long and short form of the strings can be
          used.</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>DAYNAME(date)</term>

        <listitem>
          <para>returns the name of the day</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>DAYOFMONTH(date)</term>

        <listitem>
          <para>returns the day of the month (1-31)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>DAYOFWEEK(date)</term>

        <listitem>
          <para>returns the day of the week (1 means Sunday)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>DAYOFYEAR(date)</term>

        <listitem>
          <para>returns the day of the year (1-366)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>HOUR(time)</term>

        <listitem>
          <para>return the hour (0-23)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>MINUTE(time)</term>

        <listitem>
          <para>returns the minute (0-59)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>MONTH(date)</term>

        <listitem>
          <para>returns the month (1-12)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>MONTHNAME(date)</term>

        <listitem>
          <para>returns the name of the month</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>NOW()</term>

        <listitem>
          <para>returns the current date and time as a timestamp) - use
          CURRENT_TIMESTAMP instead</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>QUARTER(date)</term>

        <listitem>
          <para>returns the quarter (1-4)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>SECOND(time)</term>

        <listitem>
          <para>returns the second (0-59)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>WEEK(date)</term>

        <listitem>
          <para>returns the week of this year (1-53)</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>YEAR(date)</term>

        <listitem>
          <para>returns the year</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CURRENT_DATE<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>returns the current date</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CURRENT_TIME<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>returns the current time</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CURRENT_TIMESTAMP<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>returns the current timestamp</para>
        </listitem>
      </varlistentry>
    </variablelist>

    <variablelist>
      <title>System/Connection built-in Functions / Stored Procedures</title>

      <varlistentry>
        <term>DATABASE()</term>

        <listitem>
          <para>returns the name of the database of this connection</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>USER()</term>

        <listitem>
          <para>returns the user name of this connection</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CURRENT_USER</term>

        <listitem>
          <para>SQL standard function, returns the user name of this
          connection</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>IDENTITY()</term>

        <listitem>
          <para>returns the last identity values that was inserted by this
          connection</para>
        </listitem>
      </varlistentry>
    </variablelist>

    <variablelist>
      <title>System built-in Functions / Stored Procedures</title>

      <varlistentry>
        <term>IFNULL(exp,value)</term>

        <listitem>
          <para>if exp is null, value is returned else exp) - use COALESCE()
          instead</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CASEWHEN(exp,v1,v2)</term>

        <listitem>
          <para>if exp is true, v1 is returned, else v2) - use CASE WHEN
          instead</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CONVERT(term,type)</term>

        <listitem>
          <para>converts exp to another data type</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CAST(term AS type)<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>converts exp to another data type</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>COALESCE(expr1,expr2,expr3,...)<footnoteref
        linkend="posthyper" /></term>

        <listitem>
          <para>if expr1 is not null then it is returned else, expr2 is
          evaluated and if not null it is returned and so on</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>NULLIF(v1,v2)<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>if v1 equals v2 return null, otherwise v1</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CASE v1 WHEN...<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>
            <literal>CASE v1 WHEN v2 THEN v3 [ELSE v4] END</literal>
          </para>

          <para>when v1 equals v2 return v3 [otherwise v4 or null if there is
          no ELSE]</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>CASE WHEN...<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>
            <literal>CASE WHEN expr1 THEN v1[WHEN expr2 THEN v2] [ELSE v4]
            END</literal>
          </para>

          <para>when expr1 is true return v1 [optionally repeated for more
          cases] [otherwise v4 or null if there is no ELSE]</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>EXTRACT<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>
            <literal>EXTRACT ({YEAR | MONTH | DAY | HOUR | MINUTE | SECOND}
            FROM &lt;datetime value&gt;)</literal>
          </para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>POSITION (... IN ..)<footnoteref linkend="posthyper" /></term>

        <listitem>
          <para>
            <literal>POSITION(&lt;string expression&gt; IN &lt;string
            expression&gt;)</literal>
          </para>

          <para>if the first string is a sub-string of the second one, returns
          the position of the sub-string, counting from one; otherwise
          0</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>SUBSTRING(... FROM ... FOR ...)<footnoteref
        linkend="posthyper" /></term>

        <listitem>
          <para>
            <literal>SUBSTRING(&lt;string expression&gt; FROM &lt;numeric
            expression&gt; [FOR &lt;numeric expression&gt;])</literal>
          </para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>TRIM( LEDING ... FROM ...)<footnoteref
        linkend="posthyper" /></term>

        <listitem>
          <para>
            <literal>TRIM([{LEADING | TRAILING | BOTH}] FROM &lt;string
            expression&gt;)</literal>
          </para>
        </listitem>
      </varlistentry>
    </variablelist>

    <para>See also: <link endterm="call-title" linkend="call-section" />,
    <link endterm="create_alias-title"
    linkend="create_alias-section" />.</para>
  </section>

  <section id="expression-section">
    <title id="expression-title">SQL Expression</title>

    <programlisting>[NOT] condition [{ OR | AND } condition]</programlisting>

    <variablelist>
      <title>Components of SQL Expressions</title>

      <varlistentry>
        <term>condition</term>

        <listitem>
          <programlisting>   { value [|| value]
  | value { = | &lt; | &lt;= | &gt; | &gt;= | &lt;&gt; | != } value
  | value IS [NOT] NULL
  | EXISTS(selectStatement)
  | value BETWEEN value AND value
  | value [NOT] IN ( {value [, ...] | selectStatement } )
  | value [NOT] LIKE value [ESCAPE] value }</programlisting>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>value</term>

        <listitem>
          <programlisting>   [+ | -] { term [{ + | - | * | / | || } term]
  | ( condition )
  | function ( [parameter] [,...] )
  | selectStatement giving one value
  | {ANY|ALL} (selectStatement giving single column)</programlisting>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>term</term>

        <listitem>
          <programlisting>   { 'string' | number | floatingpoint
  | [table.]column | TRUE | FALSE | NULL }</programlisting>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>sequence</term>

        <listitem>
          <programlisting>   NEXT VALUE FOR &lt;sequence&gt;</programlisting>

          <para>HSQLDB does not currently enforce the SQL 200n proposed rules
          on where sequence generated values are allowed to be used. In
          general, these values can be used in insert and update statements
          but not in CASE statements, order by clauses, search conditions,
          aggregate functions, or grouped queries.</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>string</term>

        <listitem>
          <para>Strings in HSQLDB are Unicode strings. A string starts and
          ends with a single ' (singlequote). In a string started with '
          (singlequote) use '' (two singlequotes) to create a '
          (singlequote).</para>

          <para>String contatenation should be performed with the standard SQL
          operator || rather than the non-standard + operator.</para>

          <para>The LIKE keyword uses '%' to match any (including 0) number of
          characters, and '_' to match exactly one character. To search for
          '%' or '_' itself an escape character must also be specified using
          the ESCAPE clause. For example, if the backslash is the escaping
          character, '\%' and '\_' can be used to find the '%' and '_'
          characters themselves. For example, SELECT .... LIKE '\_%' ESCAPE
          '\' will find the strings beginning with an underscore.</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>name</term>

        <listitem>
          <para>The character set for quoted identifiers (names) in HSQLDB is
          Unicode.</para>

          <para>A unquoted identifier (name) starts with a letter and is
          followed by any number of ASCII letters or digits. When an SQL
          statement is issued, any lowercase characters in unquoted
          identifiers are converted to uppercase. Because of this, unquoted
          names are in fact ALL UPPERCASE when used in SQL statements. An
          important implication of this is the for accessing columns names via
          JDBC DatabaseMetaData: the internal form, which is the ALL UPPERCASE
          must be used if the column name was not quoted in the CREATE TABLE
          statement.</para>

          <para>Quoted identifiers can be used as names (for tables, columns,
          constraints or indexes). Quoted identifiers start and end with "
          (one doublequote). A quoted identifier can contain any Unicode
          character, including space. In a quoted identifier use "" (two
          doublequotes) to create a " (one doublequote). With quoted
          identifiers it is possible to create mixed-case table and column
          names. Example:</para>

          <informalexample>
              <programlisting>    CREATE TABLE "Address" ("Nr" INTEGER,"Name" VARCHAR);
    SELECT "Nr", "Name" FROM "Address";</programlisting>
          </informalexample>

          <para>The equivalent quoted identifier can be used for an unquoted
          identifer by converting the identifier to all uppercase and quoting
          it. For example, if a table name is defined as Address2 (unquoted),
          it can be referred to by its quoted form, "ADDRESS2", as well as
          address2, aDDress2 and ADDRESS2. Quoted identifiers should not be
          confused with SQL strings.</para>

          <para>Quoting can sometimes be used for identifiers, aliases or
          functions when there is an ambiguity. For example:</para>

          <informalexample>
            <programlisting>    SELECT COUNT(*) "COUNT" FROM MYTABLE;
    SELECT "LEFT"(COL1, 2) FROM MYTABLE;</programlisting>
          </informalexample>

          <para>Although HSQLDB 1.8.0 does not force unquoted identifiers to
          contain only ASCII characters, the use of non-ASCII characters in
          these identifiers does not comply with SQL standards. Portability
          between different JRE locales could be an issue when accented
          characters (or extended unicode characters) are used in unquoted
          identifiers. Because native Java methods are used to convert the
          identifier to uppercase, the result may vary not be expected in
          different locales. It is recommended that accented characters are
          used only in quoted identifiers.</para>

          <para>When using JDBC DatabaseMetaData methods that take table,
          column, or index identifiers as arguments, treat the names as they
          are registered in the database. With these methods, unquoted
          identifiers should be used in all-uppercase to get the correct
          result. Quoted identifiers should be used in the exact case
          combination as they were defined - no quote character should be
          included around the name. JDBC methods that return a result set
          containing such identifiers return unquoted identifiers as
          all-uppercase and quoted identifiers in the exact case they are
          registered in the database (a change from 1.6.1 and previous
          versions).</para>

          <para>Please also note that the JDBC getXXX(String columnName)
          methods interpret the columnName as case-independent. This is a
          general feature of JDBC and not specific to HSQLDB.</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>password</term>

        <listitem>
          <para>Passwords must be double quoted and used consistently.
          Passwords are case insensitive only for backward compatibility. This
          may change in future versions.</para>
        </listitem>
      </varlistentry>

      <varlistentry>
        <term>values</term>

        <listitem>
          <itemizedlist>
            <listitem>
              <para>A DATE literal starts and ends with ' (singlequote), the
              format is yyyy-mm-dd (see
              <classname>java.sql.Date</classname>.</para>
            </listitem>

            <listitem>
              <para>A TIME liteal starts and ends with ' (singlequote), the
              format is hh:mm:ss (see
              <classname>java.sql.Time</classname>).</para>
            </listitem>

            <listitem>
              <para>A TIMESTAMP or DATETIME literal starts and ends with '
              (singlequote), the format is yyyy-mm-dd hh:mm:ss.SSSSSSSSS (see
              <classname>java.sql.Timestamp</classname>).</para>
            </listitem>
          </itemizedlist>

          <para>When specifying default values for date / time columns in
          CREATE TABLE statements, or in SELECT,INSERT, and UPDATE statements,
          special SQL functions: NOW, SYSDATE, TODAY, CURRENT_TIMESTAMP,
          CURRENT_TIME and CURRENT_DATE (case independent) can be used. NOW is
          used for TIME and TIMESTAMP columns, TODAY is used for DATE columns.
          The data and time variants CURRENT_* are SQL standard versions and
          should be used in preference to others. Example:</para>

          <programlisting>    CREATE TABLE T(D DATE DEFAULT CURRENT_DATE);
    CREATE TABLE T1(TS TIMESTAMP DEFAULT CURRENT_TIMESTAMP);</programlisting>

          <para>Binary data starts and ends with ' (singlequote), the format
          is hexadecimal. '0004ff' for example is 3 bytes, first 0, second 4
          and last 255 (0xff).</para>
        </listitem>
      </varlistentry>
    </variablelist>

    <para>Any number of commands may be combined. With combined commands, ';'
    (semicolon) must be used at the end of each command to ensure data
    integrity, despite the fact that the engine may understand the end of
    commands and not return an error when a semicolon is not used.</para>
  </section>
</chapter>