File: guide.html

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 (6174 lines) | stat: -rw-r--r-- 553,601 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
3078
3079
3080
3081
3082
3083
3084
3085
3086
3087
3088
3089
3090
3091
3092
3093
3094
3095
3096
3097
3098
3099
3100
3101
3102
3103
3104
3105
3106
3107
3108
3109
3110
3111
3112
3113
3114
3115
3116
3117
3118
3119
3120
3121
3122
3123
3124
3125
3126
3127
3128
3129
3130
3131
3132
3133
3134
3135
3136
3137
3138
3139
3140
3141
3142
3143
3144
3145
3146
3147
3148
3149
3150
3151
3152
3153
3154
3155
3156
3157
3158
3159
3160
3161
3162
3163
3164
3165
3166
3167
3168
3169
3170
3171
3172
3173
3174
3175
3176
3177
3178
3179
3180
3181
3182
3183
3184
3185
3186
3187
3188
3189
3190
3191
3192
3193
3194
3195
3196
3197
3198
3199
3200
3201
3202
3203
3204
3205
3206
3207
3208
3209
3210
3211
3212
3213
3214
3215
3216
3217
3218
3219
3220
3221
3222
3223
3224
3225
3226
3227
3228
3229
3230
3231
3232
3233
3234
3235
3236
3237
3238
3239
3240
3241
3242
3243
3244
3245
3246
3247
3248
3249
3250
3251
3252
3253
3254
3255
3256
3257
3258
3259
3260
3261
3262
3263
3264
3265
3266
3267
3268
3269
3270
3271
3272
3273
3274
3275
3276
3277
3278
3279
3280
3281
3282
3283
3284
3285
3286
3287
3288
3289
3290
3291
3292
3293
3294
3295
3296
3297
3298
3299
3300
3301
3302
3303
3304
3305
3306
3307
3308
3309
3310
3311
3312
3313
3314
3315
3316
3317
3318
3319
3320
3321
3322
3323
3324
3325
3326
3327
3328
3329
3330
3331
3332
3333
3334
3335
3336
3337
3338
3339
3340
3341
3342
3343
3344
3345
3346
3347
3348
3349
3350
3351
3352
3353
3354
3355
3356
3357
3358
3359
3360
3361
3362
3363
3364
3365
3366
3367
3368
3369
3370
3371
3372
3373
3374
3375
3376
3377
3378
3379
3380
3381
3382
3383
3384
3385
3386
3387
3388
3389
3390
3391
3392
3393
3394
3395
3396
3397
3398
3399
3400
3401
3402
3403
3404
3405
3406
3407
3408
3409
3410
3411
3412
3413
3414
3415
3416
3417
3418
3419
3420
3421
3422
3423
3424
3425
3426
3427
3428
3429
3430
3431
3432
3433
3434
3435
3436
3437
3438
3439
3440
3441
3442
3443
3444
3445
3446
3447
3448
3449
3450
3451
3452
3453
3454
3455
3456
3457
3458
3459
3460
3461
3462
3463
3464
3465
3466
3467
3468
3469
3470
3471
3472
3473
3474
3475
3476
3477
3478
3479
3480
3481
3482
3483
3484
3485
3486
3487
3488
3489
3490
3491
3492
3493
3494
3495
3496
3497
3498
3499
3500
3501
3502
3503
3504
3505
3506
3507
3508
3509
3510
3511
3512
3513
3514
3515
3516
3517
3518
3519
3520
3521
3522
3523
3524
3525
3526
3527
3528
3529
3530
3531
3532
3533
3534
3535
3536
3537
3538
3539
3540
3541
3542
3543
3544
3545
3546
3547
3548
3549
3550
3551
3552
3553
3554
3555
3556
3557
3558
3559
3560
3561
3562
3563
3564
3565
3566
3567
3568
3569
3570
3571
3572
3573
3574
3575
3576
3577
3578
3579
3580
3581
3582
3583
3584
3585
3586
3587
3588
3589
3590
3591
3592
3593
3594
3595
3596
3597
3598
3599
3600
3601
3602
3603
3604
3605
3606
3607
3608
3609
3610
3611
3612
3613
3614
3615
3616
3617
3618
3619
3620
3621
3622
3623
3624
3625
3626
3627
3628
3629
3630
3631
3632
3633
3634
3635
3636
3637
3638
3639
3640
3641
3642
3643
3644
3645
3646
3647
3648
3649
3650
3651
3652
3653
3654
3655
3656
3657
3658
3659
3660
3661
3662
3663
3664
3665
3666
3667
3668
3669
3670
3671
3672
3673
3674
3675
3676
3677
3678
3679
3680
3681
3682
3683
3684
3685
3686
3687
3688
3689
3690
3691
3692
3693
3694
3695
3696
3697
3698
3699
3700
3701
3702
3703
3704
3705
3706
3707
3708
3709
3710
3711
3712
3713
3714
3715
3716
3717
3718
3719
3720
3721
3722
3723
3724
3725
3726
3727
3728
3729
3730
3731
3732
3733
3734
3735
3736
3737
3738
3739
3740
3741
3742
3743
3744
3745
3746
3747
3748
3749
3750
3751
3752
3753
3754
3755
3756
3757
3758
3759
3760
3761
3762
3763
3764
3765
3766
3767
3768
3769
3770
3771
3772
3773
3774
3775
3776
3777
3778
3779
3780
3781
3782
3783
3784
3785
3786
3787
3788
3789
3790
3791
3792
3793
3794
3795
3796
3797
3798
3799
3800
3801
3802
3803
3804
3805
3806
3807
3808
3809
3810
3811
3812
3813
3814
3815
3816
3817
3818
3819
3820
3821
3822
3823
3824
3825
3826
3827
3828
3829
3830
3831
3832
3833
3834
3835
3836
3837
3838
3839
3840
3841
3842
3843
3844
3845
3846
3847
3848
3849
3850
3851
3852
3853
3854
3855
3856
3857
3858
3859
3860
3861
3862
3863
3864
3865
3866
3867
3868
3869
3870
3871
3872
3873
3874
3875
3876
3877
3878
3879
3880
3881
3882
3883
3884
3885
3886
3887
3888
3889
3890
3891
3892
3893
3894
3895
3896
3897
3898
3899
3900
3901
3902
3903
3904
3905
3906
3907
3908
3909
3910
3911
3912
3913
3914
3915
3916
3917
3918
3919
3920
3921
3922
3923
3924
3925
3926
3927
3928
3929
3930
3931
3932
3933
3934
3935
3936
3937
3938
3939
3940
3941
3942
3943
3944
3945
3946
3947
3948
3949
3950
3951
3952
3953
3954
3955
3956
3957
3958
3959
3960
3961
3962
3963
3964
3965
3966
3967
3968
3969
3970
3971
3972
3973
3974
3975
3976
3977
3978
3979
3980
3981
3982
3983
3984
3985
3986
3987
3988
3989
3990
3991
3992
3993
3994
3995
3996
3997
3998
3999
4000
4001
4002
4003
4004
4005
4006
4007
4008
4009
4010
4011
4012
4013
4014
4015
4016
4017
4018
4019
4020
4021
4022
4023
4024
4025
4026
4027
4028
4029
4030
4031
4032
4033
4034
4035
4036
4037
4038
4039
4040
4041
4042
4043
4044
4045
4046
4047
4048
4049
4050
4051
4052
4053
4054
4055
4056
4057
4058
4059
4060
4061
4062
4063
4064
4065
4066
4067
4068
4069
4070
4071
4072
4073
4074
4075
4076
4077
4078
4079
4080
4081
4082
4083
4084
4085
4086
4087
4088
4089
4090
4091
4092
4093
4094
4095
4096
4097
4098
4099
4100
4101
4102
4103
4104
4105
4106
4107
4108
4109
4110
4111
4112
4113
4114
4115
4116
4117
4118
4119
4120
4121
4122
4123
4124
4125
4126
4127
4128
4129
4130
4131
4132
4133
4134
4135
4136
4137
4138
4139
4140
4141
4142
4143
4144
4145
4146
4147
4148
4149
4150
4151
4152
4153
4154
4155
4156
4157
4158
4159
4160
4161
4162
4163
4164
4165
4166
4167
4168
4169
4170
4171
4172
4173
4174
4175
4176
4177
4178
4179
4180
4181
4182
4183
4184
4185
4186
4187
4188
4189
4190
4191
4192
4193
4194
4195
4196
4197
4198
4199
4200
4201
4202
4203
4204
4205
4206
4207
4208
4209
4210
4211
4212
4213
4214
4215
4216
4217
4218
4219
4220
4221
4222
4223
4224
4225
4226
4227
4228
4229
4230
4231
4232
4233
4234
4235
4236
4237
4238
4239
4240
4241
4242
4243
4244
4245
4246
4247
4248
4249
4250
4251
4252
4253
4254
4255
4256
4257
4258
4259
4260
4261
4262
4263
4264
4265
4266
4267
4268
4269
4270
4271
4272
4273
4274
4275
4276
4277
4278
4279
4280
4281
4282
4283
4284
4285
4286
4287
4288
4289
4290
4291
4292
4293
4294
4295
4296
4297
4298
4299
4300
4301
4302
4303
4304
4305
4306
4307
4308
4309
4310
4311
4312
4313
4314
4315
4316
4317
4318
4319
4320
4321
4322
4323
4324
4325
4326
4327
4328
4329
4330
4331
4332
4333
4334
4335
4336
4337
4338
4339
4340
4341
4342
4343
4344
4345
4346
4347
4348
4349
4350
4351
4352
4353
4354
4355
4356
4357
4358
4359
4360
4361
4362
4363
4364
4365
4366
4367
4368
4369
4370
4371
4372
4373
4374
4375
4376
4377
4378
4379
4380
4381
4382
4383
4384
4385
4386
4387
4388
4389
4390
4391
4392
4393
4394
4395
4396
4397
4398
4399
4400
4401
4402
4403
4404
4405
4406
4407
4408
4409
4410
4411
4412
4413
4414
4415
4416
4417
4418
4419
4420
4421
4422
4423
4424
4425
4426
4427
4428
4429
4430
4431
4432
4433
4434
4435
4436
4437
4438
4439
4440
4441
4442
4443
4444
4445
4446
4447
4448
4449
4450
4451
4452
4453
4454
4455
4456
4457
4458
4459
4460
4461
4462
4463
4464
4465
4466
4467
4468
4469
4470
4471
4472
4473
4474
4475
4476
4477
4478
4479
4480
4481
4482
4483
4484
4485
4486
4487
4488
4489
4490
4491
4492
4493
4494
4495
4496
4497
4498
4499
4500
4501
4502
4503
4504
4505
4506
4507
4508
4509
4510
4511
4512
4513
4514
4515
4516
4517
4518
4519
4520
4521
4522
4523
4524
4525
4526
4527
4528
4529
4530
4531
4532
4533
4534
4535
4536
4537
4538
4539
4540
4541
4542
4543
4544
4545
4546
4547
4548
4549
4550
4551
4552
4553
4554
4555
4556
4557
4558
4559
4560
4561
4562
4563
4564
4565
4566
4567
4568
4569
4570
4571
4572
4573
4574
4575
4576
4577
4578
4579
4580
4581
4582
4583
4584
4585
4586
4587
4588
4589
4590
4591
4592
4593
4594
4595
4596
4597
4598
4599
4600
4601
4602
4603
4604
4605
4606
4607
4608
4609
4610
4611
4612
4613
4614
4615
4616
4617
4618
4619
4620
4621
4622
4623
4624
4625
4626
4627
4628
4629
4630
4631
4632
4633
4634
4635
4636
4637
4638
4639
4640
4641
4642
4643
4644
4645
4646
4647
4648
4649
4650
4651
4652
4653
4654
4655
4656
4657
4658
4659
4660
4661
4662
4663
4664
4665
4666
4667
4668
4669
4670
4671
4672
4673
4674
4675
4676
4677
4678
4679
4680
4681
4682
4683
4684
4685
4686
4687
4688
4689
4690
4691
4692
4693
4694
4695
4696
4697
4698
4699
4700
4701
4702
4703
4704
4705
4706
4707
4708
4709
4710
4711
4712
4713
4714
4715
4716
4717
4718
4719
4720
4721
4722
4723
4724
4725
4726
4727
4728
4729
4730
4731
4732
4733
4734
4735
4736
4737
4738
4739
4740
4741
4742
4743
4744
4745
4746
4747
4748
4749
4750
4751
4752
4753
4754
4755
4756
4757
4758
4759
4760
4761
4762
4763
4764
4765
4766
4767
4768
4769
4770
4771
4772
4773
4774
4775
4776
4777
4778
4779
4780
4781
4782
4783
4784
4785
4786
4787
4788
4789
4790
4791
4792
4793
4794
4795
4796
4797
4798
4799
4800
4801
4802
4803
4804
4805
4806
4807
4808
4809
4810
4811
4812
4813
4814
4815
4816
4817
4818
4819
4820
4821
4822
4823
4824
4825
4826
4827
4828
4829
4830
4831
4832
4833
4834
4835
4836
4837
4838
4839
4840
4841
4842
4843
4844
4845
4846
4847
4848
4849
4850
4851
4852
4853
4854
4855
4856
4857
4858
4859
4860
4861
4862
4863
4864
4865
4866
4867
4868
4869
4870
4871
4872
4873
4874
4875
4876
4877
4878
4879
4880
4881
4882
4883
4884
4885
4886
4887
4888
4889
4890
4891
4892
4893
4894
4895
4896
4897
4898
4899
4900
4901
4902
4903
4904
4905
4906
4907
4908
4909
4910
4911
4912
4913
4914
4915
4916
4917
4918
4919
4920
4921
4922
4923
4924
4925
4926
4927
4928
4929
4930
4931
4932
4933
4934
4935
4936
4937
4938
4939
4940
4941
4942
4943
4944
4945
4946
4947
4948
4949
4950
4951
4952
4953
4954
4955
4956
4957
4958
4959
4960
4961
4962
4963
4964
4965
4966
4967
4968
4969
4970
4971
4972
4973
4974
4975
4976
4977
4978
4979
4980
4981
4982
4983
4984
4985
4986
4987
4988
4989
4990
4991
4992
4993
4994
4995
4996
4997
4998
4999
5000
5001
5002
5003
5004
5005
5006
5007
5008
5009
5010
5011
5012
5013
5014
5015
5016
5017
5018
5019
5020
5021
5022
5023
5024
5025
5026
5027
5028
5029
5030
5031
5032
5033
5034
5035
5036
5037
5038
5039
5040
5041
5042
5043
5044
5045
5046
5047
5048
5049
5050
5051
5052
5053
5054
5055
5056
5057
5058
5059
5060
5061
5062
5063
5064
5065
5066
5067
5068
5069
5070
5071
5072
5073
5074
5075
5076
5077
5078
5079
5080
5081
5082
5083
5084
5085
5086
5087
5088
5089
5090
5091
5092
5093
5094
5095
5096
5097
5098
5099
5100
5101
5102
5103
5104
5105
5106
5107
5108
5109
5110
5111
5112
5113
5114
5115
5116
5117
5118
5119
5120
5121
5122
5123
5124
5125
5126
5127
5128
5129
5130
5131
5132
5133
5134
5135
5136
5137
5138
5139
5140
5141
5142
5143
5144
5145
5146
5147
5148
5149
5150
5151
5152
5153
5154
5155
5156
5157
5158
5159
5160
5161
5162
5163
5164
5165
5166
5167
5168
5169
5170
5171
5172
5173
5174
5175
5176
5177
5178
5179
5180
5181
5182
5183
5184
5185
5186
5187
5188
5189
5190
5191
5192
5193
5194
5195
5196
5197
5198
5199
5200
5201
5202
5203
5204
5205
5206
5207
5208
5209
5210
5211
5212
5213
5214
5215
5216
5217
5218
5219
5220
5221
5222
5223
5224
5225
5226
5227
5228
5229
5230
5231
5232
5233
5234
5235
5236
5237
5238
5239
5240
5241
5242
5243
5244
5245
5246
5247
5248
5249
5250
5251
5252
5253
5254
5255
5256
5257
5258
5259
5260
5261
5262
5263
5264
5265
5266
5267
5268
5269
5270
5271
5272
5273
5274
5275
5276
5277
5278
5279
5280
5281
5282
5283
5284
5285
5286
5287
5288
5289
5290
5291
5292
5293
5294
5295
5296
5297
5298
5299
5300
5301
5302
5303
5304
5305
5306
5307
5308
5309
5310
5311
5312
5313
5314
5315
5316
5317
5318
5319
5320
5321
5322
5323
5324
5325
5326
5327
5328
5329
5330
5331
5332
5333
5334
5335
5336
5337
5338
5339
5340
5341
5342
5343
5344
5345
5346
5347
5348
5349
5350
5351
5352
5353
5354
5355
5356
5357
5358
5359
5360
5361
5362
5363
5364
5365
5366
5367
5368
5369
5370
5371
5372
5373
5374
5375
5376
5377
5378
5379
5380
5381
5382
5383
5384
5385
5386
5387
5388
5389
5390
5391
5392
5393
5394
5395
5396
5397
5398
5399
5400
5401
5402
5403
5404
5405
5406
5407
5408
5409
5410
5411
5412
5413
5414
5415
5416
5417
5418
5419
5420
5421
5422
5423
5424
5425
5426
5427
5428
5429
5430
5431
5432
5433
5434
5435
5436
5437
5438
5439
5440
5441
5442
5443
5444
5445
5446
5447
5448
5449
5450
5451
5452
5453
5454
5455
5456
5457
5458
5459
5460
5461
5462
5463
5464
5465
5466
5467
5468
5469
5470
5471
5472
5473
5474
5475
5476
5477
5478
5479
5480
5481
5482
5483
5484
5485
5486
5487
5488
5489
5490
5491
5492
5493
5494
5495
5496
5497
5498
5499
5500
5501
5502
5503
5504
5505
5506
5507
5508
5509
5510
5511
5512
5513
5514
5515
5516
5517
5518
5519
5520
5521
5522
5523
5524
5525
5526
5527
5528
5529
5530
5531
5532
5533
5534
5535
5536
5537
5538
5539
5540
5541
5542
5543
5544
5545
5546
5547
5548
5549
5550
5551
5552
5553
5554
5555
5556
5557
5558
5559
5560
5561
5562
5563
5564
5565
5566
5567
5568
5569
5570
5571
5572
5573
5574
5575
5576
5577
5578
5579
5580
5581
5582
5583
5584
5585
5586
5587
5588
5589
5590
5591
5592
5593
5594
5595
5596
5597
5598
5599
5600
5601
5602
5603
5604
5605
5606
5607
5608
5609
5610
5611
5612
5613
5614
5615
5616
5617
5618
5619
5620
5621
5622
5623
5624
5625
5626
5627
5628
5629
5630
5631
5632
5633
5634
5635
5636
5637
5638
5639
5640
5641
5642
5643
5644
5645
5646
5647
5648
5649
5650
5651
5652
5653
5654
5655
5656
5657
5658
5659
5660
5661
5662
5663
5664
5665
5666
5667
5668
5669
5670
5671
5672
5673
5674
5675
5676
5677
5678
5679
5680
5681
5682
5683
5684
5685
5686
5687
5688
5689
5690
5691
5692
5693
5694
5695
5696
5697
5698
5699
5700
5701
5702
5703
5704
5705
5706
5707
5708
5709
5710
5711
5712
5713
5714
5715
5716
5717
5718
5719
5720
5721
5722
5723
5724
5725
5726
5727
5728
5729
5730
5731
5732
5733
5734
5735
5736
5737
5738
5739
5740
5741
5742
5743
5744
5745
5746
5747
5748
5749
5750
5751
5752
5753
5754
5755
5756
5757
5758
5759
5760
5761
5762
5763
5764
5765
5766
5767
5768
5769
5770
5771
5772
5773
5774
5775
5776
5777
5778
5779
5780
5781
5782
5783
5784
5785
5786
5787
5788
5789
5790
5791
5792
5793
5794
5795
5796
5797
5798
5799
5800
5801
5802
5803
5804
5805
5806
5807
5808
5809
5810
5811
5812
5813
5814
5815
5816
5817
5818
5819
5820
5821
5822
5823
5824
5825
5826
5827
5828
5829
5830
5831
5832
5833
5834
5835
5836
5837
5838
5839
5840
5841
5842
5843
5844
5845
5846
5847
5848
5849
5850
5851
5852
5853
5854
5855
5856
5857
5858
5859
5860
5861
5862
5863
5864
5865
5866
5867
5868
5869
5870
5871
5872
5873
5874
5875
5876
5877
5878
5879
5880
5881
5882
5883
5884
5885
5886
5887
5888
5889
5890
5891
5892
5893
5894
5895
5896
5897
5898
5899
5900
5901
5902
5903
5904
5905
5906
5907
5908
5909
5910
5911
5912
5913
5914
5915
5916
5917
5918
5919
5920
5921
5922
5923
5924
5925
5926
5927
5928
5929
5930
5931
5932
5933
5934
5935
5936
5937
5938
5939
5940
5941
5942
5943
5944
5945
5946
5947
5948
5949
5950
5951
5952
5953
5954
5955
5956
5957
5958
5959
5960
5961
5962
5963
5964
5965
5966
5967
5968
5969
5970
5971
5972
5973
5974
5975
5976
5977
5978
5979
5980
5981
5982
5983
5984
5985
5986
5987
5988
5989
5990
5991
5992
5993
5994
5995
5996
5997
5998
5999
6000
6001
6002
6003
6004
6005
6006
6007
6008
6009
6010
6011
6012
6013
6014
6015
6016
6017
6018
6019
6020
6021
6022
6023
6024
6025
6026
6027
6028
6029
6030
6031
6032
6033
6034
6035
6036
6037
6038
6039
6040
6041
6042
6043
6044
6045
6046
6047
6048
6049
6050
6051
6052
6053
6054
6055
6056
6057
6058
6059
6060
6061
6062
6063
6064
6065
6066
6067
6068
6069
6070
6071
6072
6073
6074
6075
6076
6077
6078
6079
6080
6081
6082
6083
6084
6085
6086
6087
6088
6089
6090
6091
6092
6093
6094
6095
6096
6097
6098
6099
6100
6101
6102
6103
6104
6105
6106
6107
6108
6109
6110
6111
6112
6113
6114
6115
6116
6117
6118
6119
6120
6121
6122
6123
6124
6125
6126
6127
6128
6129
6130
6131
6132
6133
6134
6135
6136
6137
6138
6139
6140
6141
6142
6143
6144
6145
6146
6147
6148
6149
6150
6151
6152
6153
6154
6155
6156
6157
6158
6159
6160
6161
6162
6163
6164
6165
6166
6167
6168
6169
6170
6171
6172
6173
6174
<html><head><META http-equiv="Content-Type" content="text/html; charset=ISO-8859-1"><title>Hsqldb User Guide</title><link href="guide.css" rel="stylesheet" type="text/css"><meta content="DocBook XSL Stylesheets V1.65.1" name="generator"><meta name="keywords" content="Hsqldb, Hypersonic, Database, JDBC, Java"></head><body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="book" lang="en"><div class="titlepage"><div><div><h1 class="title"><a name="N10002"></a>Hsqldb User Guide</h1></div><div><div class="authorgroup"><h3 class="corpauthor">The HSQLDB Development Group</h3><h4 class="editedby">Edited by</h4><h3 class="editor"><span class="firstname">Blaine</span> <span class="surname">Simpson</span></h3><h3 class="editor"><span class="firstname">Fred</span> <span class="surname">Toussi</span></h3></div></div><div><div class="legalnotice"><p>
            Copyright 2002-2005 HSQLDB Development Group.
            Permission is granted to distribute this document without any 
            alteration under the terms of the HSQLDB license.
        </p></div></div><div><p class="pubdate">$Date: 2005/07/25 23:02:52 $</p></div></div><div></div><hr></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="preface"><a href="#N10030">Introduction</a></span></dt><dd><dl><dt><span class="section"><a href="#N1003A">Available formats for this document</a></span></dt></dl></dd><dt><span class="chapter"><a href="#N1007D">1. Running and Using Hsqldb</a></span></dt><dd><dl><dt><span class="section"><a href="#N1009E">Introduction</a></span></dt><dt><span class="section"><a href="#N100B7">Running Tools</a></span></dt><dt><span class="section"><a href="#N100F3">Running Hsqldb</a></span></dt><dt><span class="section"><a href="#N1013D">Server Modes</a></span></dt><dd><dl><dt><span class="section"><a href="#N10148">Hsqldb Server</a></span></dt><dt><span class="section"><a href="#N10157">Hsqldb Web Server</a></span></dt><dt><span class="section"><a href="#N10168">Hsqldb Servlet</a></span></dt><dt><span class="section"><a href="#N101A8">In-Process (Standalone) Mode</a></span></dt><dt><span class="section"><a href="#N101CA">Memory-Only Databases</a></span></dt></dl></dd><dt><span class="section"><a href="#N101D8">General</a></span></dt><dd><dl><dt><span class="section"><a href="#N101DB">Closing the Database</a></span></dt><dt><span class="section"><a href="#N101E6">Using Multiple Databases in One JVM</a></span></dt><dt><span class="section"><a href="#N101EF">Creating a New Database</a></span></dt></dl></dd><dt><span class="section"><a href="#N10202">Using the Database Engine</a></span></dt><dd><dl><dt><span class="section"><a href="#N1023C">Different Types of Tables</a></span></dt><dt><span class="section"><a href="#N10255">Constraints and Indexes</a></span></dt><dt><span class="section"><a href="#N10268">SQL Support</a></span></dt><dt><span class="section"><a href="#N10281">JDBC Support</a></span></dt></dl></dd></dl></dd><dt><span class="chapter"><a href="#sql_issues-chapter">2. SQL Issues</a></span></dt><dd><dl><dt><span class="section"><a href="#N102AE">Purpose</a></span></dt><dt><span class="section"><a href="#N102B3">SQL Standard Support</a></span></dt><dt><span class="section"><a href="#N102D3">Constraints and Indexes</a></span></dt><dd><dl><dt><span class="section"><a href="#N102D6">Primary Key Constraints</a></span></dt><dt><span class="section"><a href="#N102DF">Unique Constraints</a></span></dt><dt><span class="section"><a href="#N1030E">Unique Indexes</a></span></dt><dt><span class="section"><a href="#N10318">FOREIGN KEYS</a></span></dt><dt><span class="section"><a href="#N1033B">Indexes and Query Speed</a></span></dt><dt><span class="section"><a href="#N10372">Where Condition or Join</a></span></dt><dt><span class="section"><a href="#N103A6">Subqueries and Joins</a></span></dt></dl></dd><dt><span class="section"><a href="#N103BF">Types and Arithmetic Operations</a></span></dt><dd><dl><dt><span class="section"><a href="#N103D6">Integral Types</a></span></dt><dt><span class="section"><a href="#N10426">Other Numeric Types</a></span></dt><dt><span class="section"><a href="#N1045F">Bit and Boolean Types</a></span></dt><dt><span class="section"><a href="#N1047A">Storage and Handling of Java Objects</a></span></dt><dt><span class="section"><a href="#N10499">Type Size, Precision and Scale</a></span></dt></dl></dd><dt><span class="section"><a href="#N104AE">Sequences and Identity</a></span></dt><dd><dl><dt><span class="section"><a href="#N104B3">Identity Auto-Increment Columns</a></span></dt><dt><span class="section"><a href="#N104E1">Sequences</a></span></dt></dl></dd><dt><span class="section"><a href="#N104FC">Issues with Transactions</a></span></dt><dt><span class="section"><a href="#N10521">New Features and Changes</a></span></dt></dl></dd><dt><span class="chapter"><a href="#unix-chapter">3. UNIX Quick Start</a></span></dt><dd><dl><dt><span class="section"><a href="#N10553">Purpose</a></span></dt><dt><span class="section"><a href="#N1055A">Installation</a></span></dt><dt><span class="section"><a href="#instance_setup-section">Setting up Database Instance and Server</a></span></dt><dt><span class="section"><a href="#N106CC">Accessing your Database</a></span></dt><dt><span class="section"><a href="#N10737">Create additional Accounts</a></span></dt><dt><span class="section"><a href="#N10751">Shutdown</a></span></dt><dt><span class="section"><a href="#N1075E">Running Hsqldb as a System Daemon</a></span></dt><dd><dl><dt><span class="section"><a href="#N10775">
                Portability of hsqldb init script
            </a></span></dt><dt><span class="section"><a href="#N10780">Init script Setup Procedure</a></span></dt><dt><span class="section"><a href="#initscriptTrouble-section">
                Troubleshooting the Init Script
            </a></span></dt></dl></dd></dl></dd><dt><span class="chapter"><a href="#advanced-chapter">4. Advanced Topics</a></span></dt><dd><dl><dt><span class="section"><a href="#N108C9">Purpose</a></span></dt><dt><span class="section"><a href="#N108D2">Connections</a></span></dt><dd><dl><dt><span class="section"><a href="#N109E6">Connection properties</a></span></dt></dl></dd><dt><span class="section"><a href="#N10A68">Properties Files</a></span></dt><dd><dl><dt><span class="section"><a href="#N10AC1">Server and Web Server Properties</a></span></dt><dt><span class="section"><a href="#N10BBC">Starting a Server from your application</a></span></dt><dt><span class="section"><a href="#N10BCF">Individual Database Properties</a></span></dt></dl></dd><dt><span class="section"><a href="#N10D67">SQL Commands for Database Properties</a></span></dt></dl></dd><dt><span class="chapter"><a href="#N10DAC">5. Deployment Issues</a></span></dt><dd><dl><dt><span class="section"><a href="#N10DCD">Purpose</a></span></dt><dt><span class="section"><a href="#N10DD6">Mode of Operation and Tables</a></span></dt><dd><dl><dt><span class="section"><a href="#N10DDB">Mode of Operation</a></span></dt><dt><span class="section"><a href="#N10DED">Tables</a></span></dt><dt><span class="section"><a href="#N10E04">Large Objects</a></span></dt><dt><span class="section"><a href="#N10E15">Deployment context</a></span></dt></dl></dd><dt><span class="section"><a href="#N10E21">Memory and Disk Use</a></span></dt><dd><dl><dt><span class="section"><a href="#N10E3E">Cache Memory Allocation</a></span></dt></dl></dd><dt><span class="section"><a href="#N10E5F">Managing Database Connections</a></span></dt><dt><span class="section"><a href="#N10E76">Upgrading Databases</a></span></dt><dd><dl><dt><span class="section"><a href="#upgrade_via_script-section">Upgrading Using the SCRIPT
      Command</a></span></dt><dt><span class="section"><a href="#N10ECE">Manual Changes to the .script File</a></span></dt></dl></dd><dt><span class="section"><a href="#N10F02">Backing Up Databases</a></span></dt></dl></dd><dt><span class="chapter"><a href="#texttables-chapter">6. Text Tables</a></span></dt><dd><dl><dt><span class="section"><a href="#N10F46">The Implementation</a></span></dt><dd><dl><dt><span class="section"><a href="#N10F49">Definition of Tables</a></span></dt><dt><span class="section"><a href="#N10F58">Scope and Reassignment</a></span></dt><dt><span class="section"><a href="#N10F73">Null Values in Columns of Text Tables</a></span></dt><dt><span class="section"><a href="#N10F7F">Configuration</a></span></dt></dl></dd><dt><span class="section"><a href="#N11030">Text File Issues</a></span></dt><dt><span class="section"><a href="#N11055">Text File Global Properties</a></span></dt><dt><span class="section"><a href="#N11093">Importing from a Text Table file</a></span></dt></dl></dd><dt><span class="chapter"><a href="#tls-chapter">7. TLS</a></span></dt><dd><dl><dt><span class="section"><a href="#N110D1">Requirements</a></span></dt><dt><span class="section"><a href="#N110EE">Encrypting your JDBC connection</a></span></dt><dd><dl><dt><span class="section"><a href="#N110F3">Client-Side</a></span></dt><dt><span class="section"><a href="#N1115E">Server-Side</a></span></dt></dl></dd><dt><span class="section"><a href="#jsse-section">JSSE</a></span></dt><dt><span class="section"><a href="#privatekey-section">Making a Private-key Keystore</a></span></dt><dd><dl><dt><span class="section"><a href="#N1119A">CA-Signed Cert</a></span></dt><dt><span class="section"><a href="#N111C3">Non-CA-Signed Cert</a></span></dt></dl></dd><dt><span class="section"><a href="#N111D0">Automatic Server or WebServer startup on UNIX</a></span></dt></dl></dd><dt><span class="chapter"><a href="#sqltool-chapter">8. SqlTool</a></span></dt><dd><dl><dt><span class="section"><a href="#N11219">Purpose</a></span></dt><dd><dl><dt><span class="section"><a href="#N11222">Recent changes</a></span></dt></dl></dd><dt><span class="section"><a href="#baremin-section">The Bare Minimum</a></span></dt><dd><dl><dt><span class="section"><a href="#N112DD">Non-displayable Types</a></span></dt><dt><span class="section"><a href="#N11302">Desktop shortcuts</a></span></dt><dt><span class="section"><a href="#N11380">Loading sample data</a></span></dt></dl></dd><dt><span class="section"><a href="#auth-section">RC File Authentication Setup</a></span></dt><dt><span class="section"><a href="#ilauth-section">Using Inline RC Authentication</a></span></dt><dt><span class="section"><a href="#N11461">
            Using the current version of SqlTool with an older HSQLDB
            distribution.
        </a></span></dt><dt><span class="section"><a href="#int-section">Interactive</a></span></dt><dd><dl><dt><span class="section"><a href="#N114E7">Command Types</a></span></dt><dt><span class="section"><a href="#N11538">Special Commands</a></span></dt><dt><span class="section"><a href="#N115E6">Buffer Commands</a></span></dt><dt><span class="section"><a href="#interactive_pl_commands-section">PL Commands</a></span></dt><dt><span class="section"><a href="#binary_files-section">
                Storing and retrieving binary files</a></span></dt><dt><span class="section"><a href="#N1170A">SQL History</a></span></dt><dt><span class="section"><a href="#N11719">Shell scripting and command-line piping</a></span></dt><dt><span class="section"><a href="#N11722">Emulating Non-Interactive mode</a></span></dt></dl></dd><dt><span class="section"><a href="#nonint-section">Non-Interactive</a></span></dt><dd><dl><dt><span class="section"><a href="#sqlswitch-section">Giving SQL on the Command Line</a></span></dt><dt><span class="section"><a href="#N1177D">SQL Files</a></span></dt><dt><span class="section"><a href="#scripting-section">Piping and shell scripting</a></span></dt><dt><span class="section"><a href="#N117E5">Optimally Compatible SQL Files</a></span></dt><dt><span class="section"><a href="#N117F8">Comments</a></span></dt><dt><span class="section"><a href="#N1181B">Special Commands and Buffer Commands in SQL Files</a></span></dt><dt><span class="section"><a href="#N11880">Automation</a></span></dt><dt><span class="section"><a href="#N1188B">Getting Interactive Functionality with SQL Files</a></span></dt><dt><span class="section"><a href="#charencoding-section">
                Character Encoding</a></span></dt></dl></dd><dt><span class="section"><a href="#report-section">Generating Text or HTML Reports</a></span></dt><dt><span class="section"><a href="#pl-section">SqlTool Procedural Language</a></span></dt><dd><dl><dt><span class="section"><a href="#N11915">Variables</a></span></dt><dt><span class="section"><a href="#pl_alias-section">PL Aliases</a></span></dt><dt><span class="section"><a href="#N11993">Logical Expressions</a></span></dt><dt><span class="section"><a href="#N11A0C">Flow Control</a></span></dt></dl></dd><dt><span class="section"><a href="#chunk-section">Chunking</a></span></dt><dd><dl><dt><span class="section"><a href="#N11A6A">Why?</a></span></dt><dt><span class="section"><a href="#N11A71">How?</a></span></dt></dl></dd><dt><span class="section"><a href="#raw-section">Raw Mode</a></span></dt><dt><span class="section"><a href="#N11A9E">PL/SQL</a></span></dt><dt><span class="section"><a href="#N11ABF">Using hsqltool.jar and hsqldbutil.jar</a></span></dt><dt><span class="section"><a href="#N11B18">Character-Separated-Value Imports and Exports</a></span></dt><dd><dl><dt><span class="section"><a href="#N11B36">Simple CSV exports and imports using default settings</a></span></dt><dt><span class="section"><a href="#N11B7B">Specifying queries, delimiters, file names, table names,
                columns</a></span></dt></dl></dd></dl></dd><dt><span class="chapter"><a href="#sqlsyntax-chapter">9. SQL Syntax</a></span></dt><dd><dl><dt><span class="section"><a href="#N11BFC">Notational Conventions Used in this Chapter</a></span></dt><dt><span class="section"><a href="#N11C19">SQL Commands</a></span></dt><dd><dl><dt><span class="section"><a href="#alter_index-section">ALTER INDEX</a></span></dt><dt><span class="section"><a href="#alter_sequence-section">ALTER SEQUENCE</a></span></dt><dt><span class="section"><a href="#N11C38">ALTER SCHEMA</a></span></dt><dt><span class="section"><a href="#alter_table-section">ALTER TABLE</a></span></dt><dt><span class="section"><a href="#alter_user-section">ALTER USER</a></span></dt><dt><span class="section"><a href="#call-section">CALL</a></span></dt><dt><span class="section"><a href="#checkpoint-section">CHECKPOINT</a></span></dt><dt><span class="section"><a href="#commit-section">COMMIT</a></span></dt><dt><span class="section"><a href="#connect-section">CONNECT</a></span></dt><dt><span class="section"><a href="#create_alias-section">CREATE ALIAS</a></span></dt><dt><span class="section"><a href="#create_index-section">CREATE INDEX</a></span></dt><dt><span class="section"><a href="#create_role-section">CREATE ROLE</a></span></dt><dt><span class="section"><a href="#N11D63">CREATE SCHEMA</a></span></dt><dt><span class="section"><a href="#create_sequence-section">CREATE SEQUENCE</a></span></dt><dt><span class="section"><a href="#create_table-section">CREATE TABLE</a></span></dt><dt><span class="section"><a href="#create_trigger-section">CREATE TRIGGER</a></span></dt><dt><span class="section"><a href="#create_user-section">CREATE USER</a></span></dt><dt><span class="section"><a href="#create_view-section">CREATE VIEW</a></span></dt><dt><span class="section"><a href="#delete-section">DELETE</a></span></dt><dt><span class="section"><a href="#disconnect-section">DISCONNECT</a></span></dt><dt><span class="section"><a href="#drop_index-section">DROP INDEX</a></span></dt><dt><span class="section"><a href="#N11ED7">DROP ROLE</a></span></dt><dt><span class="section"><a href="#drop_sequence-section">DROP SEQUENCE</a></span></dt><dt><span class="section"><a href="#N11EF1">DROP SCHEMA</a></span></dt><dt><span class="section"><a href="#drop_table-section">DROP TABLE</a></span></dt><dt><span class="section"><a href="#drop_trigger-section">DROP TRIGGER</a></span></dt><dt><span class="section"><a href="#drop_user-section">DROP USER</a></span></dt><dt><span class="section"><a href="#drop_view-section">DROP VIEW</a></span></dt><dt><span class="section"><a href="#explain-section">EXPLAIN PLAN</a></span></dt><dt><span class="section"><a href="#grant-section">GRANT</a></span></dt><dt><span class="section"><a href="#insert-section">INSERT</a></span></dt><dt><span class="section"><a href="#revoke-section">REVOKE</a></span></dt><dt><span class="section"><a href="#rollback-section">ROLLBACK</a></span></dt><dt><span class="section"><a href="#savepoint-section">SAVEPOINT</a></span></dt><dt><span class="section"><a href="#script-section">SCRIPT</a></span></dt><dt><span class="section"><a href="#select-section">SELECT</a></span></dt><dt><span class="section"><a href="#set_autocommit-section">SET AUTOCOMMIT</a></span></dt><dt><span class="section"><a href="#collation-section">SET DATABASE COLLATION</a></span></dt><dt><span class="section"><a href="#N1208B">SET CHECKPOINT DEFRAG</a></span></dt><dt><span class="section"><a href="#set_ignorecase-section">SET IGNORECASE</a></span></dt><dt><span class="section"><a href="#set_initialschema-section">SET INITIAL SCHEMA </a></span></dt><dt><span class="section"><a href="#set_logsize-section">SET LOGSIZE</a></span></dt><dt><span class="section"><a href="#set_password-section">SET PASSWORD</a></span></dt><dt><span class="section"><a href="#set_property-section">SET PROPERTY</a></span></dt><dt><span class="section"><a href="#set_refint-section">SET REFERENTIAL INTEGRITY</a></span></dt><dt><span class="section"><a href="#set_schema-section">SET SCHEMA</a></span></dt><dt><span class="section"><a href="#set_scriptformat-section">SET SCRIPTFORMAT</a></span></dt><dt><span class="section"><a href="#set_table_index-section">SET TABLE INDEX</a></span></dt><dt><span class="section"><a href="#set_table_readonly-section">SET TABLE READONLY</a></span></dt><dt><span class="section"><a href="#set_table_source-section">SET TABLE SOURCE</a></span></dt><dt><span class="section"><a href="#set_write_delay-section">SET WRITE DELAY</a></span></dt><dt><span class="section"><a href="#shutdown-section">SHUTDOWN</a></span></dt><dt><span class="section"><a href="#update-section">UPDATE</a></span></dt></dl></dd><dt><span class="section"><a href="#schemanaming-section">Schema object naming</a></span></dt><dt><span class="section"><a href="#datatypes-section">Data Types</a></span></dt><dt><span class="section"><a href="#N12364">SQL Comments</a></span></dt><dt><span class="section"><a href="#stored-section">Stored Procedures / Functions</a></span></dt><dt><span class="section"><a href="#N12395">Built-in Functions and Stored Procedures</a></span></dt><dt><span class="section"><a href="#expression-section">SQL Expression</a></span></dt></dl></dd><dt><span class="appendix"><a href="#building-appendix">A. Building HSQLDB</a></span></dt><dd><dl><dt><span class="section"><a href="#N1269A">Purpose</a></span></dt><dt><span class="section"><a href="#N126A3">Building with Ant</a></span></dt><dd><dl><dt><span class="section"><a href="#N126AA">Obtaining Ant</a></span></dt><dt><span class="section"><a href="#N126C2">Building Hsqldb with Ant</a></span></dt></dl></dd><dt><span class="section"><a href="#N12771">Building with DOS Batch Files</a></span></dt><dt><span class="section"><a href="#N1278A">Hsqldb CodeSwitcher</a></span></dt><dt><span class="section"><a href="#N127B6">Building documentation</a></span></dt></dl></dd><dt><span class="appendix"><a href="#firstclient-appendix">B. First JDBC Client Example</a></span></dt><dt><span class="appendix"><a href="#N12811">C. Hsqldb Database Files and Recovery</a></span></dt><dd><dl><dt><span class="section"><a href="#N12828"></a></span></dt><dt><span class="section"><a href="#N12858">States</a></span></dt><dd><dl><dt><span class="section"><a href="#N1285B"></a></span></dt><dt><span class="section"><a href="#N1288A"></a></span></dt><dt><span class="section"><a href="#N128B9"></a></span></dt></dl></dd><dt><span class="section"><a href="#N128EB">Procedures</a></span></dt><dd><dl><dt><span class="section"><a href="#N128F0">Clean Shutdown</a></span></dt><dt><span class="section"><a href="#N1294A">Startup</a></span></dt><dt><span class="section"><a href="#N1299C">Repair</a></span></dt></dl></dd></dl></dd><dt><span class="appendix"><a href="#N129E2">D. Running Hsqldb with OpenOffice.org 1.1.x</a></span></dt><dd><dl><dt><span class="section"><a href="#N12A02">Introduction</a></span></dt><dt><span class="section"><a href="#N12A0B">Installing</a></span></dt><dt><span class="section"><a href="#N12A10">Setting up OpenOffice.org</a></span></dt><dd><dl><dt><span class="section"><a href="#N12A22">On Windows</a></span></dt><dt><span class="section"><a href="#N12A35">On Linux</a></span></dt></dl></dd></dl></dd><dt><span class="appendix"><a href="#N12A55">E. Hsqldb Test Utility</a></span></dt><dt><span class="appendix"><a href="#N12ACB">F. Database Manager</a></span></dt><dd><dl><dt><span class="section"><a href="#N12AF4">Brief Introduction</a></span></dt><dt><span class="section"><a href="#N12B1E">Auto tree-update</a></span></dt><dt><span class="section"><a href="#N12B35">Automatic Connection</a></span></dt><dt><span class="section"><a href="#N12B43">RC File</a></span></dt><dt><span class="section"><a href="#N12B68">Using the current DatabaseManagers with an older HSQLDB
    distribution.</a></span></dt><dt><span class="section"><a href="#N12B9A">DatabaseManagerSwing as an Applet</a></span></dt></dl></dd><dt><span class="appendix"><a href="#N12BF8">G. Transfer Tool</a></span></dt><dd><dl><dt><span class="section"><a href="#N12C15">Brief Introduction</a></span></dt></dl></dd></dl></div><div class="list-of-tables"><p><b>List of Tables</b></p><dl><dt>1. <a href="#N1004D">Alternate formats of this document</a></dt><dt>4.1. <a href="#N108EC">Hsqldb URL Components</a></dt><dt>4.2. <a href="#N109FA">Connection Properties</a></dt><dt>4.3. <a href="#N10A81">Hsqldb Server Properties Files</a></dt><dt>4.4. <a href="#N10ACE">Property File Properties</a></dt><dt>4.5. <a href="#N10B3C">Server Property File Properties</a></dt><dt>4.6. <a href="#N10B6F">WebServer Property File Properties</a></dt><dt>4.7. <a href="#N10BEF">Database-specific Property File Properties</a></dt><dt>4.8. <a href="#N10D6C">SQL command properties</a></dt><dt>9.1. <a href="#N12272">Data Types</a></dt></dl></div><div class="list-of-examples"><p><b>List of Examples</b></p><dl><dt>1.1. <a href="#N1018D">Java code to connect to the local Server above</a></dt><dt>2.1. <a href="#N102E6">Column values which satisfy a 2-column UNIQUE
        constraint</a></dt><dt>2.2. <a href="#N103AB">Query comparison</a></dt><dt>2.3. <a href="#N104F2">Numbering returned rows of a SELECT in sequential order</a></dt><dt>3.1. <a href="#N107DB">server.properties fragment</a></dt><dt>3.2. <a href="#N107EE">example sqltool.rc stanza</a></dt><dt>7.1. <a href="#N11110">Exporting certificate from the server's keystore</a></dt><dt>7.2. <a href="#N11125">Adding a certificate to the client keystore</a></dt><dt>7.3. <a href="#N11134">Specifying your own trust store to a JDBC client</a></dt><dt>7.4. <a href="#N1116A">Running an Hsqldb server with TLS encryption</a></dt><dt>7.5. <a href="#N111AA">Getting a pem-style private key into a JKS keystore</a></dt><dt>8.1. <a href="#N113AE">Sample RC File</a></dt><dt>8.2. <a href="#alias-example">Defining and using a PL alias (PL variable)</a></dt><dt>8.3. <a href="#N116F8">Inserting binary data into database from a file</a></dt><dt>8.4. <a href="#N116FE">Downloading binary data from database to a file</a></dt><dt>8.5. <a href="#N117D5">Piping input into SqlTool</a></dt><dt>8.6. <a href="#N11801">Valid comment example</a></dt><dt>8.7. <a href="#N11809">Invalid comment example</a></dt><dt>8.8. <a href="#N11985">Simple SQL file using PL</a></dt><dt>8.9. <a href="#N11A4E">SQL File showing use of most PL features</a></dt><dt>8.10. <a href="#N11A63">Single-line chunking example</a></dt><dt>8.11. <a href="#N11A76">Multi-line chunking example</a></dt><dt>8.12. <a href="#N11A95">Raw Mode example</a></dt><dt>8.13. <a href="#N11AB8">PL/SQL Example</a></dt><dt>8.14. <a href="#N11B49">CSV Export Example</a></dt><dt>8.15. <a href="#N11B6C">CSV Import Example</a></dt><dt>8.16. <a href="#N11BB2">CSV Export of an Arbitrary SELECT Statement</a></dt><dt>A.1. <a href="#N12763">Buiding the standard Hsqldb jar file with Ant</a></dt><dt>A.2. <a href="#N12793">Example source code before CodeSwitcher is run</a></dt><dt>A.3. <a href="#N1279B">CodeSwitcher command line invocation</a></dt><dt>A.4. <a href="#N127A7">Source code after CodeSwitcher processing</a></dt><dt>A.5. <a href="#N127C8">Building HTML User Guides</a></dt><dt>A.6. <a href="#N127D9">Building User Guides in all formats</a></dt><dt>B.1. <a href="#N1280A">JDBC Client source code example</a></dt></dl></div><div class="preface" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="N10030"></a>Introduction</h2></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N1003A">Available formats for this document</a></span></dt></dl></div><p>
            If you notice any mistakes in this document, please email the
            author listed at the beginning of the chapter.
            If you have problems with the procedures themselves, please
            use the HSQLDB support facilities which are listed at
   <a href="http://hsqldb.org/web/hsqlSupport.html" target="_top">http://hsqldb.org/web/hsqlSupport.html</a>.
        </p><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N1003A"></a>Available formats for this document</h2></div></div><div></div></div><p>This document is available in several formats.</p><p>
        You may be reading this document right now at http://hsqldb.org/doc/guide, or in
        a distribution somewhere else.
        I hereby call the document distribution from which you are reading 
        this, your <span class="emphasis"><em>current distro</em></span>.
    </p><p>
        http://hsqldb.org/doc/guide hosts the latest production versions of all available formats.
        If you want a different format of the same <span class="emphasis"><em>version</em></span>
        of the document you are reading now, then you should try your
        current distro.
        If you want the latest production version, you should try http://hsqldb.org/doc/guide.
    </p><p>
        Sometimes, distributions other than http://hsqldb.org/doc/guide do not host all
        available formats.
        So, if you can't access the format that you want in your current
        distro, you have no choice but to use the newest production version at 
        http://hsqldb.org/doc/guide.
    </p><p>
    <div class="table"><a name="N1004D"></a><p class="title"><b>Table&nbsp;1.&nbsp;Alternate formats of this document</b></p><table summary="Alternate formats of this document" border="1"><colgroup><col><col><col></colgroup><thead><tr><th align="left">format</th><th align="left">your distro</th><th align="left">at http://hsqldb.org/doc/guide</th></tr></thead><tbody><tr><td align="left">
                Chunked HTML
            </td><td align="left"><a href="index.html" target="_top">index.html</a></td><td align="left"><a href="http://hsqldb.org/doc/guide/index.html" target="_top">http://hsqldb.org/doc/guide/index.html</a></td></tr><tr><td align="left">
                All-in-one HTML
            </td><td align="left"><a href="guide.html" target="_top">guide.html</a></td><td align="left"><a href="http://hsqldb.org/doc/guide/guide.html" target="_top">http://hsqldb.org/doc/guide/guide.html</a></td></tr><tr><td align="left">
                PDF
            </td><td align="left"><a href="guide.pdf" target="_top">guide.pdf</a></td><td align="left"><a href="http://hsqldb.org/doc/guide/guide.pdf" target="_top">http://hsqldb.org/doc/guide/guide.pdf</a></td></tr></tbody></table></div>
    </p></div></div><div class="chapter" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="N1007D"></a>Chapter&nbsp;1.&nbsp;Running and Using Hsqldb</h2></div><div><div class="authorgroup"><div class="author"><h3 class="author"><span class="firstname">Fred</span> <span class="surname">Toussi</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:ft@cluedup.com">ft@cluedup.com</a>&gt;</tt></div></div></div><div><div class="legalnotice"><p>Copyright 2002-2005 Fred Toussi. Permission is granted to
      distribute this document without any alteration under the terms of the
      HSQLDB license. Additional permission is granted to the HSQLDB
      Development Group to distribute this document with or without
      alterations under the terms of the HSQLDB license.</p></div></div><div><p class="pubdate">$Date: 2005/09/19 00:03:12 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N1009E">Introduction</a></span></dt><dt><span class="section"><a href="#N100B7">Running Tools</a></span></dt><dt><span class="section"><a href="#N100F3">Running Hsqldb</a></span></dt><dt><span class="section"><a href="#N1013D">Server Modes</a></span></dt><dd><dl><dt><span class="section"><a href="#N10148">Hsqldb Server</a></span></dt><dt><span class="section"><a href="#N10157">Hsqldb Web Server</a></span></dt><dt><span class="section"><a href="#N10168">Hsqldb Servlet</a></span></dt><dt><span class="section"><a href="#N101A8">In-Process (Standalone) Mode</a></span></dt><dt><span class="section"><a href="#N101CA">Memory-Only Databases</a></span></dt></dl></dd><dt><span class="section"><a href="#N101D8">General</a></span></dt><dd><dl><dt><span class="section"><a href="#N101DB">Closing the Database</a></span></dt><dt><span class="section"><a href="#N101E6">Using Multiple Databases in One JVM</a></span></dt><dt><span class="section"><a href="#N101EF">Creating a New Database</a></span></dt></dl></dd><dt><span class="section"><a href="#N10202">Using the Database Engine</a></span></dt><dd><dl><dt><span class="section"><a href="#N1023C">Different Types of Tables</a></span></dt><dt><span class="section"><a href="#N10255">Constraints and Indexes</a></span></dt><dt><span class="section"><a href="#N10268">SQL Support</a></span></dt><dt><span class="section"><a href="#N10281">JDBC Support</a></span></dt></dl></dd></dl></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N1009E"></a>Introduction</h2></div></div><div></div></div><p>The HSQLDB jar package is located in the /lib directory and contains
    several components and programs. Different commands are used to run each
    program.</p><div class="itemizedlist"><p class="title"><b>Components of the Hsqldb jar package</b></p><ul type="disc"><li><p>HSQLDB RDBMS</p></li><li><p>HSQLDB JDBC Driver</p></li><li><p>Database Manager (Swing and AWT versions)</p></li><li><p>Query Tool (AWT)</p></li><li><p>Sql Tool (command line)</p></li></ul></div><p>The HSQLDB RDBMS and JDBC Driver provide the core functionality. The
    rest are general-purpose database tools that can be used with any database
    engine that has a JDBC driver.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N100B7"></a>Running Tools</h2></div></div><div></div></div><p>All tools can be run in the standard way for archived Java classes.
    In the following example the AWT version of the Database Manager, the
    <tt class="filename">hsqldb.jar</tt> is located in the directory
    <tt class="filename">../lib</tt> relative to the current directory.</p><pre class="screen">
    java -cp ../lib/hsqldb.jar org.hsqldb.util.DatabaseManager</pre><p>If <tt class="filename">hsqldb.jar</tt> is in the current directory, the
    command would change to:</p><pre class="screen">
    java -cp hsqldb.jar org.hsqldb.util.DatabaseManager</pre><div class="itemizedlist"><p class="title"><b>Main classes for the Hsqldb tools</b></p><ul type="disc"><li><p>
          <tt class="classname">org.hsqldb.util.DatabaseManager</tt>
        </p></li><li><p>
          <tt class="classname">org.hsqldb.util.DatabaseManagerSwing</tt>
        </p></li><li><p>
          <tt class="classname">org.hsqldb.util.Transfer</tt>
        </p></li><li><p>
          <tt class="classname">org.hsqldb.util.QueryTool</tt>
        </p></li><li><p>
          <tt class="classname">org.hsqldb.util.SqlTool</tt>
        </p></li></ul></div><p>Some tools, such as the Database Manager or SQL Tool, can use
    command line arguments or entirely rely on them. You can add the command
    line argument -? to get a list of available arguments for these tools.
    Database Manager features a graphical user interface and
    can be explored interactively.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N100F3"></a>Running Hsqldb</h2></div></div><div></div></div><p>HSQLDB can be run in a number of different ways. In general these
    are divided into Server Modes and In-Process Mode (also called Standalone
    Mode). A different sub-program from the jar is used to run HSQLDB in each
    mode.</p><p>Each HSQLDB database consists of between 2 to 5 files, all named the
    same but with different extensions, located in the same directory. For
    example, the database named "test" consists of the following files:</p><div class="itemizedlist"><ul type="disc"><li><p>
          <tt class="filename">test.properties</tt>
        </p></li><li><p>
          <tt class="filename">test.script</tt>
        </p></li><li><p>
          <tt class="filename">test.log</tt>
        </p></li><li><p>
          <tt class="filename">test.data</tt>
        </p></li><li><p>
          <tt class="filename">test.backup</tt>
        </p></li></ul></div><p>The properties files contains general settings about the database.
    The script file contains the definition of tables and other database
    objects, plus the data for non-cached tables. The log file contains recent
    changes to the database. The data file contains the data for cached tables
    and the backup file is a zipped backup of the last known consistent state
    of the data file. All these files are essential and should never be
    deleted. If the database has no cached tables, the
    <tt class="filename">test.data</tt> and <tt class="filename">test.backup</tt> files
    will not be present. In addition to those files, HSQLDB database may link
    to any formatted text files, such as CSV lists, anywhere on the
    disk.</p><p>While the "test" database is operational, a
    <tt class="filename">test.log</tt> file is used to write the changes made to
    data. This file is removed at a normal SHUTDOWN. Otherwise (with abnormal
    shutdown) this file is used at the next startup to redo the changes. A
    <tt class="filename">test.lck </tt>file is also used to record the fact that
    the database is open. This is deleted at a normal SHUTDOWN. In some
    circumstances, a <tt class="filename">test.data.old</tt> is created and deleted
    afterwards.</p><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>When the engine closes the database at a shutdown, it creates
      temporary files with the extension <tt class="literal">.new</tt> which it then
      renames to those listed above.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N1013D"></a>Server Modes</h2></div></div><div></div></div><p>Server modes provide the maximum accessibility. The database engine
    runs in a JVM and listens for connections from programs on the same
    computer or other computers on the network. Several different programs can
    connect to the server and retrieve or update information. Applications
    programs (clients) connect to the server using the HSQLDB JDBC driver. In
    most server modes, the server can serve up to 10 databases that are
    specified at the time of running the server.</p><p>Server modes can use preset properties or command line arguments as
    detailed in the <a href="#advanced-chapter" title="Chapter&nbsp;4.&nbsp;Advanced Topics">Advanced Topics</a> chapter. There are three server modes, based
    on the protocol used for communications between the client and
    server.</p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10148"></a>Hsqldb Server</h3></div></div><div></div></div><p>This is the preferred way of running a database server and the
      fastest one. A proprietary communications protocol is used for this
      mode. A command similar to those used for running tools and described
      above is used for running the server. The following example of the
      command for starting the server starts the server with one (default)
      database with files named "mydb.*".</p><div class="informalexample"><pre class="screen">
    java -cp ../lib/hsqldb.jar org.hsqldb.Server -database.0 file:mydb -dbname.0 xdb</pre></div><p>The command line argument <tt class="literal">-?</tt> can be used to get
      a list of available arguments.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10157"></a>Hsqldb Web Server</h3></div></div><div></div></div><p>This mode is used when access to the computer hosting the database
      server is restricted to the HTTP protocol. The only reason for using the
      Web Server mode is restrictions imposed by firewalls on the client or
      server machines and it should not be used where there are no such
      restrictions. The HSQLDB Web Server is a special web server that allows
      JDBC clients to connect via HTTP. From 1.7.2 this mode also supports
      transactions.</p><p>To run a web server, replace the main class for the server in the
      example command line above with the following:</p><div class="informalexample"><pre class="screen">
    org.hsqldb.WebServer</pre></div><p>The command line argument <tt class="literal">-?</tt> can be used to get
      a list of available arguments.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10168"></a>Hsqldb Servlet</h3></div></div><div></div></div><p>This uses the same protocol as the Web Server. It is used when a
      separate servlet engine (or application server) such as Tomcat or Resin
      provides access to the database. The Servlet Mode cannot be started
      independently from the servlet engine. The
      <tt class="filename">hsqlServlet</tt> class, in the HSQLDB jar, should be
      installed on the application server to provide the connection. The
      database is specified using an application server property. Refer to the
      source file <tt class="filename">hsqlServlet.java</tt> to see the
      details.</p><p>Both Web Server and Servlet modes can only be accessed using the
      JDBC driver at the client end. They do not provide a web front end to
      the database. The Servlet mode can serve only a single database.</p><p>Please note that you do not normally use this mode if you are
      using the database engine in an application server.</p><div class="section" lang="en"><div class="titlepage"><div><div><h4 class="title"><a name="N10179"></a>Connecting to a Database running as a Server</h4></div></div><div></div></div><p>Once an HSQLDB server is running, client programs can connect to
        it using the HSQLDB JDBC Driver contained in
        <tt class="filename">hsqldb.jar</tt>. Full information on how to connect to
        a server is provided in the Java Documentation for <a href="../src/org/hsqldb/jdbc/jdbcConnection.html" target="_top">
            <tt class="classname">jdbcConnection</tt>
          </a> (located in the <tt class="filename">/doc/src</tt> directory of
        HSQLDB distribution. A common example is connection to the default
        port (9001) used for the hsql protocol on the same machine:</p><div class="example"><a name="N1018D"></a><p class="title"><b>Example&nbsp;1.1.&nbsp;Java code to connect to the local Server above</b></p><pre class="programlisting">
    try {
        Class.forName("org.hsqldb.jdbcDriver" );
    } catch (Exception e) {
        System.out.println("ERROR: failed to load HSQLDB JDBC driver.");
        e.printStackTrace();
        return;
    }

    Connection c = DriverManager.getConnection("jdbc:hsqldb:hsql://localhost/xdb", "sa", "");</pre></div><p>In some circumstances, you may have to use the following line to
        get the driver.</p><div class="informalexample"><pre class="programlisting">
    Class.forName("org.hsqldb.jdbcDriver").newInstance();</pre></div><p>Note in the above connection URL, there is no mention of the
        database file, as this was specified when running the server. Instead,
        the value defined for dbname.0 is used. Also, see the <a href="#advanced-chapter" title="Chapter&nbsp;4.&nbsp;Advanced Topics">Advanced Topics</a> chapter for the
        connection URL when there is more than one database per server
        instance.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h4 class="title"><a name="N1019F"></a>Security Considerations</h4></div></div><div></div></div><p>When HSQLDB is run as a server, network access should be
        adequately protected. Source IP addresses may be restricted by use of
        TCP filtering or firewall programs, or standalone firewalls. If the
        traffic will cross an unprotected network (such as the Internet), the
        stream should be encrypted (for example by VPN, ssh tunneling, or
        <a href="#tls-chapter" title="Chapter&nbsp;7.&nbsp;TLS">TLS</a> using the SSL
        enabled HSQLS and HTTPS variants of the server and web server modes).
        Only secure passwords should be used-- most importantly, the password
        for the default system user should be changed from the default empty
        string. If you are purposefully providing data to the public, then the
        wide-open public network connection should be used exclusively to
        access the public data via read-only accounts. (I.e., neither secure
        data nor privileged accounts should use this connection). These
        considerations also apply to HSQLDB servers run with the HTTP
        protocol.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N101A8"></a>In-Process (Standalone) Mode</h3></div></div><div></div></div><p>This mode runs the database engine as part of your application
      program in the same Java Virtual Machine. For most applications this
      mode can be faster, as the data is not converted and sent over the
      network. The main drawback is that it is not possible by default to
      connect to the database from outside your application. As a result you
      cannot check the contents of the database with external tools such as
      Database Manager while your application is running. In 1.8.0, you can
      run a server instance in a thread from the same virtual machine as your
      application and provide external access to your in-process
      database.</p><p>The recommended way of using the in-process mode in an application
      is to use an HSQLDB Server instance for the database while developing
      the application and then switch to In-Process mode for
      deployment.</p><p>An In-Process Mode database is started from JDBC, with the
      database file path specified in the connection URL. For example, if the
      database name is testdb and its files are located in the same directory
      as where the command to run your application was issued, the following
      code is used for the connection:</p><pre class="programlisting">
    Connection c = DriverManager.getConnection("jdbc:hsqldb:file:testdb", "sa", "");</pre><p>The database file path format can be specified using forward
      slashes in Windows hosts as well as Linux hosts. So relative paths or
      paths that refer to the same directory on the same drive can be
      identical. For example if your database path in Linux is
      <tt class="filename">/opt/db/testdb</tt> and you create an identical
      directory structure on the <tt class="literal">C:</tt> drive of a Windows
      host, you can use the same URL in both Windows and Linux:</p><pre class="programlisting">
    Connection c = DriverManager.getConnection("jdbc:hsqldb:file:/opt/db/testdb", "sa", "");</pre><p>When using relative paths, these paths will be taken relative to
      the directory in which the shell command to start the Java Virtual
      Machine was executed. Refer to Javadoc for <a href="../src/org/hsqldb/jdbc/jdbcConnection.html" target="_top">
          <tt class="classname">jdbcConnection</tt>
        </a> for more details.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N101CA"></a>Memory-Only Databases</h3></div></div><div></div></div><p>It is possible to run HSQLDB in a way that the database is not
      persistent and exists entirely in random access memory. As no
      information is written to disk, this mode should be used only for
      internal processing of application data, in applets or certain special
      applications. This mode is specified by the mem: protocol.</p><pre class="programlisting">
    Connection c = DriverManager.getConnection("jdbc:hsqldb:mem:aname", "sa", "");</pre><p>You can also run a memory-only server instance by specifying the
      same URL in the <tt class="filename">server.properties</tt>. This usage is
      not common and is limited to special applications where the database
      server is used only for exchanging information between clients, or for
      non-persistent data.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N101D8"></a>General</h2></div></div><div></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N101DB"></a>Closing the Database</h3></div></div><div></div></div><p>All databases running in different modes can be closed with the
      SHUTDOWN command, issued as an SQL query. From version 1.7.2, in-process
      databases are no longer closed when the last connection to the database
      is explicitly closed via JDBC, a SHUTDOWN is required. In 1.8.0, a
      connection property, shutdown=true, can be specified on the first
      connection to the database (the connection that opens the database) to
      force a shutdown when the last connection closes.</p><p>When SHUTDOWN is issued, all active transactions are rolled back.
      A special form of closing the database is via the SHUTDOWN COMPACT
      command. This command rewrites the <tt class="literal">.data</tt> file that
      contains the information stored in CACHED tables and compacts it to
      size. This command should be issued periodically, especially when lots
      of inserts, updates or deletes have been performed on the cached tables.
      Changes to the structure of the database, such as dropping or modifying
      populated CACHED tables or indexes also create large amounts of unused
      file space that can be reclaimed using this command.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N101E6"></a>Using Multiple Databases in One JVM</h3></div></div><div></div></div><p>In the above examples each server serves only one database and
      only one in-memory database can be created. However, from version 1.7.2,
      HSQLDB can serve several databases in multiple server modes and allow
      simultaneous access to multiple in-process and memory-only databases.
      These capabilities are covered in the <a href="#advanced-chapter" title="Chapter&nbsp;4.&nbsp;Advanced Topics">Advanced Topics</a> chapter.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N101EF"></a>Creating a New Database</h3></div></div><div></div></div><p>When a server instance is started, or when a connection is made to
      an in-process database, a new, empty database is created if no database
      exists at the given path.</p><p>This feature has a side effect that can confuse new users. If a
      mistake is made in specifying the path for connecting to an existing
      database, a connection is nevertheless established to a new database.
      For troubleshooting purposes, you can specify a connection property
      <span class="property">ifexists</span>=<tt class="literal">true</tt> to allow
      connection to an existing database only and avoid creating a new
      database. In this case, if the database does not exist, the
      <tt class="literal">getConnection()</tt> method will throw an
      exception.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10202"></a>Using the Database Engine</h2></div></div><div></div></div><p>Once a connection is established to a database in any mode, JDBC
    methods are used to interact with the database. The Javadoc for <a href="../src/org/hsqldb/jdbc/jdbcConnection.html" target="_top">
        <tt class="classname">jdbcConnection</tt>
      </a>, <a href="../src/org/hsqldb/jdbcDriver.html" target="_top">
        <tt class="classname">jdbcDriver</tt>
      </a>, <a href="../src/org/hsqldb/jdbc/jdbcDatabaseMetaData.html" target="_top">
        <tt class="classname">jdbcDatabaseMetadata</tt>
      </a>, <a href="../src/org/hsqldb/jdbc/jdbcResultSet.html" target="_top">
        <tt class="classname">jdbcResultSet</tt>
      </a>, <a href="../src/org/hsqldb/jdbc/jdbcStatement.html" target="_top">
        <tt class="classname">jdbcStatement</tt>
      </a>, and <a href="../src/org/hsqldb/jdbc/jdbcPreparedStatement.html" target="_top">
        <tt class="classname">jdbcPreparedStatement</tt>
      </a> list all the supported JDBC methods together with information
    that is specific to HSQLDB. JDBC methods are broadly divided into:
    connection related methods, metadata methods and database access methods.
    The database access methods use SQL commands to perform actions on the
    database and return the results either as a Java primitive type or as an
    instance of the <tt class="classname">java.sql.ResultSet</tt> class.</p><p>You can use Database Manager or other Java database access tools to
    explore your database and update it with SQL commands. These programs use
    JDBC internally to submit your commands to the database engine and to
    display the results in a human readable format.</p><p>The SQL dialect used in HSQLDB is as close to the SQL92 and SQL200n
    standards as it has been possible to achieve so far in a small-footprint
    database engine. The full list of SQL commands is in the <a href="#sqlsyntax-chapter" title="Chapter&nbsp;9.&nbsp;SQL Syntax">SQL Syntax</a> chapter.</p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1023C"></a>Different Types of Tables</h3></div></div><div></div></div><p>HSQLDB supports TEMP tables and three types of persistent
      tables.</p><p>TEMP tables are not written to disk and last only for the lifetime
      of the Connection object. The contents of each TEMP table is visible
      only from the Connection that was used to populate it; other concurrent
      connections to the database will have access to their own copies of the
      table. Since 1.8.0 the definition of TEMP tables conforms to the GLOBAL
      TEMPORARY type in the SQL standard. The definition of the table persists
      but each new connections sees its own copy of the table, which is empty
      at the beginning. When the connection commits, the contents of the table
      are cleared by default. If the table definition statements includes ON
      COMMIT PRESERVE ROWS, then the contents are kept when a commit takes
      place.</p><p>The three types of persistent tables are MEMORY tables, CACHED
      tables and TEXT tables.</p><p>Memory tables are the default type when the CREATE TABLE command
      is used. Their data is held entirely in memory but any change to their
      structure or contents is written to the
      <tt class="filename">&lt;dbname&gt;.script</tt> file. The script file is read
      the next time the database is opened, and the MEMORY tables are
      recreated with all their contents. So unlike TEMP table, the default,
      MEMORY tables are persistent.</p><p>CACHED tables are created with the CREATE CACHED TABLE command.
      Only part of their data or indexes is held in memory, allowing large
      tables that would otherwise take up to several hundred megabytes of
      memory. Another advantage of cached tables is that the database engine
      takes less time to start up when a cached table is used for large
      amounts of data. The disadvantage of cached tables is a reduction in
      speed. Do not use cached tables if your data set is relatively small. In
      an application with some small tables and some large ones, it is better
      to use the default, MEMORY mode for the small tables.</p><p>TEXT tables are supported since version 1.7.0 and use a CSV (Comma
      Separated Value) or other delimited text file as the source of their
      data. You can specify an existing CSV file, such as a dump from another
      database or program, as the source of a TEXT table. Alternatively, you
      can specify an empty file to be filled with data by the database engine.
      TEXT tables are efficient in memory usage as they cache only part of the
      text data and all of the indexes. The Text table data source can always
      be reassigned to a different file if necessary. Two commands are needed
      to set up a TEXT table as detailed in the <a href="#texttables-chapter" title="Chapter&nbsp;6.&nbsp;Text Tables">Text Tables</a>
      chapter.</p><p>With memory-only databases (see above), both MEMORY table and
      CACHED table declarations are treated as declarations for non-persistent
      memory tables. TEXT table declarations are not allowed in this
      mode.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10255"></a>Constraints and Indexes</h3></div></div><div></div></div><p>HSQLDB supports PRIMARY KEY, NOT NULL, UNIQUE, CHECK and FOREIGN
      KEY constraints. In addition, it supports UNIQUE or ordinary indexes.
      This support is fairly comprehensive and covers multi-column constraints
      and indexes, plus cascading updates and deletes for foreign keys.</p><p>HSQLDB creates indexes internally to support PRIMARY KEY, UNIQUE
      and FOREIGN KEY constraints: a unique index is created for each PRIMARY
      KEY or UNIQUE constraint; an ordinary index is created for each FOREIGN
      KEY constraint. Because of this, you should not create duplicate
      user-defined indexes on the same column sets covered by these
      constraints. This would result in unnecessary memory and speed
      overheads. See the discussion in the <a href="#sql_issues-chapter" title="Chapter&nbsp;2.&nbsp;SQL Issues">SQL Issues</a> chapter for more information.</p><p>Indexes are crucial for adequate query speed. When queries joining
      multiple tables are used, there must be an index on each joined column
      of each table. When range or equality conditions are used e.g.
      <tt class="literal">SELECT ... WHERE acol &gt;10 AND bcol = 0</tt>, an indexe
      is required on the acol column used in the condition. Indexes have no
      effect on ORDER BY clauses or some LIKE conditions.</p><p>As a rule of thumb, HSQLDB is capable of internal processing of
      queries at over 100,000 rows per second. Any query that runs into
      several seconds should be checked and indexes should be added to the
      relevant columns of the tables if necessary.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10268"></a>SQL Support</h3></div></div><div></div></div><p>The SQL syntax supported by HSQLDB is essentially that specified
      by the SQL Standard (92 and 200n). Not all the features of the Standard
      are supported and there are some proprietary extensions. In 1.8.0 the
      behaviour of the engine is far more compliant with the Standards than
      with older versions. The main changes are</p><div class="itemizedlist"><ul type="disc"><li><p>correct treatment of NULL column values in joins, in UNIQUE
          constraints and in query conditions</p></li><li><p>correct processing of selects with JOIN and LEFT OUTER
          JOIN</p></li><li><p>correct processing of aggregate functions contained in
          expressions or containing expression arguments</p></li></ul></div><p>The supported commands are listed in the <a href="#sqlsyntax-chapter" title="Chapter&nbsp;9.&nbsp;SQL Syntax">SQL Syntax</a> chapter. For a
      well written basic guide to SQL with examples you can consult <a href="http://www.postgresql.org/files/documentation/books/aw_pgsql/index.html" target="_top">
      PostgreSQL: Introduction and Concepts</a> by Bruce Momjian, which is
      available on the web. Most of the SQL coverage in the book applies also
      to HSQLDB. There are some differences in keywords supported by one and
      not the other engine (OUTER, OID's, etc.) or used differently
      (IDENTITY/SERIAL, TRIGGER, SEQUENCE, etc.).</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10281"></a>JDBC Support</h3></div></div><div></div></div><p>Since 1.7.2, support for JDBC2 has been significantly extended and
      some features of JDBC3 are also supported. The relevant classes are
      thoroughly documented. See the JavaDoc for <a href="../src/index.html" target="_top">org.hsqldb.jdbcXXXX </a> classes.</p></div></div></div><div class="chapter" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="sql_issues-chapter"></a>Chapter&nbsp;2.&nbsp;SQL Issues</h2></div><div><div class="authorgroup"><div class="author"><h3 class="author"><span class="firstname">Fred</span> <span class="surname">Toussi</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:ft@cluedup.com">ft@cluedup.com</a>&gt;</tt></div></div></div><div><div class="legalnotice"><p>Copyright 2002-2005 Fred Toussi. Permission is granted to
      distribute this document without any alteration under the terms of the
      HSQLDB license. Additional permission is granted to the HSQLDB
      Development Group to distribute this document with or without
      alterations under the terms of the HSQLDB license.</p></div></div><div><p class="pubdate">$Date: 2005/07/01 17:06:32 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N102AE">Purpose</a></span></dt><dt><span class="section"><a href="#N102B3">SQL Standard Support</a></span></dt><dt><span class="section"><a href="#N102D3">Constraints and Indexes</a></span></dt><dd><dl><dt><span class="section"><a href="#N102D6">Primary Key Constraints</a></span></dt><dt><span class="section"><a href="#N102DF">Unique Constraints</a></span></dt><dt><span class="section"><a href="#N1030E">Unique Indexes</a></span></dt><dt><span class="section"><a href="#N10318">FOREIGN KEYS</a></span></dt><dt><span class="section"><a href="#N1033B">Indexes and Query Speed</a></span></dt><dt><span class="section"><a href="#N10372">Where Condition or Join</a></span></dt><dt><span class="section"><a href="#N103A6">Subqueries and Joins</a></span></dt></dl></dd><dt><span class="section"><a href="#N103BF">Types and Arithmetic Operations</a></span></dt><dd><dl><dt><span class="section"><a href="#N103D6">Integral Types</a></span></dt><dt><span class="section"><a href="#N10426">Other Numeric Types</a></span></dt><dt><span class="section"><a href="#N1045F">Bit and Boolean Types</a></span></dt><dt><span class="section"><a href="#N1047A">Storage and Handling of Java Objects</a></span></dt><dt><span class="section"><a href="#N10499">Type Size, Precision and Scale</a></span></dt></dl></dd><dt><span class="section"><a href="#N104AE">Sequences and Identity</a></span></dt><dd><dl><dt><span class="section"><a href="#N104B3">Identity Auto-Increment Columns</a></span></dt><dt><span class="section"><a href="#N104E1">Sequences</a></span></dt></dl></dd><dt><span class="section"><a href="#N104FC">Issues with Transactions</a></span></dt><dt><span class="section"><a href="#N10521">New Features and Changes</a></span></dt></dl></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N102AE"></a>Purpose</h2></div></div><div></div></div><p>Many questions repeatedly asked in Forums and mailing lists are
    answered in this guide. If you want to use HSQLDB with your application,
    you should read this guide.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N102B3"></a>SQL Standard Support</h2></div></div><div></div></div><p>HSQLDB 1.8.0 supports the dialect of SQL defined by SQL standards
    92, 99 and 2003. This means where a feature of the standard is supported,
    e.g. left outer join, the syntax is that specified by the standard text.
    Many features of SQL92 and 99 up to Advanced Level are supported and there
    is support for most of SQL 2003 Foundation and several optional features
    of this standard. However, certain features of the Standards are not
    supported so no claim is made for full support of any level of the
    standards.</p><p>The SQL Syntax chapter of this guide <a href="#sqlsyntax-chapter" title="Chapter&nbsp;9.&nbsp;SQL Syntax">SQL Syntax</a> lists all the keywords and syntax that is
    supported. When writing or converting existing SQL DDL (Data Definition
    Language) and DML (Data Manipulation Language) statements for HSQLDB, you
    should consult the supported syntax and modify the statements
    accordingly.</p><p>Several words are reserved by the standard and cannot be used as
    table or column names. For example, the word POSITION is reserved as it is
    a function defined by the Standards with a similar role as
    String.indexOf() in Java. HSQLDB does not currently prevent you from using
    a reserved word if it does not support its use or can distinguish it. For
    example BEGIN is a reserved words that is not currently supported by
    HSQLDB and is allowed as a table or column name. You should avoid the use
    of such words as future versions of HSQLDB are likely to support the words
    and will reject your table definitions or queries. The full list of SQL
    reserved words is in the source of the
    <tt class="classname">org.hsqldb.Token</tt> class.</p><p>HSQLDB also supports some keywords and expressions that are not part
    of the SQL standard as enhancements. Expressions such as <tt class="literal">SELECT
    TOP 5 FROM ..</tt>, <tt class="literal">SELECT LIMIT 0 10 FROM ...</tt> or
    <tt class="literal">DROP TABLE mytable IF EXISTS</tt> are among such
    constructs.</p><p>All keywords, can be used for database objects if they are double
    quoted.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N102D3"></a>Constraints and Indexes</h2></div></div><div></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N102D6"></a>Primary Key Constraints</h3></div></div><div></div></div><p>Before 1.7.0, a<tt class="literal"> CONSTRAINT &lt;name&gt; PRIMARY
      KEY</tt> was translated internally to a unique index and, in
      addition, a hidden column was added to the table with an extra unique
      index. From 1.7.0 both single-column and multi-column PRIMARY KEY
      constraints are supported. They are supported by a unique index on the
      primary key column(s) specified and no extra hidden column is maintained
      for these indexes.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N102DF"></a>Unique Constraints</h3></div></div><div></div></div><p>According to the SQL standards, a unique constraint on a single
      column means no two values are equal unless one of them is NULL. This
      means you can have one or more rows where the column value is
      NULL.</p><p>A unique constraint on multiple columns (c1, c2, c3, ..) means
      that no two sets of values for the columns are equal unless at lease one
      of them is NULL. Each single column taken by itself can have repeat
      values. The following example satisfies a UNIQUE constraint on the two
      columns:</p><div class="example"><a name="N102E6"></a><p class="title"><b>Example&nbsp;2.1.&nbsp;Column values which satisfy a 2-column UNIQUE
        constraint</b></p><table summary="Simple list" border="0" class="simplelist"><tr><td>1,</td><td>2</td></tr><tr><td>2,</td><td>1</td></tr><tr><td>2,</td><td>2</td></tr><tr><td>NULL,</td><td>1</td></tr><tr><td>NULL,</td><td>1</td></tr><tr><td>1,</td><td>NULL</td></tr><tr><td>NULL,</td><td>NULL</td></tr><tr><td>NULL,</td><td>NULL</td></tr></table></div><p>Since version 1.7.2 the behaviour of UNIQUE constraints and
      indexes with respect to NULL values has changed to conform to SQL
      standards. A row, in which the value for any of the UNIQUE constraint
      columns is NULL, can always be added to the table. So multiple rows can
      contain the same values for the UNIQUE columns if one of the values is
      NULL.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1030E"></a>Unique Indexes</h3></div></div><div></div></div><p>In 1.8.0, user defined UNIQUE indexes can still be declared but
      they are deprecated. You should use a UNIQUE constraint instead.</p><p><tt class="literal">CONSTRAINT &lt;name&gt; UNIQUE</tt> always creates
      internally a unique index on the columns, as with previous versions, so
      it has exactly the same effect as the deprecated UNIQUE index
      declaration.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10318"></a>FOREIGN KEYS</h3></div></div><div></div></div><p>From version 1.7.0, HSQLDB features single and multiple column
      foreign keys. A foreign key can also be specified to reference a target
      table without naming the target column(s). In this case the primary key
      column(s) of the target table is used as the referenced column(s). Each
      pair of referencing and referenced columns in any foreign key should be
      of identical type. When a foreign key is declared, a unique constraint
      (or primary key) must exist on the referenced columns in the primary key
      table. A non-unique index is automatically created on the referencing
      columns. For example:</p><div class="informalexample"><pre class="programlisting">
    CREATE TABLE child(c1 INTEGER, c2 VARCHAR, FOREIGN KEY (c1, c2) REFERENCES parent(p1, p2));</pre></div><p>There must be a UNIQUE constraint on columns
      <tt class="literal">(p1,p2)</tt> in the table named "parent". A non-unique
      index is automatically created on columns <tt class="literal">(c1, c2)</tt> in
      the table named "child". Columns <tt class="literal">p1</tt> and
      <tt class="literal">c1</tt> must be of the same type (INTEGER). Columns
      <tt class="literal">p2</tt> and <tt class="literal">c2</tt> must be of the same type
      (VARCHAR).</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1033B"></a>Indexes and Query Speed</h3></div></div><div></div></div><p>HSQLDB does not use indexes to improve sorting of query results.
      But indexes have a crucial role in improving query speed. If no index is
      used in a query on a single table, such as a DELETE query, then all the
      rows of the table must be examined. With an index on one of the columns
      that is in the WHERE clause, it is often possible to start directly from
      the first candidate row and reduce the number of rows that are
      examined.</p><p>Indexes are even more important in joins between multiple tables.
      <tt class="literal">SELECT ... FROM t1 JOIN t2 ON t1.c1 = t2.c2 </tt> is
      performed by taking rows of t1 one by one and finding a matching row in
      t2. If there is no index index on t2.c2 then for each row of t1, all the
      rows of t2 must be checked. Whereas with an index, a matching row can be
      found in a fraction of the time. If the query also has a condition on
      t1, e.g., <tt class="literal">SELECT ... FROM t1 JOIN t2 ON t1.c1 = t2.c2 WHERE
      t1.c3 = 4</tt> then an index on t1.c3 would eliminate the need for
      checking all the rows of t1 one by one, and will reduce query time to
      less than a millisecond per returned row. So if t1 and t2 each contain
      10,000 rows, the query without indexes involves checking 100,000,000 row
      combinations. With an index on t2.c2, this is reduced to 10,000 row
      checks and index lookups. With the additional index on t2.c2, only about
      4 rows are checked to get the first result row.</p><p>Indexes are automatically created for primary key and unique
      columns. Otherwise you should define an index using the CREATE INDEX
      command.</p><p>Note that in HSQLDB a unique index on multiple columns can be used
      internally as a non-unique index on the first column in the list. For
      example: <tt class="literal">CONSTRAINT name1 UNIQUE (c1, c2, c3); </tt> means
      there is the equivalent of <tt class="literal">CREATE INDEX name2 ON
      atable(c1);</tt>. So you do not need to specify an extra index if
      you require one on the first column of the list.</p><p>In 1.8.0, a multi-column index will speed up queries that contain
      joins or values on ALL the columns. You need NOT declare additional
      individual indexes on those columns unless you use queries that search
      only on a subset of the columns. For example, rows of a table that has a
      PRIMARY KEY or UNIQUE constraint on three columns or simply an ordinary
      index on those columns can be found efficiently when values for all
      three columns are specified in the WHERE clause. For example,
      <tt class="literal">SELECT ... FROM t1 WHERE t1.c1 = 4 AND t1.c2 = 6 AND t1.c3 = 8
      </tt>will use an index on <tt class="literal">t1(c1,c2,c3)</tt> if it
      exists.</p><p>As a result of the improvements to multiple key indexes, the order
      of declared columns of the index or constraint has less affect on the
      speed of searches than before. If the column that contains more diverse
      values appears first, the searches will be slightly faster.</p><p>A multi-column index will not speed up queries on the second or
      third column only. The first column must be specified in the JOIN .. ON
      or WHERE conditions.</p><p>Query speed depends a lot on the order of the tables in the JOIN
      .. ON or FROM clauses. For example the second query below should be
      faster with large tables (provided there is an index on
      <tt class="literal">TB.COL3</tt>). The reason is that TB.COL3 can be evaluated
      very quickly if it applies to the first table (and there is an index on
      TB.COL3):</p><div class="informalexample"><pre class="programlisting">
    (TB is a very large table with only a few rows where TB.COL3 = 4)

    SELECT * FROM TA JOIN TB ON TA.COL1 = TB.COL2 AND TB.COL3 = 4;

    SELECT * FROM TB JOIN TA ON TA.COL1 = TB.COL2 AND TB.COL3 = 4;</pre></div><p>The general rule is to put first the table that has a narrowing
      condition on one of its columns.</p><p>1.7.3 features automatic, on-the-fly indexes for views and
      subselects that are used in a query. An index is added to a view when it
      is joined to a table or another view.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10372"></a>Where Condition or Join</h3></div></div><div></div></div><p>Using <tt class="literal">WHERE</tt> conditions to join tables is likely
      to reduce execution speed. For example the following query will
      generally be slow, even with indexes:</p><pre class="programlisting">
    SELECT ... FROM TA, TB, TC WHERE TC.COL3 = TA.COL1 AND TC.COL3=TB.COL2 AND TC.COL4 = 1</pre><p>The query implies <tt class="literal">TA.COL1 = TB.COL2</tt> but does
      not explicitly set this condition. If TA and TB each contain 100 rows,
      10000 combinations will be joined with TC to apply the column
      conditions, even though there may be indexes on the joined columns. With
      the JOIN keyword, the <tt class="literal">TA.COL1 = TB.COL2</tt> condition has
      to be explicit and will narrow down the combination of TA and TB rows
      before they are joined with TC, resulting in much faster execution with
      larger tables:</p><pre class="programlisting">
    SELECT ... FROM TA JOIN TB ON TA.COL1 = TB.COL2 JOIN TC ON TB.COL2 = TC.COL3 WHERE TC.COL4 = 1</pre><p>The query can be speeded up a lot more if the order of tables in
      joins are changed, so that <tt class="literal">TC.COL1 = 1</tt> is applied
      first and a smaller set of rows are joined together:</p><pre class="programlisting">
    SELECT ... FROM TC JOIN TB ON TC.COL3 = TB.COL2 JOIN TA ON TC.COL3 = TA.COL1 WHERE TC.COL4 = 1</pre><p>In the above example the engine automatically applies
      <tt class="literal">TC.COL4 = 1</tt> to TC and joins only the set of rows that
      satisfy this condition with other tables. Indexes on
      <tt class="literal">TC.COL4</tt>, <tt class="literal">TB.COL2</tt> and
      <tt class="literal">TA.COL1</tt> will be used if present and will speed up the
      query.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N103A6"></a>Subqueries and Joins</h3></div></div><div></div></div><p>Using joins and setting up the order of tables for maximum
      performance applies to all areas. For example, the second query below
      should generally be much faster if there are indexes on TA.COL1 and
      TB.COL3:</p><div class="example"><a name="N103AB"></a><p class="title"><b>Example&nbsp;2.2.&nbsp;Query comparison</b></p><pre class="programlisting">
    SELECT ... FROM TA WHERE TA.COL1 = (SELECT MAX(TB.COL2) FROM TB WHERE TB.COL3 = 4)

    SELECT ... FROM (SELECT MAX(TB.COL2) C1 FROM TB WHERE TB.COL3 = 4) T2 JOIN TA ON TA.COL1 = T2.C1</pre></div><p>The second query turns <tt class="literal">MAX(TB.COL2)</tt> into a
      single row table then joins it with TA. With an index on
      <tt class="literal">TA.COL1</tt>, this will be very fast. The first query will
      test each row in TA and evaluate <tt class="literal">MAX(TB.COL2)</tt> again
      and again.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N103BF"></a>Types and Arithmetic Operations</h2></div></div><div></div></div><p>Table columns of all types supported by HSQLDB can be indexed and
    can feature in comparisons. Types can be explicitly converted using the
    CONVERT() library function, but in most cases they are converted
    automatically. It is recommended not to use indexes on LONGVARBINARY,
    LONGVARCHAR and OTHER columns, as these indexes will probably not be
    allowed in future versions.</p><p>Previous versions of HSQLDB featured poor handling of arithmetic
    operations. For example, it was not possible to insert
    <tt class="literal">10/2.5</tt> into any DOUBLE or DECIMAL column. Since 1.7.0,
    full operations are possible with the following rules:</p><p>TINYINT, SMALLINT, INTEGER, BIGINT, NUMERIC and DECIMAL (without a
    decimal point) are supported integral types and map to byte, short, int,
    long and BigDecimal in Java. The SQL type dictates the maximum and minimum
    values that can be held in a field of each type. For example the value
    range for TINYINT is -128 to +127, although the actual Java type used for
    handling TINYINT is <tt class="classname">java.lang.Integer</tt>.</p><p>REAL, FLOAT, DOUBLE are all mapped to double in Java.</p><p>DECIMAL and NUMERIC are mapped to
    <tt class="classname">java.math.BigDecimal</tt> and can have very large
    numbers of digits.</p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N103D6"></a>Integral Types</h3></div></div><div></div></div><p>TINYINT, SMALLINT, INTEGER, BIGINT, NUMERIC and DECIMAL (without a
      decimal point) are fully interchangeable internally, and no data
      narrowing takes place. Depending on the types of the operands, the
      result of the operations is returned in a JDBC
      <tt class="classname">ResultSet</tt> in any of related Java types:
      <tt class="classname">Integer</tt>, <tt class="classname">Long</tt> or
      <tt class="classname">BigDecimal</tt>. The
      <tt class="literal">ResultSet.getXXXX()</tt> methods can be used to retrieve
      the values so long as the returned value can be represented by the
      resulting type. This type is deterministically based on the query, not
      on the actual rows returned. The type does not change when the same
      query that returned one row, returns many rows as a result of adding
      more data to the tables.</p><p>If the SELECT statement refers to a simple column or function,
      then the return type is the type corresponding to the column or the
      return type of the function. For example:</p><div class="informalexample"><pre class="programlisting">
    CREATE TABLE t(a INTEGER, b BIGINT); SELECT MAX(a), MAX(b) FROM t;</pre></div><p>would return a result set where the type of the first column is
      <tt class="filename">java.lang.Integer</tt> and the second column is
      <tt class="filename">java.lang.Long</tt>. However,</p><div class="informalexample"><pre class="programlisting">
    SELECT MAX(a) + 1, MAX(b) + 1 FROM t;</pre></div><p>would return <tt class="filename">java.lang.Long</tt> and
      <tt class="classname">BigDecimal</tt> values, generated as a result of
      uniform type promotion for all the return values.</p><p>There is no built-in limit on the size of intermediate integral
      values in expressions. As a result, you should check for the type of the
      <tt class="classname">ResultSet</tt> column and choose an appropriate
      <tt class="literal">getXXXX()</tt> method to retrieve it. Alternatively, you
      can use the <tt class="literal">getObject()</tt> method, then cast the result
      to <tt class="classname">java.lang.Number </tt> and use the
      <tt class="literal">intValue()</tt> or <tt class="literal">longValue()</tt> methods
      on the result.</p><p>When the result of an expression is stored in a column of a
      database table, it has to fit in the target column, otherwise an error
      is returned. For example when <tt class="literal">1234567890123456789012 /
      12345687901234567890</tt> is evaluated, the result can be stored in
      any integral type column, even a TINYINT column, as it is a small
      value.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10426"></a>Other Numeric Types</h3></div></div><div></div></div><p>In SQL statements, numbers with a decimal point are treated as
      DECIMAL unless they are written with an exponent. Thus
      <tt class="literal">0.2</tt> is considered a DECIMAL value but
      <tt class="literal">0.2E0</tt> is considered a DOUBLE value.</p><p>When <tt class="literal">PreparedStatement.setDouble()</tt> or
      <tt class="literal">setFloat()</tt> is used, the value is treated as a DOUBLE
      automatically.</p><p>When a REAL, FLOAT or DOUBLE (all synonymous) is part of an
      expression, the type of the result is DOUBLE.</p><p>Otherwise, when no DOUBLE value exists, if a DECIMAL or NUMERIC
      value is part an expression, the type of the result is DECIMAL. The
      result can be retrieved from a <tt class="classname">ResultSet</tt> in the
      required type so long as it can be represented. This means DECIMAL
      values can be converted to DOUBLE unless they are beyond the
      <tt class="literal">Double.MIN_VALUE - Double.MAX_VALUE</tt> range. Similar to
      integral values, when the result of an expression is stored in a table
      column, it has to fit in the target column, otherwise an error is
      returned.</p><p>The distinction between DOUBLE and DECIMAL is important when a
      division takes place. When the terms are DECIMAL, the result is a value
      with a scale (number of digits to the right of the decimal point) equal
      to the larger of the scales of the two terms. With a DOUBLE term, the
      scale will reflect the actual result of the operation. For example,
      <tt class="literal">10.0/8.0</tt> (DECIMAL) equals <tt class="literal">1.2</tt> but
      <tt class="literal">10.0E0/8.0E0</tt> (DOUBLE) equals <tt class="literal">1.25</tt>.
      Without division operations, DECIMAL values represent exact arithmetic;
      the resulting scale is the sum of the scales of the two terms when
      multiplication is performed.</p><p>REAL, FLOAT and DOUBLE values are all stored in the database as
      <tt class="classname">java.lang.Double</tt> objects. Special values such as
      NaN and +-Infinity are also stored and supported. These values can be
      submitted to the database via JDBC PreparedStatement methods and are
      returned in ResultSet objects.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1045F"></a>Bit and Boolean Types</h3></div></div><div></div></div><p>Since 1.7.2, BIT is simply an alias for BOOLEAN. The primary
      representation of BOOLEAN column is <tt class="literal">'true'</tt> or
      <tt class="literal">'false'</tt> either as the boolean type or as strings when
      used from JDBC. This type of column can also be initialised using values
      of any numeric type. In this case <tt class="literal">0</tt> is translated to
      <tt class="literal">false</tt> and any other value such as 1 is translated to
      <tt class="literal">true</tt>.</p><p>Since 1.7.3 the BOOLEAN type conforms to the SQL standards and
      supports the UNDEFINED state in addition to TRUE or FALSE. NULL values
      are treated as undefined. This improvement affects queries that contain
      NOT IN. See the test text file, TestSelfNot.txt, for examples of the
      queries.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1047A"></a>Storage and Handling of Java Objects</h3></div></div><div></div></div><p>Since version 1.7.2 this support has improved and any serializable
      JAVA Object can be inserted directly into a column of type OTHER using
      any variation of <tt class="literal">PreparedStatement.setObject()</tt>
      methods.</p><p>For comparison purposes and in indexes, any two Java Objects are
      considered equal unless one of them is NULL. You cannot search for a
      specific object or perform a join on a column of type OTHER.</p><p>Please note that HSQLDB is not an object-relational database. Java
      Objects can simply be stored internally and no operations should be
      performed on them other than assignment between columns of type OTHER or
      tests for NULL. Tests such as <tt class="literal">WHERE object1 =
      object2</tt>, or <tt class="literal">WHERE object1 = ? </tt>do not mean
      what you might expect, as any non-null object would satisfy such a
      tests. But <tt class="literal">WHERE object1 IS NOT NULL</tt> is perfectly
      acceptable.</p><p>The engine does not return errors when normal column values are
      assigned to Java Object columns (for example assigning an INTEGER or
      STRING to such a column with an SQL statement such as <tt class="literal">UPDATE
      mytable SET objectcol = intcol WHERE ...</tt>) but this is highly
      likely to be disallowed in future. So please use columns of type OTHER
      only to store your objects and nothing else.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10499"></a>Type Size, Precision and Scale</h3></div></div><div></div></div><p>Prior to 1.7.2, all table column type definitions with a column
      size, precision or scale qualifier were accepted and ignored.</p><p>In 1.8.0, such qualifiers must conform to the SQL standards. For
      example INTEGER(8) is no longer acceptable. The qualifiers are still
      ignored unless you set a database property. <tt class="literal">SET PROPERTY
      "sql.enforce_strict_size" TRUE </tt>will enforce sizes for
      CHARACTER or VARCHAR columns and pad any strings when inserting or
      updating a CHARACTER column. The precision and scale qualifiers are also
      enforced for DECIMAL and NUMERIC types. TIMESTAMP can be used with a
      precision of 0 or 6 only.</p><p>Casting a value to a qualified CHARACTER type will result in
      truncation or padding as you would expect. So a test such as
      <tt class="literal">CAST (mycol AS VARCHAR(2)) = 'xy'</tt> will find the
      values beginning with 'xy'. This is the equivalent of
      <tt class="literal">SUBSTRING(mycol FROM 1 FOR 2)</tt> = 'xy'.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N104AE"></a>Sequences and Identity</h2></div></div><div></div></div><p>The SEQUENCE keyword was introduced in 1.7.2 with a subset of the
    SQL 200n standard syntax. Corresponding SQL 200n syntax for IDENTITY
    columns has also been introduced.</p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N104B3"></a>Identity Auto-Increment Columns</h3></div></div><div></div></div><p>Each table can contain one auto-increment column, known as the
      IDENTITY column. An IDENTITY column is always treated as the primary key
      for the table (as a result, multi-column primary keys are not possible
      with an IDENTITY column present). Support has been added for
      <tt class="literal">CREATE TABLE &lt;tablename&gt;(&lt;colname&gt; IDENTITY,
      ...)</tt> as a shortcut.</p><p>Since 1.7.2, the SQL standard syntax is used by default, which
      allows the initial value to be specified. The supported form
      is<tt class="literal">(&lt;colname&gt; INTEGER GENERATED BY DEFAULT AS
      IDENTITY(START WITH n, [INCREMENT BY m])PRIMARY KEY, ...)</tt>.
      Support has also been added for <tt class="literal">BIGINT</tt> identity
      columns. As a result, an IDENTITY column is simply an INTEGER or BIGINT
      column with its default value generated by a sequence generator.</p><p>When you add a new row to such a table using an <tt class="literal">INSERT
      INTO &lt;tablename&gt; ...; </tt>statement, you can use the NULL
      value for the IDENTITY column, which results in an auto-generated value
      for the column. The <tt class="literal">IDENTITY() </tt>function returns the
      last value inserted into any IDENTITY column by this connection. Use
      <tt class="literal">CALL IDENTITY(); </tt>as an SQL statement to retrieve this
      value. If you want to use the value for a field in a child table, you
      can use <tt class="literal">INSERT INTO &lt;childtable&gt; VALUES
      (...,IDENTITY(),...);</tt>. Both types of call to<tt class="literal">
      IDENTITY()</tt> must be made before any additional update or insert
      statements are issued on the database.</p><p>The next IDENTITY value to be used can be set with the
      <pre class="programlisting">ALTER TABLE ALTER COLUMN &lt;column name&gt; RESTART WITH &lt;new value&gt;;</pre></p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N104E1"></a>Sequences</h3></div></div><div></div></div><p>The SQL 200n syntax and usage is different from what is supported
      by many existing database engines. Sequences are created with the
      <tt class="literal">CREATE SEQUENCE</tt> command and their current value can
      be modified at any time with <tt class="literal">ALTER SEQUENCE</tt>. The next
      value for a sequence is retrieved with the <tt class="literal">NEXT VALUE FOR
      &lt;name&gt;</tt> expression. This expression can be used for
      inserting and updating table rows. You can also use it in select
      statements. For example, if you want to number the returned rows of a
      SELECT in sequential order, you can use:</p><div class="example"><a name="N104F2"></a><p class="title"><b>Example&nbsp;2.3.&nbsp;Numbering returned rows of a SELECT in sequential order</b></p><pre class="programlisting">
    SELECT NEXT VALUE FOR mysequence, col1, col2 FROM mytable WHERE ...</pre></div><p>Please note that the semantics of sequences is not exactly the
      same as defined by SQL 200n. For example if you use the same sequence
      twice in the same row insert query, you will get two different values,
      not the same value as required by the standard.</p><p>You can query the SYSTEM_SEQUENCES table for the next value that
      will be returned from any of the defined sequences. The SEQUENCE_NAME
      column contains the name and the NEXT_VALUE column contains the next
      value to be returned.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N104FC"></a>Issues with Transactions</h2></div></div><div></div></div><p>HSQLDB supports transactions at the READ_UNCOMMITTED level, also
    known as level 0 transaction isolation. This means that during the
    lifetime of a transaction, other connections to the database can see the
    changes made to the data. Transaction support works well in general.
    Reported bugs concerning transactions being committed if the database is
    abruptly closed have been fixed. However, the following issues may be
    encountered only with multiple connections to a database using
    transactions:</p><p>If two transactions modify the same row, no exception is raised when
    both transactions are committed. This can be avoided by designing your
    database in such a way that application data consistency does not depend
    on exclusive modification of data by one transaction. You can set a
    database property to cause an exception when this happens.<pre class="programlisting">SET PROPERTY "sql.tx_no_multi_rewrite" TRUE</pre>When
    an <tt class="literal">ALTER TABLE .. INSERT COLUMN</tt> or <tt class="literal">DROP
    COLUMN</tt> command results in changes to the table structure, the
    current session is committed. If an uncommitted transaction started by
    another connections has changed the data in the affected table, it may not
    be possible to roll it back after the <tt class="literal">ALTER TABLE</tt>
    command. This may also apply to <tt class="literal">ADD INDEX</tt> or
    <tt class="literal">ADD CONSTRAINT</tt> commands. It is recommended to use these
    <tt class="literal">ALTER</tt> commands only when it is known that other
    connections are not using transactions.</p><p>After a CHECKPOINT command is issued, uncommitted transactions can
    be continued, committed, or rolled back. However, if the database is not
    subsequently closed properly with the SHUTDOWN command, any such
    transaction that still remains uncommitted at the time of shutdown, is
    part committed (to the state at CHECKPOINT) at the next startup. It is
    recommended to use the CHECKPOINT command either when no uncommitted
    transactions is in progress, or it is known that any such transaction is
    not likely to last for such a long time that an abnormal shutdown might
    affect its data.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10521"></a>New Features and Changes</h2></div></div><div></div></div><p>In recent versions leading to 1.8.0 many enhancements were made for
    better SQL support. These are listed in the <a href="#sqlsyntax-chapter" title="Chapter&nbsp;9.&nbsp;SQL Syntax">SQL Syntax</a> chapter, in
    <a href="../changelog_1_8_0.txt" target="_top">../changelog_1_8_0.txt</a> and <a href="../changelog_1_7_2.txt" target="_top">../changelog_1_7_2.txt</a>.
 Functions and expressions such as
    POSITION(), SUBSTRING(), NULLIF(), COALESCE(), CASE ... WHEN .. ELSE, ANY,
    ALL etc. are among them. Other enhancements may not be very obvious in the
    documentation but can result in changes of behaviour from previous
    versions. Most significant among these are handling of NULL values in
    joins (null columns are no longer joined) and OUTER joins (the results are
    now correct). You should test your applications with the new version to
    ensure they do not rely on past incorrect behaviour of the engine. The
    engine will continue to evolve in future versions towards full SQL
    standard support, so it is best not to rely on any non-standard feature of
    the current version.</p></div></div><div class="chapter" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="unix-chapter"></a>Chapter&nbsp;3.&nbsp;UNIX Quick Start</h2></div><div><h3 class="subtitle"><i>
        How to quickly get Hsqldb up and running on UNIX, including Mac OS X
    </i></h3></div><div><div class="author"><h3 class="author"><span class="firstname">Blaine</span> <span class="surname">Simpson</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:blaine.simpson@admc.com">blaine.simpson@admc.com</a>&gt;</tt></div></div><div><p class="pubdate">$Date: 2005/07/25 23:20:53 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N10553">Purpose</a></span></dt><dt><span class="section"><a href="#N1055A">Installation</a></span></dt><dt><span class="section"><a href="#instance_setup-section">Setting up Database Instance and Server</a></span></dt><dt><span class="section"><a href="#N106CC">Accessing your Database</a></span></dt><dt><span class="section"><a href="#N10737">Create additional Accounts</a></span></dt><dt><span class="section"><a href="#N10751">Shutdown</a></span></dt><dt><span class="section"><a href="#N1075E">Running Hsqldb as a System Daemon</a></span></dt><dd><dl><dt><span class="section"><a href="#N10775">
                Portability of hsqldb init script
            </a></span></dt><dt><span class="section"><a href="#N10780">Init script Setup Procedure</a></span></dt><dt><span class="section"><a href="#initscriptTrouble-section">
                Troubleshooting the Init Script
            </a></span></dt></dl></dd></dl></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10553"></a>Purpose</h2></div></div><div></div></div><p>
            This chapter explains how to quickly install, run, and
            use HSQLDB on UNIX.
        </p><p>
            HSQLDB has lots of great optional features.
            I intend to cover very few of them.
            I do intend to cover what I think is the most common UNIX setup:
            To run a multi-user database with permament data persistence.
            (By the latter I mean that data is stored to disk so that the
            data will persist across database shutdowns and startups).
            I also cover how to run HSQLDB as a system daemon.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N1055A"></a>Installation</h2></div></div><div></div></div><p>
            Go to <a href="http://sourceforge.net/projects/hsqldb" target="_top">http://sourceforge.net/projects/hsqldb</a>
            and click on the "files" link.
            You want the current version.  This will be the highest
            numbered version under the plain black "hsqldb" heading.
            See if there's a distribution for the current HSQLDB version in
            the format that you want.
        </p><p>
            If you want an rpm, you should still find out the current
            version of HSQLDB as described in the previous paragraph.
            Then click "hsqldb" in the "free section" of
            <a href="http://www.jpackage.org/" target="_top">http://www.jpackage.org/</a> and see if they have
            the current HSQLDB version built yet.
            Hopefully, the JPackage folk will document what JVM versions their
            rpm will support (currently they document this neither on their
            site nor within the package itself).
            (I really can't document how to download from a site that is
            totally beyond my control).
        </p><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>
            It could very well happen that some of the file formats which I
            discuss below are not in fact offered.
            If so, then we have not gotten around to building them.
        </p></div><p>
            Binary installation depends on the package format that you 
            downloaded.
        </p><div class="variablelist"><dl><dt><span class="term">Installing from a .pkg.Z file</span></dt><dd><p>
            This package is only for use by a Solaris super-user.
            It's a System V package.
            Download then uncompress the package with uncompress or gunzip
            <div class="informalexample"><pre class="screen">
    uncompress filename.pkg.Z</pre></div>
                You can read about the package by running
            <div class="informalexample"><pre class="screen">
    pkginfo -l -d filename.pkg</pre></div>
                Run pkgadd as root to install.
            </p><div class="informalexample"><pre class="screen">
    pkgadd -d filename.pkg</pre></div></dd><dt><span class="term">Installing from a .rpm file</span></dt><dd><p>
            This is a Linux rpm package.
            After you download the rpm, you can read about it by running
            <div class="informalexample"><pre class="screen">
    rpm -qip /path/to/file.rpm</pre></div></p><p>
            Rpms can be installed or upgraded by running
                <div class="informalexample"><pre class="screen">
    rpm -Uvh /path/to/file.rpm</pre></div>
                as root.
                Suse users may want to keep Yast aware of installed packages by
                running rpm through Yast:
                <tt class="literal">yast2 -i /path/to/file.rpm</tt>.
            </p></dd><dt><span class="term">Installing from a .zip file</span></dt><dd><p>
            Extract the zip file to the parent directory of the new HSQLDB
            home.
            You don't need to create the
            <span class="bold"><b>HSQLDB_HOME</b></span> directory because
            the extraction will create it for you with the right name)
            </p><div class="informalexample"><pre class="screen">
    cd parent/of/new/hsqldb/home
    unzip /path/to/file.zip</pre></div><p>
            All the files in the zip archive will be extracted to underneath
            a new <tt class="filename">hsqldb</tt> directory.
            </p></dd></dl></div><p>
            Take a look at the files you installed.
            (Under <tt class="filename">hsqldb</tt> for zip file installations.
            Otherwise, use the utilities for your packaging system).
            The most important file of the hsqldb system is
            <tt class="filename">hsqldb.jar</tt>, which resides in the directory
            <tt class="filename">lib</tt>.
        </p><div class="important" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Important</h3><p>
            For the purposes of this chapter, I define
            <span class="bold"><b>HSQLDB_HOME</b></span> to be the parent
            directory of the lib directory that contains
            <tt class="filename">hsqldb.jar</tt>.
            E.g., if your path to <tt class="filename">hsqldb.jar</tt> is
            <tt class="filename">/a/b/hsqldb/lib/hsqldb.jar</tt>, then your
            <span class="bold"><b>HSQLDB_HOME</b></span> is
            <tt class="filename">/a/b/hsqldb</tt>.
        </p></div><p>
            If the description of your distribution says that the hsqldb.jar
            file will work for your Java version, then you are finished with
            installation.
            Otherwise you need to build a new hsqldb.jar file.
        </p><p>
            If you followed the instructions above and you still don't know
            what Java version your <tt class="filename">hsqldb.jar</tt> supports,
            then read
            <span class="bold"><b>HSQLDB_HOME</b></span><tt class="filename">/readme.txt</tt>
            and <span class="bold"><b>HSQLDB_HOME</b></span><tt class="filename">/index.html</tt>.
            If that still doesn't help, then you can just try your hsqldb.jar
            and see if it works, or build your own.
            </p><p>
                To use the supplied <tt class="filename">hsqldb.jar</tt>, just skip to
                the <a href="#instance_setup-section" title="

            Setting up a Hsqldb Persistent Database Instance and a Hsqldb

            Server

        "> next section of this 
            document</a>.
            Otherwise build a new <tt class="filename">hsqldb.jar</tt>.
        </p><div class="procedure"><p class="title"><b>Procedure&nbsp;3.1.&nbsp;Building hsqldb.jar</b></p><ol type="1"><li><p>
                If you don't already have Ant, download the latest stable 
                binary version from <a href="http://ant.apache.org" target="_top">http://ant.apache.org</a>.
                cd to where you want Ant to live, and extract from the archive 
                with
                <div class="informalexample"><pre class="screen">
    unzip /path/to/file.zip</pre></div>or<div class="informalexample"><pre class="screen">
    tar -xzf /path/to/file.tar.gz</pre></div>or<div class="informalexample"><pre class="screen">
    bunzip2 -c /path/to/file.tar.bz2 | tar -xzf -</pre></div>
                Everything will be installed into a new subdirectory named
                <tt class="filename">apache-ant- + version</tt>.
                You can rename the directory after the extraction if you wish.
            </p></li><li><p>
                Set the environmental variable <tt class="literal">JAVA_HOME</tt> to 
                the base directory of your Java JRE or SDK, like
                <div class="informalexample"><pre class="screen">
    export JAVA_HOME; JAVA_HOME=/usr/java/j2sdk1.4.0</pre></div>
                The location is entirely dependent upon your variety of UNIX.
                Sun's rpm distributions of Java normally install to
                <tt class="filename">/usr/java/something</tt>.
                Sun's System V package distributions of Java (including those 
                that come with Solaris) normally install to
                <tt class="filename">/usr/something</tt>, with a sym-link from 
                <tt class="filename">/usr/java</tt> to the default version (so for 
                Solaris you will usually set JAVA_HOME to 
                <tt class="filename">/usr/java</tt>).
            </p></li><li><p>
                Remove the existing file
<span class="bold"><b>HSQLDB_HOME</b></span><tt class="filename">/lib/hsqldb.jar</tt>.
            </p></li><li><p>
                cd to
                <span class="bold"><b>HSQLDB_HOME</b></span><tt class="filename">/build</tt>.
                Make sure that the bin directory under your Ant home is in your 
                search path.
                Run the following command.
                <div class="informalexample"><pre class="screen">
    ant hsqldb</pre></div>
                This will build a new
<span class="bold"><b>HSQLDB_HOME</b></span><tt class="filename">/lib/hsqldb.jar</tt>.
                </p></li></ol></div><p>
            See the <a href="#building-appendix" title="Appendix&nbsp;A.&nbsp;Building HSQLDB">Building HSQLDB</a>
            appendix if you want to build anything other than
            <tt class="filename">hsqldb.jar</tt> with all default settings.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="instance_setup-section"></a>
            Setting up a Hsqldb Persistent Database Instance and a Hsqldb
            Server
        </h2></div></div><div></div></div><p>
            If you installed from an OS-specific package, you may already
            have a database instance and server pre-configured.
            See if your package includes a file named 
            <tt class="filename">server.properties</tt>
            (make use of your packaging utilities).
            If you do, then I suggest that you still read this section while
            you poke around, in order to understand your setup.
        </p><div class="procedure"><ol type="1"><li><p>
                Select a UNIX user to run the database as.
                If this database is for the use of multiple users, or is a
                production system (or to emulate a production system), you
                should dedicate a UNIX user for this purpose.
                In my examples, I use the user name <tt class="literal">hsqldb</tt>.
                In this chapter, I refer to this user as the 
                <span class="bold"><b>HSQLDB_OWNER</b></span>, since that user 
                will own the database instance files and processes.
                </p><p>
                If the account doesn't exist, then create it.
                On all system-5 UNIXes and most hybrids (including Linux), 
                you can run (as root) something like
                <div class="informalexample"><pre class="screen">
    useradd -c 'HSQLDB Database Owner' -s /bin/bash -m hsqldb</pre></div>
                    (BSD-variant users can use a similar
                    <tt class="literal">pw useradd hsqldb...</tt> command).
                </p></li><li><p>
                Become the <span class="bold"><b>HSQLDB_OWNER</b></span>.
                Copy the sample file 
                <span class="bold"><b>HSQLDB_HOME</b></span><tt class="filename">/src/org/hsqldb/sample/sample-server.properties</tt>
                to the <span class="bold"><b>HSQLDB_OWNER</b></span>'s home
                directory and rename it to 
                <tt class="filename">server.properties</tt>.
            </p><pre class="programlisting"># Hsqldb Server cfg file.
# See the Advanced Topics chapter of the Hsqldb User Guide.

server.database.0   file:db0/db0
</pre><p>
                Since the value of the first database
                (<span class="property">server.database.0</span>) begins with
                <tt class="literal">file:</tt>, the database instance will be
                persisted to a set of files in the specified directory with
                names beginning with the specified name.
                Set the path to whatever you want (relative paths will be
                relative to the directory containing the properties file).
                You can read about how to specify other database instances
                of various types, and how to make settings for the listen
                port and many other things, in the 
                <a href="#advanced-chapter" title="Chapter&nbsp;4.&nbsp;Advanced Topics">Advanced Topics</a>
                chapter.
            </p></li><li><p>
                Set and export the environmental variable
                <tt class="literal">CLASSPATH</tt> to the value of
                <span class="bold"><b>HSQLDB_HOME</b></span> (as described 
                above) plus "/lib/hsqldb.jar", like
                <div class="informalexample"><pre class="screen">
    export CLASSPATH; CLASSPATH=/path/to/hsqldb/lib/hsqldb.jar</pre></div>
                In <span class="bold"><b>HSQLDB_OWNER</b></span>'s home
                directory, run</p><div class="informalexample"><pre class="screen">
    nohup java org.hsqldb.Server &amp;</pre></div><p>
                    This will start the Server process in the background, and 
                    will create your new database instance "db0".
                    Continue on when you see the message containing
                    <tt class="literal">HSQLDB server... is online</tt>.
                    <tt class="literal">nohup</tt> just makes sure that the command
                    will not quit when you exit the current shell (omit it
                    if that's what you want to do).
                </p></li></ol></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N106CC"></a>Accessing your Database</h2></div></div><div></div></div><p>
            Copy the file
            <span class="bold"><b>HSQLDB_HOME</b></span><tt class="filename">/src/org/hsqldb/sample/sqltool.rc</tt>
            to the
            <span class="bold"><b>HSQLDB_OWNER</b></span>'s home directory.
            Use <tt class="literal">chmod</tt> to make the file readable and
            writable only to <span class="bold"><b>HSQLDB_OWNER</b></span>.
        </p><pre class="programlisting"># $Id: sqltool.rc,v 1.17 2005/11/06 18:01:49 unsaved Exp $

# This is a sample RC configuration file used by SqlTool, DatabaseManager,
# and any other program that uses the org.hsqldb.util.RCData class.

# You can run SqlTool right now by copying this file to your home directory
# and running
#    java -jar /path/to/hsqldb.jar mem
# This will access the first urlid definition below in order to use a 
# personal Memory-Only database.

# If you have the least concerns about security, then secure access to
# your RC file.
# See the documentation for SqlTool for various ways to use this file.

# A personal Memory-Only database.
urlid mem
url jdbc:hsqldb:mem:memdbid
username sa
password

# This is for a hsqldb Server running with default settings on your local
# computer (and for which you have not changed the password for "sa").
urlid localhost-sa
url jdbc:hsqldb:hsql://localhost
username sa
password



# Template for a urlid for an Oracle database.
# You will need to put the oracle.jdbc.OracleDriver class into your 
# classpath.
# In the great majority of cases, you want to use the file classes12.zip
# (which you can get from the directory $ORACLE_HOME/jdbc/lib of any
# Oracle installation compatible with your server).
# Since you need to add to the classpath, you can't invoke SqlTool with
# the jar switch, like "java -jar .../hsqldb.jar..." or 
# "java -jar .../hsqlsqltool.jar...".
# Put both the HSQLDB jar and classes12.zip in your classpath (and export!)
# and run something like "java org.hsqldb.util.SqlTool...".

#urlid cardiff2
#url jdbc:oracle:thin:@aegir.admc.com:1522:TRAFFIC_SID
#username blaine
#password secretpassword
#driver oracle.jdbc.OracleDriver



# Template for a TLS-encrypted HSQLDB Server.
# Remember that the hostname in hsqls (and https) JDBC URLs must match the
# CN of the server certificate (the port and instance alias that follows 
# are not part of the certificate at all).
# You only need to set "truststore" if the server cert is not approved by
# your system default truststore (which a commercial certificate probably
# would be).

#urlid tls
#url jdbc:hsqldb:hsqls://db.admc.com:9001/lm2
#username blaine
#password asecret
#truststore /home/blaine/ca/db/db-trust.store


# Template for a Postgresql database
#urlid blainedb
#url jdbc:postgresql://idun.africawork.org/blainedb
#username blaine
#password losung1
#driver org.postgresql.Driver

# Template for a MySQL database.  MySQL has poor JDBC support.
#urlid mysql-testdb
#url jdbc:mysql://hostname:3306/dbname
#username root
#username blaine
#password hiddenpwd
#driver com.mysql.jdbc.Driver

# Note that "databases" in SQL Server and Sybase are traditionally used for
# the same purpose as "schemas" with more SQL-compliant databases.

# Template for a Microsoft SQL Server database
url jdbc:microsoft:sqlserver://hostname;DatabaseName=DbName;SelectMethod=Cursor
# The SelectMethod setting is required to do more than one thing on a JDBC
# session (I guess Microsoft thought nobody would really use Java for 
# anything other than a "hello world" program).
# This is for Microsoft's SQL Server 2000 driver (requires mssqlserver.jar
# and msutil.jar).
driver com.microsoft.jdbc.sqlserver.SQLServerDriver
username myuser
password hiddenpwd

# Template for a Sybase database
urlid sybase
url jdbc:sybase:Tds:hostname:4100/dbname
username blaine
password hiddenpwd
# This is for the jConnect driver (requires jconn3.jar).
driver com.sybase.jdbc3.jdbc.SybDriver
</pre><p>
            We will be using the "localhost-sa" sample urlid definition from 
            the config file.
            The JDBC URL for this urlid is
            <tt class="literal">jdbc:hsqldb:hsql://localhost</tt>.
            That is the URL for the default database instance of a HSQLDB
            Server running on the default port of the local host.
            You can read about URLs to connect to other instances and 
            other servers in the 
            <a href="#advanced-chapter" title="Chapter&nbsp;4.&nbsp;Advanced Topics">Advanced Topics</a>
            chapter.
        </p><p>
            Run <tt class="classname">SqlTool</tt>.
        <div class="informalexample"><pre class="screen">
    java -jar path/to/hsqldb.jar localhost-sa</pre></div>
            If you get a prompt, then all is well.
            If security is of any concern to you at all, then you should change 
            the privileged password in the database.
            Use the command
            <a href="#set_password-section" title="SET PASSWORD">SET PASSWORD</a>
            command to change SA's password.
            <div class="informalexample"><pre class="programlisting">
    set password "newpassword";</pre></div></p><p>
            When you're finished playing, exit with the command
            <tt class="literal">\q</tt>.
        </p><p>
            If you changed the SA password, then you need to
            fix the password in the <tt class="filename">sqltool.rc</tt> file
            accordingly.
        </p><p>
            You can, of course, also access the database with any JDBC client
            program.
            See the
            <a href="#firstclient-appendix" title="Appendix&nbsp;B.&nbsp;First JDBC Client Example">First JDBC Client Example</a>
            appendix.
            You will need to modify your classpath to include 
            <tt class="filename">hsqldb.jar</tt> as well as your client class(es).
            You can also use the other HSQLDB client programs, such as
            <tt class="classname">org.hsqldb.util.DatabasManagerSwing</tt>,
            a graphical client with a similar purpose to
            <tt class="classname">SqlTool</tt>.
        </p><p>
            You can use any normal UNIX account to run the JDBC clients,
            including <tt class="classname">SqlTool</tt>, as long as the account 
            has read access to the <tt class="filename">hsqldb.jar</tt> file and to 
            an <tt class="filename">sqltool.rc</tt> file.
            See the <a href="#sqltool-chapter" title="Chapter&nbsp;8.&nbsp;SqlTool">SqlTool</a>
            chapter about where to put <tt class="filename">sqltool.rc</tt>, how to
            execute sql files, and other <tt class="classname">SqlTool</tt> 
            features.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10737"></a>Create additional Accounts</h2></div></div><div></div></div><p>
            Connect to the database as SA (or any other Administrative user)
            and run <a href="#create_user-section" title="CREATE USER">CREATE USER</a>
            to create new accounts for your database instance.
            HSQLDB accounts are database-instance-specific, not 
            <tt class="classname">Server</tt>-specific.
        </p><p>
            For the current version of HSQLDB, only users with Role of
            <tt class="literal">DBA</tt> may create or own database objects.
            DBA members have privileges to do anything.  Non-DBAs may be 
            granted some privileges, but may never create or own database 
            objects.
            (Before long, non-DBAs will be able to create objects if they
            have permission to do so in the target schema).
            When you first create a hsqldb database, it has only one database 
            user-- SA, a DBA account, with an empty string password.
            You should set a password (as described above).
            You can create as many additional users as you wish.
            To make a user a DBA, you can use the "ADMIN" option to the 
            <a href="#create_user-section" title="CREATE USER">CREATE USER</a> command,
            or GRANT the DBA Role to the account after creating it.
        </p><p>
            If you create a user without the ADMIN tag (and without granting
            the DBA role to them) this user will be able to read the data
            dictionary tables, but will be able unable to create or own his
            own objects.
            He will have only the rights which the pseudo-user PUBLIC has.
            To give him more permissions, even rights to read objects,
            you can GRANT permissions for specific objects, grant Roles
            (which encompass a set of permissions), or grant the DBA Role
            itself.
        </p><p>
            Since only people with a database account may do anything at all 
            with the database, it is often useful to permit other database 
            users to view the data in your tables.
            To optimize performance, reduce contention, and minimize 
            administration, it is often best to grant SELECT to PUBLIC on any 
            object that needs to be accessed by multiple database users (with 
            the significant exception of any data which you want to keep 
            secret).
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10751"></a>Shutdown</h2></div></div><div></div></div><p>
            Do a clean database shutdown when you are finished with the
            database instance.
            You need to connect up as SA or some other Admin user, of course.
            With SqlTool, you can run
        <div class="informalexample"><pre class="screen">
    java -jar path/to/hsqldb.jar --sql shutdown localhost-sa</pre></div>
        You don't have to worry about stopping the
        <tt class="classname">Server</tt> because it shuts down automatically when 
        all served database instances are shut down.
    </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N1075E"></a>Running Hsqldb as a System Daemon</h2></div></div><div></div></div><p>
            You can, of course, run HSQLDB through inittab on System V
            UNIXes, but usually an init script is more convenient and
            manageable.
            This section explains how to set up and use our UNIX init script.
            Our init script is only for use by root.
            (That is not to say that the <span class="emphasis"><em>Server</em></span> will run
            as root-- it usually should not).
        </p><p>
            The main purpose of the init script is to start up a Server with
            the database instances specified in your
            <tt class="filename">server.properties</tt> file; and to shut down all
            of those instances <span class="emphasis"><em>plus</em></span> additional urlids
            which you may (optionally) list in your init script config file.
            These urlids must all have entries in a sqltool.rc file.
            If, due to firewall issues, you want to run a WebServer instead
            of a Server, then make sure you have a healthy WebServer with
            a webserver.properties set up, adjust your URLs in
            <tt class="filename">sqltool.rc</tt>, and set TARGET_CLASS in the 
            config file.
            (By following the commented examples in the config file, you
            can start up any number of Server and/or WebServer listeners
            with or without TLS ecryption).
        </p><p>
            After you have the init script set up, root can use it anytime
            to start or stop HSQLDB.
            (I.e., not just at system bootup or shutdown).
        </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10775"></a>
                Portability of <tt class="filename">hsqldb</tt> init script
            </h3></div></div><div></div></div><p>
                The primary design criterion of the init script is portability.
                It does not print pretty color startup/shutdown messages as is
                common in late-model Linuxes and HPUX; and it does not keep 
                subsystem state files or use the startup/shutdown functions
                supplied by many UNIXes, because these features are all 
                non-portable.
            </p><p>
                Offsetting these limitations, this one script does it's 
                intended job great on the UNIX varieties I have tested, and can 
                easily be modified to accommodate other UNIXes.
                While you don't have tight integration with OS-specific
                daemon administration guis, etc., you do have a well tested
                and well behaved script that gives good, utilitarian feedback.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10780"></a>Init script Setup Procedure</h3></div></div><div></div></div><p>
                The strategy taken here is to get the init script to run your
                single Server or WebServer first (as specified by TARGET_CLASS).
                After that's working, you can customize the JVM that is run
                by running additional Servers in it, running your own
                application in it (embedding), or even overriding HSQLDB
                behavior with your own overriding classes.
            </p><div class="procedure"><ol type="1"><li><p>
                Copy the init script <tt class="filename">hsqldb</tt> from
                <span class="bold"><b>HSQLDB_HOME</b></span><tt class="filename">/bin</tt>
                into the directory where init scripts live on your variety of 
                UNIX.
                The most common locations are <tt class="filename">/etc/init.d</tt>
                or <tt class="filename">/etc/rc.d/init.d</tt> on System V style
                UNIXes, <tt class="filename">/usr/local/etc/rc.d</tt> on BSD style
                UNIXes, and <tt class="filename">/Library/StartupItems/hsqldb</tt>
                on OS X (you'll need to create the directory for the last).
            </p></li><li><p>
                Look at the comment towards the top of the init script which
                lists recommended locations for the configuration file for
                various UNIX platforms.
                Copy the sample config file
                <span class="bold"><b>HSQLDB_HOME</b></span><tt class="filename">/src/org/hsqldb/sample/sample-hsqldb.cfg</tt>
                to one of the listed locations (your choice).
                Edit the config file according to the instructions in it.
                </p><pre class="programlisting"># $Id: sample-hsqldb.cfg,v 1.16 2005/07/24 18:33:13 unsaved Exp $

# Sample configuration file for HSQLDB database server.
# See the "UNIX Quick Start" chapter of the Hsqldb User Guide.

# N.b.!!!!  You must place this in the right location for your type of UNIX.
# See the init script "hsqldb" to see where this must be placed and
# what it should be renamed to.

# This file is "sourced" by a Bourne shell, so use Bourne shell syntax.

# This file WILL NOT WORK until you set (at least) the non-commented
# variables to the appropriate values for your system.
# Life will be easier if you avoid all filepaths with spaces or any other
# funny characters.  Don't ask for support if you ignore this advice.

# Thanks to Meikel Bisping for his contributions.  -- Blaine

JAVA_EXECUTABLE=/usr/bin/java

# Unless you copied a hsqldb.jar file from another system, this typically
# resides at $HSQLDB_HOME/lib/hsqldb.jar, where $HSQLDB_HOME is your HSQLDB
# software base directory.
HSQLDB_JAR_PATH=/opt/hsqldb/lib/hsqldb.jar

# Where the file "server.properties" resides.
SERVER_HOME=/opt/hsqldb/data

# What UNIX user the server will run as.
# (The shutdown client is always run as root or the invoker of the init script).
# Runs as root by default, but you should take the time to set database file
# ownerships to another user and set that user name here.
HSQLDB_OWNER=hsqldb

# The HSQLDB jar file specified in HSQLDB_JAR_PATH above will automatically
# be in the class path.  This arg specifies additional classpath elements.
# To embed your own application, add your jar file(s) or class base
# directories here, and add your main class to the INVOC_ADDL_ARGS setting
# below.
#SERVER_ADDL_CLASSPATH=/usr/local/dist/currencybank.jar

# We require all Server/WebServer instances to be accessible within 
# $MAX_START_SECS from when the Server/WebServer is started.
# Defaults to 60.
# Raise this is you are running lots of DB instances or have a slow server.
#MAX_START_SECS=200

# Time to allow for JVM to die after all HSQLDB instances stopped.
# Defaults to 1.
#MAX_TERMINATE_SECS=0

# These are "urlid" values from a SqlTool authentication file
# ** IN ADDITION TO THOSE IN YOUR server.properties OR webserver.properties **
# file.  All server.urlid.X values from your properties file will automatically
# be started/stopped/tested.  $SHUTDOWN_URLIDS is for additional urlids which
# will stopped.  (Therefore, most users will not set this at all).
# Separate multiple values with white space.  NO OTHER SPECIAL CHARACTERS!
# Make sure to quote the entire value if it contains white space separator(s).
# Defaults to none (i.e., only urlids set in properties file will be stopped).
#SHUTDOWN_URLIDS='sa mygms'

# SqlTool authentication file used only for shutdown.
# The default value will be sqltool.rc in root's home directory, since it is 
# root who runs the init script.
# (See the SqlTool chapter of the HSQLDB User Guide if you don't understand 
# this).
#AUTH_FILE=/home/blaine/sqltool.rc

# Set this to either 'WebServer' or 'Server'.  Defaults to Server.
# The JVM that is started can invoke many classes (see the following item
# about that), but this is the Server that is used (1) to check status,
# (2) to shut down the JVM, (3) to get urlids for #1 from the 
# server's server/webserver.properties file.
#TARGET_CLASS=WebServer
# Note that you don't specify the org.hsqldb package, since you have no 
# choice in the matter (you can only run org.hsqldb.Server or 
# org.hsqldb.WebServer).  If you specify additional classes with
# INVOC_ADDL_ARGS (described next), you do need to specify the
# full class name with package name.

# This is where you specify exactly what your HSQLDB JVM will run.
# The class org.hsqldb.util.MainInvoker will run the TARGET_CLASS
# specified above with any arguments supplied here + any other classes
# and arguments.  Every additional class (in addition to the TARGET_CLASS)
# must be preceded with an empty string, so that MainInvoker will know
# you are giving a class name.  MainInvoker will invoke the normal 
# static main(String[]) method of each such class.  
# By default, MainInvoker will just run TARGET_CLASS with no args.
# Example that runs just the TARGET_CLASS with the specified arguments:
#INVOC_ADDL_ARGS='-silent false'
# Example that runs the TARGET_CLASS plus a WebServer:
#INVOC_ADDL_ARGS='"" org.hsqldb.WebServer'
# Note the empty string preceding the class name.
# Example that starts TARGET_CLASS with an argument + a WebServer +
# your own application with its args (i.e., the HSQLDB Servers are
# "embedded" in your application).  (Set SERVER_ADDL_CLASSPATH too).:
#INVOC_ADDL_ARGS='-silent false "" org.hsqldb.WebServer "" com.acme.Stone --env prod localhost'
# Example to run a non-TLS server in same JVM with a TLS server.  In this
# case, TARGET_CLASS is Server which will run in TLS mode by virtue of 
# setting TLS_KEYSTORE and TLS_PASSWORD above.  The "additional" Server
# here overrides the 'tls' and 'port' settings:
#INVOC_ADDL_ARGS="'' org.hsqldb.Server -port 9002 -tls false"
# Note that you use nested quotes to group arguments and to specify the
# empty-string delimiter.

# For TLS encryption for your Server, set these two variables.
# N.b.:  If you set these, then make this file unreadable to non-root users!!!!
# See the TLS chapter of the HSQLDB User Guide, paying attention to the 
# security warning(s).
# If you are running with a private server cert, then you will also need to 
# set "truststore" in the your SqlTool config file (location is set by the
# AUTH_FILE variable in this file, or it must be at the default location for 
# HSQLDB_OWNER).
#TLS_KEYSTORE=/path/to/jks/server.store
#TLS_PASSWORD=password

# Any JVM args for the invocation of the JDBC client used to verify DB
# instances and to shut them down (SqlToolSprayer).
# This example specifies the location of a private trust store for TLS 
# encryption.
# For multiple args, put quotes around entire value.
#CLIENT_JVMARGS=-Djavax.net.debug=ssl

# Any JVM args for the server.
# For multiple args, put quotes around entire value.
#SERVER_JVMARGS=-Xmx512m
</pre></li><li><p>
                Either copy <span class="bold"><b>HSQLDB_OWNER</b></span>'s
                <tt class="filename">sqltool.rc</tt> file into root's home 
                directory, or set the value of AUTH_FILE to the absolute path
                of <span class="bold"><b>HSQLDB_OWNER</b></span>'s
                <tt class="filename">sqltool.rc</tt> file.
                This file is read (for stops) directly by root, even if you run 
                hsqldb as non-root (by setting HSQLDB_OWNER in the config file).
                If you copy the file, make sure to use <tt class="literal">chmod</tt>
                to restrict permissions on the new copy.
                (The init script now enforces permissions on this file).
            </p></li><li><p>
                Edit your <tt class="filename">server.properties</tt> file.
                For every <tt class="literal">server.database.X</tt> that you have
                defined, set a property of name 
                <tt class="literal">server.urlid.X</tt> to the urlid for an 
                Administrative user for that database instance.
                </p><div class="example"><a name="N107DB"></a><p class="title"><b>Example&nbsp;3.1.&nbsp;server.properties fragment</b></p><pre class="programlisting">
    server.database.0=file://home/hsqldb/data/db1
    server.urlid.0=localhostdb1</pre></div><div class="warning" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Warning</h3><p>
                    Make sure to add a urlid for each and every database
                    instance.
                    If you don't then the init script will never know about
                    databases that become inaccessible and will give false
                    diagnostics.
                </p></div><p>
                For this example, you would need to define the urlid
                <tt class="literal">localhostdb1</tt> in your
                <tt class="filename">sqltool.rc</tt> file.
                </p><div class="example"><a name="N107EE"></a><p class="title"><b>Example&nbsp;3.2.&nbsp;example sqltool.rc stanza</b></p><pre class="programlisting">
    urlid localhostdb1
    url jdbc:hsqldb:hsql://localhost
    username sa
    password secret</pre></div></li><li><p>
                <span class="bold"><b>Verify that the init script
                works.</b></span>
            </p><p>
                Just run
            <div class="informalexample"><pre class="screen">
    /path/to/hsqldb</pre></div>
                as root to see the arguments you may use.
                Notice that you can run
            </p><div class="informalexample"><pre class="screen">
    /path/to/hsqldb status</pre></div><p>
                at any time to see whether your HSQLDB
                <tt class="classname">Server</tt> is running.
            </p><p>
                Re-run the script with each of the possible arguments to really
                test it good.
                If anything doesn't work right, then see the
                <a href="#initscriptTrouble-section" title="

                Troubleshooting the Init Script

            ">
                Troubleshooting the Init Script
            </a> section.
            </p></li><li><p>
                Tell your OS to run the init script upon system startup and 
                shutdown.
                If you are using a UNIX variant that has 
                <tt class="filename">/etc/rc.conf</tt> or 
                <tt class="filename">/etc/rc.conf.local</tt> (like BSD variants
                and Gentoo), you must set "hsqldb_enable" to "YES" in either
                of those files.
                (Just run <tt class="literal">cd /etc; ls rc.conf rc.conf.local</tt>
                to see if you have one of these files).
                For good UNIXes that use System V style init, you must set up 
                hard links or soft links either manually or with management 
                tools (such as <tt class="literal">chkconfig</tt> or
                <tt class="literal">insserv</tt>) or Gui's (like run level editors).
            </p><p>
                This paragraph is for Mac OS X users only.
                If you followed the instructions above, your init script
                should reside at
                <tt class="filename">/Library/StartupItems/hsqldb/hsqldb</tt>.
                Now copy the file <tt class="filename">StartupParameters.plist</tt>
                from the directory <tt class="filename">src/org.hsqldb/sample</tt>
                of your HSQLDB distribution to the same directory as the
                init script.
                As long as these two files reside in
                <tt class="filename">/Library/StartupItems/hsqldb</tt>, your
                init script is active (for portability reasons, it doesn't
                check for a setting in <tt class="filename">/etc/hostconfig</tt>).
                You can run it as a <span class="emphasis"><em>Startup Item</em></span> by running
                <pre class="screen">
    SystemStarter {start|stop|restart} Hsqldb</pre>
                Hsqldb is the service name.  See the man page for
                <tt class="literal">SystemStarter</tt>.
                To disable the init script, wipe out the 
                <tt class="filename">/Library/StartupItems/hsqldb</tt> directory.
                Hard to believe, but the Mac people tell me that during
                system shutdown the Startup Items don't run at all.
                Therefore, if you don't want your data corrupted, make
                sure to run "SystemStarter stop Hsqldb" before shutting
                down your Mac.
            </p></li></ol></div><p>
                Follow the examples in the config file to add additional
                classes to the server JVM's classpath and to execute
                additional classes in your JVM.
                (See the SERVER_ADDL_CLASSPATH and INVOC_ADDL_ARGS items).
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="initscriptTrouble-section"></a>
                Troubleshooting the Init Script
            </h3></div></div><div></div></div><p>
                Do a <tt class="literal">ps</tt> to look for processes containing
                the string <tt class="literal">hsqldb</tt>, and try to connect to the 
                database from any client.
                If the init script starts up your database successfully, but 
                incorrectly reports that it has not, then your problem is with
                specification of urlid(s) or SqlTool setup.
                If your database really did not start, then skip to the next
                paragraph.
                Verify that the urlid(s) listed in the
                <tt class="filename">server.properties</tt> or
                <tt class="filename">webserver.properties</tt> are correct.
                and verify that you can run 
                <tt class="classname">SqlTool</tt> as root to connect to the 
                instances.
                (For the latter test, use the <tt class="literal">--rcfile</tt>
                switch if you are setting <tt class="literal">AUTH_FILE</tt> in the 
                init script config file).
            </p><p>
                If your database really is not starting, then verify that
                you can su to the database owner account and start the 
                database.
                The command <tt class="literal">su USERNAME -c ...</tt> won't work
                on most UNIXes unless the target user has a real login shell.
                Therefore, if you try to tighten up security by disabling
                this user's login shell, you will break the init script.
                If these possibilities don't pan out, then debug the init 
                script or seek help, as described below.
            </p><p>
                To debug the init script, run it in verbose mode to see exactly
                what is happening
                (and perhaps manually run the steps that are suspect).
                To run an init script (in fact, any sh shell script) in verbose 
                mode, use 
                <tt class="literal">sh</tt> with the <tt class="literal">-x</tt> or
                <tt class="literal">-v</tt> switch, like
                <pre class="screen">
    sh -x path/to/hsqldb start</pre>
                See the man page for <tt class="literal">sh</tt> if you don't know 
                the difference between <tt class="literal">-v</tt> and 
                <tt class="literal">-x</tt>.
            </p><p>
                If you want troubleshooting help, use the HSQLDB lists/forums
                or email me at 
                <a href="mailto:blaine.simpson@admc.com?Subject=hsqldb-unix" target="_top">
                    blaine.simpson@admc.com</a>.
                If you email me, make sure to include the revision number 
                from your <tt class="filename">hsqldb</tt> init script (it's
                towards the top in the line that starts like "# $Id:"), and
                the output of a run of
                <pre class="screen">
    sh -x path/to/hsqldb start &gt; /tmp/hstart.log 2&gt;&amp;1</pre>
            </p></div></div></div><div class="chapter" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="advanced-chapter"></a>Chapter&nbsp;4.&nbsp;Advanced Topics</h2></div><div><div class="authorgroup"><div class="author"><h3 class="author"><span class="firstname">Fred</span> <span class="surname">Toussi</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:ft@cluedup.com">ft@cluedup.com</a>&gt;</tt></div></div></div><div><div class="legalnotice"><p>Copyright 2002-2005 Fred Toussi. Permission is granted to
      distribute this document without any alteration under the terms of the
      HSQLDB license. Additional permission is granted to the HSQLDB
      Development Group to distribute this document with or without
      alterations under the terms of the HSQLDB license.</p></div></div><div><p class="pubdate">$Date: 2005/06/30 22:38:54 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N108C9">Purpose</a></span></dt><dt><span class="section"><a href="#N108D2">Connections</a></span></dt><dd><dl><dt><span class="section"><a href="#N109E6">Connection properties</a></span></dt></dl></dd><dt><span class="section"><a href="#N10A68">Properties Files</a></span></dt><dd><dl><dt><span class="section"><a href="#N10AC1">Server and Web Server Properties</a></span></dt><dt><span class="section"><a href="#N10BBC">Starting a Server from your application</a></span></dt><dt><span class="section"><a href="#N10BCF">Individual Database Properties</a></span></dt></dl></dd><dt><span class="section"><a href="#N10D67">SQL Commands for Database Properties</a></span></dt></dl></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N108C9"></a>Purpose</h2></div></div><div></div></div><p>Many questions repeatedly asked in Forums and mailing lists are
    answered in this guide. If you want to use HSQLDB with your application,
    you should read this guide. This document covers system related issues.
    For issues related to SQL see the <a href="#sql_issues-chapter" title="Chapter&nbsp;2.&nbsp;SQL Issues">SQL Issues</a> chapter.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N108D2"></a>Connections</h2></div></div><div></div></div><p>The normal method of accessing an HSQLDB database is via the JDBC
    Connection interface. An introduction to different methods of providing
    database services and accessing them can be found in the <a href="#sql_issues-chapter" title="Chapter&nbsp;2.&nbsp;SQL Issues">SQL Issues</a> chapter.
    Details and examples of how to connect via JDBC are provided in our <a href="../src/org/hsqldb/jdbc/jdbcConnection.html" target="_top">JavaDoc for
    <tt class="literal">jdbcConnection</tt></a>.</p><p>Version 1.7.2 introduced a uniform method of distinguishing between
    different types of connection, alongside new capabilities to provide
    access to multiple databases. The common driver identifier is
    <tt class="literal">jdbc:hsqldb:</tt> followed by a protocol identifier
    (<tt class="literal">mem: file: res: hsql: http: hsqls: https:</tt>) then
    followed by host and port identifiers in the case of servers, then
    followed by database identifier.</p><div class="table"><a name="N108EC"></a><p class="title"><b>Table&nbsp;4.1.&nbsp;Hsqldb URL Components</b></p><table summary="Hsqldb URL Components" width="100%" border="1"><colgroup><col align="left"><col align="left"><col align="left"></colgroup><thead><tr><th align="left">Driver and Protocol</th><th align="left">Host and Port</th><th align="left">Database</th></tr></thead><tbody valign="top"><tr><td align="left"><table summary="Simple list" border="0" class="simplelist"><tr><td>
                  <tt class="literal">jdbc:hsqldb:mem:</tt>
                </td></tr></table></td><td align="left">not available</td><td align="left"><table summary="Simple list" border="0" class="simplelist"><tr><td>
                  <tt class="literal">accounts</tt>
                </td></tr></table></td></tr><tr><td colspan="3" align="left"><p>Lowercase, single-word identifier creates the in-memory
              database when the first connection is made. Subsequent use of
              the same Connection URL connects to the existing DB.</p><p>The old form for the URL, <tt class="literal">jdbc:hsqldb:.</tt>
              creates or connects to the same database as the new form for the
              URL, <tt class="literal">jdbc:hsqldb:mem:.</tt></p></td></tr><tr><td align="left"><table summary="Simple list" border="0" class="simplelist"><tr><td>
                  <tt class="literal">jdbc:hsqldb:file:</tt>
                </td></tr></table></td><td align="left">not available</td><td align="left"><table summary="Simple list" border="0" class="simplelist"><tr><td>
                  <tt class="filename">mydb</tt>
                </td></tr><tr><td>
                  <tt class="filename">/opt/db/accounts</tt>
                </td></tr><tr><td>
                  <tt class="filename">C:/data/mydb</tt>
                </td></tr></table></td></tr><tr><td colspan="3" align="left"><p>The file path specifies the database file. In the above
              examples the first one refers to a set of mydb.* files in the
              directory where the <tt class="literal">java</tt>command for running
              the application was issued. The second and third examples refer
              to absolute paths on the host machine.</p></td></tr><tr><td align="left"><table summary="Simple list" border="0" class="simplelist"><tr><td>
                  <tt class="literal">jdbc:hsqldb:res:</tt>
                </td></tr></table></td><td align="left">not available</td><td align="left"><table summary="Simple list" border="0" class="simplelist"><tr><td>
                  <tt class="filename">/adirectory/dbname</tt>
                </td></tr></table></td></tr><tr><td colspan="3" align="left">Database files can be loaded from
            one of the jars specified as part of the <tt class="literal">Java</tt>
            command the same way as resource files are accessed in Java
            programs. The <tt class="literal">/adirectory</tt> above stands for a
            directory in one of the jars.</td></tr><tr><td align="left"><table summary="Simple list" border="0" class="simplelist"><tr><td>
                  <tt class="literal">jdbc:hsqldb:hsql:</tt>
                </td></tr><tr><td>
                  <tt class="literal">jdbc:hsqldb:hsqls:</tt>
                </td></tr><tr><td>
                  <tt class="literal">jdbc:hsqldb:http:</tt>
                </td></tr><tr><td>
                  <tt class="literal">jdbc:hsqldb:https:</tt>
                </td></tr></table></td><td align="left"><table summary="Simple list" border="0" class="simplelist"><tr><td>
                  <tt class="literal">//localhost</tt>
                </td></tr><tr><td>
                  <tt class="literal">//192.0.0.10:9500</tt>
                </td></tr><tr><td>
                  <tt class="literal">//dbserver.somedomain.com</tt>
                </td></tr></table></td><td align="left"><table summary="Simple list" border="0" class="simplelist"><tr><td>
                  <tt class="literal">/an_alias</tt>
                </td></tr><tr><td>
                  <tt class="literal">/enrollments</tt>
                </td></tr><tr><td>
                  <tt class="literal">/quickdb</tt>
                </td></tr></table></td></tr><tr><td colspan="3" align="left"><p>The host and port specify the IP address or host name of
              the server and an optional port number. The database to connect
              to is specified by an alias. This alias is a lowercase string
              defined in the <tt class="filename">server.properties</tt> file to
              refer to an actual database on the file system of the server or
              a transient, in-memory database on the server. The following
              example lines in <tt class="filename">server.properties </tt> or
              <tt class="filename">webserver.properties</tt> define the database
              aliases listed above and accessible to clients to refer to
              different file and in-memory databases.</p><pre class="programlisting">
    database.0=file:/opt/db/accounts
    dbname.0=an_alias

    database.1=file:/opt/db/mydb
    dbname.1=enrollments

    database.2=mem:adatabase
    dbname.2=quickdb</pre><p>The old form for the server URL, e.g.,
              <tt class="literal">jdbc:hsqldb:hsql//localhost</tt> connects to the
              same database as the new form for the URL,
              <tt class="literal">jdbc:hsqldb:hsql//localhost/</tt> where the alias
              is a zero length string. In the example below, the database
              files <tt class="literal">lists.*</tt> in the
              <tt class="literal">/home/dbmaster/</tt> directory are associated with
              the empty alias:</p><pre class="programlisting">
    database.3=/home/dbmaster/lists
    dbname.3=</pre></td></tr></tbody></table></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N109E6"></a>Connection properties</h3></div></div><div></div></div><p>Each new JDBC Connection to a database can specify connection
      properties. The properties <span class="property">user</span> and
      <span class="property">password</span> are always required. In 1.8.0 the
      following optional properties can also be used.</p><p>Connection properties are specified either by establishing the
      connection via the:</p><pre class="programlisting">
    DriverManager.getConnection (String url, Properties info);</pre><p>method call, or the property can be appended to the full
      Connection URL.</p><div class="table"><a name="N109FA"></a><p class="title"><b>Table&nbsp;4.2.&nbsp;Connection Properties</b></p><table summary="Connection Properties" width="100%" border="1"><colgroup><col align="left"><col align="left"><col align="left"></colgroup><tbody valign="top"><tr><td align="left"><span class="property">get_column_name</span></td><td align="left"><tt class="literal">true</tt></td><td align="left">column name in ResultSet</td></tr><tr><td colspan="3" align="left"><p>This property is used for compatibility with other JDBC
                driver implementations. When true (the default),
                <tt class="literal">ResultSet.getColumnName(int c)</tt> returns the
                underlying column name</p><p>When false, the above method returns the same value as
                <tt class="literal">ResultSet.getColumnLabel(int column)</tt>
                Example below:</p><pre class="programlisting">
    jdbc:hsqldb:hsql://localhost/enrollments;get_column_name=false
                    </pre><p>When a ResultSet is used inside a user-defined stored
                procedure, the default, true, is always used for this
                property.</p></td></tr><tr><td align="left"><span class="property">ifexists</span></td><td align="left"><tt class="literal">false</tt></td><td align="left">connect only if database already exists</td></tr><tr><td colspan="3" align="left"><p>Has an effect only with <tt class="literal">mem:</tt> and
                <tt class="literal">file:</tt> database. When true, will not create
                a new database if one does not already exist for the
                URL.</p><p>When false (the default), a new <tt class="literal">mem:</tt>
                or <tt class="literal">file:</tt> database will be created if it
                does not exist.</p><p>Setting the property to true is useful when
                troubleshooting as no database is created if the URL is
                malformed. Example below:</p><pre class="programlisting">
    jdbc:hsqldb:file:enrollments;ifexists=true</pre></td></tr><tr><td align="left"><span class="property">shutdown</span></td><td align="left"><tt class="literal">false</tt></td><td align="left">shut down the database when the last connection is
              closed</td></tr><tr><td colspan="3" align="left"><p>This mimics the behaviour of 1.7.1 and older versions.
                When the last connection to a database is closed, the database
                is automatically shut down. The property takes effect only
                when the first connection is made to the database. This means
                the connection that opens the database. It has no effect if
                used with subsequent, simultaneous connections.</p><p>This command has two uses. One is for test suites, where
                connections to the database are made from one JVM context,
                immediately followed by another context. The other use is for
                applications where it is not easy to configure the environment
                to shutdown the database. Examples reported by users include
                web application servers, where the closing of the last
                connection conisides with the web app being shut down.</p></td></tr></tbody></table></div><p>In addition, when a connection to an in-process database creates a
      new database, or opens an existing database (i.e. it is the first
      connection made to the database by the application), all the
      user-defined database properties can be specified as URL properties.
      This can be used to specify properties to enforce more strict SQL
      adherence, or to change cache_scale or similar properties before the
      database files are created. However, for new databases, it is
      recommended to use the SET PROPERTY command for such settings.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10A68"></a>Properties Files</h2></div></div><div></div></div><p>HSQLDB relies on a set of properties files for different settings.
    Since 1.7.0 property naming has been streamlined and a number of new
    properties have been introduced.</p><p>In all properties files, values are case-sensitive. All values apart
    from names of files or pages are required in lowercase (e.g.
    <span class="property">server.silent</span>=<tt class="literal">FALSE</tt> will have no
    effect, but <span class="property">server.silent</span>=<tt class="literal">false</tt>
    will work).</p><p>The properties files and the settings stored in them are as
    follows:</p><div class="table"><a name="N10A81"></a><p class="title"><b>Table&nbsp;4.3.&nbsp;Hsqldb Server Properties Files</b></p><table summary="Hsqldb Server Properties Files" width="100%" border="1"><colgroup><col><col><col></colgroup><thead><tr><th align="left">File Name</th><th align="left">Location</th><th align="left">Function</th></tr></thead><tbody valign="top"><tr><td align="left"><tt class="filename">server.properties</tt></td><td align="left">the directory where the command to run the
            <tt class="classname">Server</tt> class is issued</td><td align="left">settings for running HSQLDB as a database server
            communicating with the HSQL protocol</td></tr><tr><td align="left"><tt class="filename">webserver.properties</tt></td><td align="left">the directory where the command to run the
            <tt class="classname">WebServer</tt> class is issued</td><td align="left">settings for running HSQLDB as a database server
            communicating with the HTTP protocol</td></tr><tr><td align="left"><tt class="filename">&lt;dbname&gt;.properties</tt></td><td align="left">the directory where all the files for a database are
            located</td><td align="left">settings for each particular database</td></tr></tbody></table></div><p>Properties files for running the servers are not created
    automatically. You should create your own files that contain
    <span class="property">server.property</span>=<tt class="literal">value</tt> pairs for
    each property.</p><p>The properties file for each database is generated by the database
    engine. This file can be edited after closing the database. In 1.8.0, most
    of these properties can be changed via SQL commands.</p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10AC1"></a>Server and Web Server Properties</h3></div></div><div></div></div><p>In both <tt class="filename">server.properties</tt> and
      <tt class="filename">webserver.properties</tt> files, supported values and
      their defaults are as follows:</p><div class="table"><a name="N10ACE"></a><p class="title"><b>Table&nbsp;4.4.&nbsp;Property File Properties</b></p><table summary="Property File Properties" width="100%" border="1"><colgroup><col><col><col></colgroup><thead><tr><th align="left">Value</th><th align="left">Default</th><th align="left">Description</th></tr></thead><tbody valign="top"><tr><td align="left"><span class="property">server.database.0</span></td><td align="left"><tt class="literal">test</tt></td><td align="left">the path and file name of the first database file to
              use</td></tr><tr><td align="left"><span class="property">server.dbname.0</span></td><td align="left"><tt class="literal">""</tt></td><td align="left">lowercase server alias for the first database
              file</td></tr><tr><td align="left"><span class="property">server.urlid.0</span></td><td align="left"><tt class="literal">NONE</tt></td><td align="left">SqlTool urlid used by UNIX init script. (This property is
              not used if your are running Server/Webserver on a platform
              other than UNIX, or of you are not using our UNIX init
              script).</td></tr><tr><td align="left"><span class="property">server.silent</span></td><td align="left"><tt class="literal">true</tt></td><td align="left">no extensive messages displayed on console</td></tr><tr><td align="left"><span class="property">server.trace</span></td><td align="left"><tt class="literal">false</tt></td><td align="left">JDBC trace messages displayed on console</td></tr></tbody></table></div><p>In 1.8.0, each server can serve up to 10 different databases
      simultaneously. The <span class="property">server.database.0</span> property
      defines the filename / path whereas the
      <span class="property">server.dbname.0</span> defines the lowercase alias used by
      clients to connect to that database. The digit 0 is incremented for the
      second database and so on. Values for the
      <span class="property">server.database.{0-9}</span> property can use the
      <tt class="literal">mem:</tt>, <tt class="literal">file:</tt> or
      <tt class="literal">res:</tt> prefixes and properties as discussed above under
      CONNECTIONS. For example, <div class="informalexample"><pre class="programlisting">
    database.0=mem:temp;sql.enforce_strict_size=true;</pre></div></p><p>Values specific to <tt class="filename">server.properties</tt>
      are:</p><div class="table"><a name="N10B3C"></a><p class="title"><b>Table&nbsp;4.5.&nbsp;Server Property File Properties</b></p><table summary="Server Property File Properties" width="100%" border="1"><colgroup><col><col><col></colgroup><thead><tr><th align="left">Value</th><th align="left">Default</th><th align="left">Description</th></tr></thead><tbody valign="top"><tr><td align="left"><span class="property">server.port</span></td><td align="left"><tt class="literal">9001</tt></td><td align="left">TCP/IP port used for talking to clients. All databases
              are served on the same port.</td></tr><tr><td align="left"><span class="property">server.no_system_exit</span></td><td align="left"><tt class="literal">true</tt></td><td align="left">no <tt class="literal">System.exit()</tt> call when the
              database is closed</td></tr></tbody></table></div><p>Values specific to <tt class="filename">webserver.properties</tt>
      are:</p><div class="table"><a name="N10B6F"></a><p class="title"><b>Table&nbsp;4.6.&nbsp;WebServer Property File Properties</b></p><table summary="WebServer Property File Properties" width="100%" border="1"><colgroup><col><col><col></colgroup><thead><tr><th align="left">Value</th><th align="left">Default</th><th align="left">Description</th></tr></thead><tbody valign="top"><tr><td align="left"><span class="property">server.port</span></td><td align="left"><tt class="literal">80</tt></td><td align="left">TCP/IP port used for talking to clients</td></tr><tr><td align="left"><span class="property">server.default_page</span></td><td align="left"><tt class="literal">index.html</tt></td><td align="left">the default web page for server</td></tr><tr><td align="left"><span class="property">server.root</span></td><td align="left"><tt class="literal">./</tt></td><td align="left">the location of served pages</td></tr><tr><td align="left"><span class="property">.&lt;extension&gt;</span></td><td align="left"><tt class="literal">?</tt></td><td align="left">multiple entries such as
              <tt class="literal">.html=text/html</tt> define the mime types of the
              static files served by the web server. See the source for
              <tt class="filename">WebServer.java</tt> for a list.</td></tr></tbody></table></div><p>All the above values can be specified on the command line to start
      the server by omitting the <tt class="literal">server.</tt> prefix.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10BBC"></a>Starting a Server from your application</h3></div></div><div></div></div><p>If you want to start the server from within your application, as
      opposed to the command line or batch files, you should create an
      instance of Server or Web Server, then assign the properties in the form
      of a String and start the Server. An example of this can be found in the
      <tt class="classname">org.hsqldb.test.TestBase</tt> source.</p><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>Upgrading: If you have existing custom properties files, change
        the values to the new naming convention. Note the use of digits at the
        end of <span class="property">server.database.n</span> and
        <span class="property">server.dbname.n</span> properties.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10BCF"></a>Individual Database Properties</h3></div></div><div></div></div><p>Each database has its own <tt class="filename">&lt;dbname&gt;.properties
      </tt> file as part of a small group of files which also includes
      <tt class="filename">&lt;dbname&gt;.script</tt> and
      <tt class="filename">&lt;dbname&gt;.data</tt>. The properties files contain
      key/value pairs for some important settings.</p><p>In version 1.8.0 a new SQL command allows most database properties
      to be modified as follows:</p><pre class="programlisting">
    SET PROPERTY "property_name" property_value</pre><p>Properties that can be modified via <tt class="literal">SET
      PROPERTY</tt> are indicated in the table below. Other properties
      are indicated as <tt class="literal">PROPERTIES FILE ONLY</tt> and can be
      modified only by editing the .properties file after a shutdown and
      before a restart. Only the user-defined values listed below should ever
      be modified. Changing any other value could result in unexpected
      malfunction in database operations. Most of these values have been
      introduced for the new features since 1.7.0:</p><div class="table"><a name="N10BEF"></a><p class="title"><b>Table&nbsp;4.7.&nbsp;Database-specific Property File Properties</b></p><table summary="Database-specific Property File Properties" width="100%" border="1"><colgroup><col align="left"><col align="left"><col align="left"></colgroup><thead><tr><th align="left">Value</th><th align="left">Default</th><th align="left">Description</th></tr></thead><tbody valign="top"><tr><td align="left"><span class="property">readonly</span></td><td align="left"><tt class="literal">no</tt></td><td align="left">whole database is read-only</td></tr><tr><td colspan="3" align="left"><p>When true, the database cannot be modified in use. This
                setting can be changed to <tt class="literal">yes</tt> if the
                database is to be opened from a CD. Prior to changing this
                setting, the database should be closed with the
                <tt class="literal">SHUTDOWN COMPACT</tt> command to ensure
                consistency and compactness of the data. <tt class="literal">(PROPERTIES
                FILE ONLY) but can be used as a connection property to open a
                normal database as readonly.</tt></p></td></tr><tr><td align="left"><span class="property">hsqldb.files_readonly</span></td><td align="left"><tt class="literal">false</tt></td><td align="left">database files will not be written to</td></tr><tr><td colspan="3" align="left"><p>When true, data in MEMORY tables can be modified and new
                MEMORY tables can be added. However, these changes are not
                saved when the database is shutdown. CACHED and TEXT tables
                are always readonly when this setting is true.
                <tt class="literal">(PROPERTIES FILE ONLY)</tt></p></td></tr><tr><td align="left"><span class="property">hsqldb.cache_file_scale</span></td><td align="left"><tt class="literal">1</tt></td><td align="left">Set larger data file limits. Once set, the limit will go
              up to 8GB.</td></tr><tr><td colspan="3" align="left"><p>This property can be set to 8 to increase the size limit
                of the .data file from 2GB to 8GB. To apply the change to an
                existing database, SHUTDOWN SCRIPT should be performed first,
                then the property=value line below should be added to the
                .properties file before reopening the database.
                <pre class="programlisting">hsqldb.cache_file_scale=8</pre></p><p>The property can be set with the SQL command (as opposed
                to changing the value in the properties file) when the
                database has no CACHED tables (e.g. a new database).
                <tt class="literal">(SET PROPERTY)</tt></p></td></tr><tr><td align="left"><span class="property">sql.enforce_size</span></td><td align="left"><tt class="literal">false</tt></td><td align="left">trimming and padding string columns</td></tr><tr><td colspan="3" align="left"><p>This property is no longer supported. Use
                sql.enforce_sctrict_size</p></td></tr><tr><td align="left"><span class="property">sql.enforce_strict_size</span></td><td align="left"><tt class="literal">false</tt></td><td align="left">size enforcement and padding string columns</td></tr><tr><td colspan="3" align="left"><p>Conforms to SQL standards for size and precision of data
                types. When true, all CHARACTER, VARCHAR, NUMERIC and DECIMAL
                values that are in a row affected by an INSERT INTO or UPDATE
                statement are checked against the size specified in the SQL
                table definition. An exception is thrown if the value is too
                long. Also all CHARACTER values that are shorter than the
                specified size are padded with spaces. TIMESTAMP(0) and
                TIMESTAMP(6) are also allowed in order to specify the
                subsecond resolution of the values. When false (default),
                stores the exact string that is inserted. <tt class="literal"> (SET
                PROPERTY)</tt></p></td></tr><tr><td align="left"><span class="property">sql.tx_no_multi_rewrite</span></td><td align="left"><tt class="literal">false</tt></td><td align="left">transaction management</td></tr><tr><td colspan="3" align="left"><p>In the default READ_UNCOMMITED mode, a transaction can
                write over rows inserted or updated by another uncommitted
                transaction.<tt class="literal"> Setting this property to true will raise
                an exception when such a write is attempted (SET
                PROPERTY)</tt></p></td></tr><tr><td align="left"><span class="property">hsqldb.cache_scale</span></td><td align="left"><tt class="literal">14</tt></td><td align="left">memory cache exponent</td></tr><tr><td colspan="3" align="left"><p>Indicates the maximum number of rows of cached tables
                that are held in memory, calculated as 3 *(2**value) (three
                multiplied by (two to the power value)). The default results
                in up to 3*16384 rows from all cached tables being held in
                memory at any time.</p><p>The value can range between 8-18. <tt class="literal">(SET
                PROPERTY)</tt>. If the value is set via SET PROPERTY then
                it becomes effective after the next database SHUTDOWN or
                CHECKPOINT. <tt class="literal">(SET PROPERTY)</tt></p></td></tr><tr><td align="left"><span class="property">hsqldb.cache_size_scale</span></td><td align="left"><tt class="literal">10</tt></td><td align="left">memory cache exponent</td></tr><tr><td colspan="3" align="left"><p>Indicates the average size of each row in the memory
                cache used with cached tables, calculated as 2**value (two to
                the power value). This result value is multiplied by the
                maximum number of rows defined by
                <span class="property">hsqldb.cache_scale</span> to form the maximum
                number of bytes for all the rows in memory cache. The default
                results in 1024 bytes per row. This default, combined with the
                default number of rows, results in approximately 50MB of the
                .data file to be stored in the memory cache.</p><p>The value can range between 6-20. <tt class="literal">(SET
                PROPERTY)</tt>. If the value is set via SET PROPERTY then
                it becomes effective after the next database SHUTDOWN or
                CHECKPOINT. <tt class="literal">(SET PROPERTY)</tt></p></td></tr><tr><td align="left"><span class="property">hsqldb.log_size</span></td><td align="left"><tt class="literal">200</tt></td><td align="left">size of log when checkpoint is performed</td></tr><tr><td colspan="3" align="left"><p>The value is the size in megabytes that the
                <tt class="literal">.log</tt> file can reach before an automatic
                checkpoint occurs. A checkpoint and rewrites the
                <tt class="literal">.script</tt> file and clears the
                <tt class="literal">.log</tt> file. The value can be changed via the
                <tt class="literal">SET LOGSIZE nnn</tt> SQL command.</p></td></tr><tr><td align="left"><span class="property">runtime.gc_interval</span></td><td align="left"><tt class="literal">0</tt></td><td align="left">forced garbage collection</td></tr><tr><td colspan="3" align="left"><p>This setting forces garbage collection each time a set
                number of result set row or cache row objects are created. The
                default, "0" means no garbage collection is forced by the
                program.</p><p>This should not be set when the database engine is
                acting as a server inside an exclusive JVM. The setting can be
                useful when the database is used in-process with the
                application with some Java Runtime Environments (JRE's). Some
                JRE's increase the size of the memory heap before doing any
                automatic garbage collection. This setting would prevent any
                unnecessary enlargement of the heap. Typical values for this
                setting would probably be between 10,000 to 100,000.
                <tt class="literal">(PROPERTIES FILE ONLY)</tt></p></td></tr><tr><td align="left"><span class="property">hsqldb.nio_data_file</span></td><td align="left"><tt class="literal">true</tt></td><td align="left">use of nio access methods for the .data file</td></tr><tr><td colspan="3" align="left"><p>When HSQLDB is compiled and run in Java 1.4 or higher,
                setting this property to <tt class="literal">false</tt> will avoid
                the use of nio access methods, resulting in somewhat reduced
                speed. If the data file is larger than 256MB when it is first
                opened, nio access methods are not used. Also, if the file
                gets larger than the amount of available computer memory that
                needs to be allocated for nio access, non-nio access methods
                are used.</p><p><tt class="literal">(SET PROPERTY)</tt>. If used before
                defining any CACHED table, it applies to the current session,
                otherwise it comes to effect after a SHUTDOWN and restart or
                CHECKPOINT.</p></td></tr><tr><td align="left"><span class="property">hsqldb.default_table_type</span></td><td align="left"><tt class="literal">memory</tt></td><td align="left">type of table created with unqualified CREATE
              TABLE</td></tr><tr><td colspan="3" align="left"><p>The CREATE TABLE command results in a MEMORY table by
                default. Setting the value "cached" for this property will
                result in a cached table by default. The qualified forms such
                as CREATE MEMORY TABLE or CREATE CACHED TABLE are not affected
                at all by this property. <tt class="literal">(SET
                PROPERTY)</tt></p></td></tr><tr><td align="left"><span class="property">hsqldb.applog</span></td><td align="left"><tt class="literal">0</tt></td><td align="left">application logging level</td></tr><tr><td colspan="3" align="left"><p>The default level 0 indicates no logging. Level 1
                results in events related to persistence to be logged,
                including any failures. The events are logged in a file ending
                with .app.log</p></td></tr><tr><td align="left"><span class="property">textdb.*</span></td><td align="left"><tt class="literal">0</tt></td><td align="left">default properties for new text tables</td></tr><tr><td colspan="3" align="left"><p>Properties that override the database engine defaults
                for newly created text tables. Settings in the text table
                <tt class="literal">SET &lt;tablename&gt; SOURCE &lt;source string&gt;
                </tt>command override both the engine defaults and the
                database properties defaults. Individual
                <span class="property">textdb.*</span> properties are listed in the
                <a href="#texttables-chapter" title="Chapter&nbsp;6.&nbsp;Text Tables">Text Tables</a> chapter. <tt class="literal">(SET
                PROPERTY)</tt></p></td></tr></tbody></table></div><p>When connecting to an in-process database creates a new database,
      or opens an existing database (i.e. it is the first connection made to
      the database by the application), all the user-defined database
      properties listed in this section can be specified as URL
      properties.</p><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>Upgrading: From 1.7.0, the location of the database files can no
        longer be overridden by paths defined in the properties file. All
        files belonging to a database should reside in the same
        directory.</p></div><p>The property sql.compare_in_locale=true is no longer supported.
      If the line exists in a .properties file, it will switch the database to
      the collation for the current default. See the <a href="#collation-section" title="SET DATABASE COLLATION">SET DATABASE COLLATION<sup>[<a href="#ftn.posthyper">1</a>]</sup></a>
      command.</p><p>When HSQLDB is used in OpenOffice.org, some property values
      will have a different default. The properties and values are:</p><p>hsqldb.default_table_type=cached hsqldb.cache_scale=13
      hsqldb.log_size=10; hsqldb.nio_data_file=false
      sql.enforce_strict_size=true</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10D67"></a>SQL Commands for Database Properties</h2></div></div><div></div></div><p>There are some database properties that are set with dedicated SQL
    commands beginning with SET.</p><div class="table"><a name="N10D6C"></a><p class="title"><b>Table&nbsp;4.8.&nbsp;SQL command properties</b></p><table summary="SQL command properties" width="100%" border="1"><colgroup><col></colgroup><tbody valign="top"><tr><td align="left"><span class="property">SET WRITE_DELAY {{TRUE | FALSE} | &lt;seconds&gt; |
              &lt;milliseconds&gt; MILLIS</span></td></tr><tr><td align="left"><p>The default is TRUE and indicates that the changes to the
              database that have been logged are synched to the file system
              once every 20 seconds. FALSE indicates there is no delay and at
              each commit a file synch operation is performed. Numeric values
              from 0 can also be specified for the synch delay.</p><p>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</p><p>This setting should be specified on the basis of the
              reliability of the hardware used for running the database
              engine, the type of disk system used, the possibility of power
              failure etc. Also the nature of the data stored should be
              considered.</p><p>In general, when the system is very reliable, the setting
              can be left to the default. If it is not very reliable, or the
              data is critical a setting of 1 or 2 seconds would suffice. Only
              in the worst case scenario or with the most critical data should
              a setting of 0 or FALSE be specified as this will slow the
              engine down to the speed at which the file synch operation can
              be performed by the disk subsystem.</p><p>Values down to 10 millisconds can be specified by adding
              MILLIS to the command, but in practice a delay of 100
              milliseconds provides 99.99999% reliability with an average one
              system crash per 6 days.</p></td></tr><tr><td align="left"><span class="property">SET LOG_SIZE &lt;numeric value&gt;</span></td></tr><tr><td align="left"><p>The engine writes out a log of all the changes to the
              database as they occur. This log is synched to the disk based on
              the WRITE_DELAY property above. The log is never reused unless
              there is an abnormal termination, i.e. the database process is
              terminated without SHUTDOWN, or it was terminated using SHUTDOWN
              IMMEDIATELY.</p><p>The default maximum size of the .log file is 200 MB. When
              the maximum size is reached, a CHECKPOINT operation is
              performed. This operation will save the other database files in
              a consistent state and delete the old log. A value of 0
              indicates no limit for the .log file.</p></td></tr><tr><td align="left"><span class="property">SET CHECKPOINT DEFRAG &lt;numeric value&gt;</span></td></tr><tr><td align="left"><p>When rows in CACHED tables are updated or deleted, the
              spaces are mostly reused. However, in time, some unused spaces
              are left in the .data file, especially when large tables are
              dropped or their structure is modified.</p><p>A CHECKPOINT operation does not normally reclaim the empty
              spaces, whereas CHECKPOINT DEFRAG always does.</p><p>This property determines when a normal CHECKPOINT, whether
              initiated by an administrator or when the size of the log
              exceeds its limit.</p><p>The numeric value is the number of megabytes of recorded
              empty spaces in the .data file that would force a DEFRAG
              operation. Low values result in more frequent DEFRAG operations.
              A value of 0 indicates no automatic DEFRAG is performed. The
              default is 200 megabytes of lost space.</p></td></tr><tr><td align="left"><span class="property">SET REFERENTIAL INTEGRITY {TRUE | FALSE}</span></td></tr><tr><td align="left"><p>This is TRUE by default. If bulk data needs to be loaded
              into the database, this property can be set FALSE for the
              duration of bulk load operation. This allows loading data for
              related tables in any order. The property should be set TRUE
              after bulk load. If the loaded data is not guaranteed to conform
              to the referential integrity constraints, SQL queries should be
              run after loading to identify and modify any non-conforming
              rows.</p></td></tr></tbody></table></div></div></div><div class="chapter" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="N10DAC"></a>Chapter&nbsp;5.&nbsp;Deployment Issues</h2></div><div><div class="authorgroup"><div class="author"><h3 class="author"><span class="firstname">Fred</span> <span class="surname">Toussi</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:ft@cluedup.com">ft@cluedup.com</a>&gt;</tt></div></div></div><div><div class="legalnotice"><p>Copyright 2005 Fred Toussi. Permission is granted to distribute
      this document without any alteration under the terms of the HSQLDB
      license. Additional permission is granted to the HSQLDB Development
      Group to distribute this document with or without alterations under the
      terms of the HSQLDB license.</p></div></div><div><p class="pubdate">$Date: 2005/07/02 09:11:39 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N10DCD">Purpose</a></span></dt><dt><span class="section"><a href="#N10DD6">Mode of Operation and Tables</a></span></dt><dd><dl><dt><span class="section"><a href="#N10DDB">Mode of Operation</a></span></dt><dt><span class="section"><a href="#N10DED">Tables</a></span></dt><dt><span class="section"><a href="#N10E04">Large Objects</a></span></dt><dt><span class="section"><a href="#N10E15">Deployment context</a></span></dt></dl></dd><dt><span class="section"><a href="#N10E21">Memory and Disk Use</a></span></dt><dd><dl><dt><span class="section"><a href="#N10E3E">Cache Memory Allocation</a></span></dt></dl></dd><dt><span class="section"><a href="#N10E5F">Managing Database Connections</a></span></dt><dt><span class="section"><a href="#N10E76">Upgrading Databases</a></span></dt><dd><dl><dt><span class="section"><a href="#upgrade_via_script-section">Upgrading Using the SCRIPT
      Command</a></span></dt><dt><span class="section"><a href="#N10ECE">Manual Changes to the .script File</a></span></dt></dl></dd><dt><span class="section"><a href="#N10F02">Backing Up Databases</a></span></dt></dl></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10DCD"></a>Purpose</h2></div></div><div></div></div><p>Many questions repeatedly asked in Forums and mailing lists are
    answered in this guide. If you want to use HSQLDB with your application,
    you should read this guide. This document covers system related issues.
    For issues related to SQL see the <a href="#sql_issues-chapter" title="Chapter&nbsp;2.&nbsp;SQL Issues">SQL Issues</a> chapter.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10DD6"></a>Mode of Operation and Tables</h2></div></div><div></div></div><p>HSQLDB has many modes of operation and features that allow it to be
    used in very different scenarios. Levels of memory usage, speed and
    accessibility by different applications are influenced by how HSQLDB is
    deployed.</p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10DDB"></a>Mode of Operation</h3></div></div><div></div></div><p>The decision to run HSQLDB as a separate server process or as an
      in-process database should be based on the following:</p><p>
        <div class="itemizedlist"><ul type="disc"><li><p>When HSQLDB is run as a server on a separate machine, it is
            isolated from hardware failures and crashes on the hosts running
            the application.</p></li><li><p>When HSQLDB is run as a server on the same machine, it is
            isolated from application crashes and memory leaks.</p></li><li><p>Server connections are slower than in-process connections
            due to the overhead of streaming the data for each JDBC
            call.</p></li></ul></div>
      </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10DED"></a>Tables</h3></div></div><div></div></div><p>TEXT tables are designed for special applications where the data
      has to be in an interchangeable format, such as CSV. TEXT tables should
      not be used for routine storage of data.</p><p>MEMORY tables and CACHED tables are generally used for data
      storage. The difference between the two is as follows:</p><p>
        <div class="itemizedlist"><ul type="disc"><li><p>The data for all MEMORY tables is read from the .script file
            when the database is started and stored in memory. In contrast the
            data for cached tables is not read into memory until the table is
            accessed. Furthermore, only part of the data for each CACHED table
            is held in memory, allowing tables with more data than can be held
            in memory.</p></li><li><p>When the database is shutdown in the normal way, all the
            data for MEMORY tables is written out to the disk. In comparison,
            the data in CACHED tables that has changed is written out at
            shutdown, plus a compressed backup of all the data in all cached
            tables.</p></li><li><p>The size and capacity of the data cache for all the CACHED
            tables is configurable. This makes it possible to allow all the
            data in CACHED tables to be cached in memory. In this case, speed
            of access is good, but slightly slower than MEMORY tables.</p></li><li><p>For normal applications it is recommended that MEMORY tables
            are used for small amounts of data, leaving CACHED tables for
            large data sets. For special applications in which speed is
            paramount and a large amount of free memory is available, MEMORY
            tables can be used for large tables as well</p></li></ul></div>
      </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10E04"></a>Large Objects</h3></div></div><div></div></div><p>JDBC Clobs are supported as columns of the type LONGVARCHAR. JDBC
      Blobs are supported as columns of the type LONGVARBINARY. When large
      objects (LONGVARCHAR, LONGVARBINARY, OBJECT) are stored with table
      definitions that contain several normal fields, it is better to use two
      tables instead. The first table to contain the normal fields and the
      second table to contain the large object plus an identity field. Using
      this method has two benefits. (a) The first table can usually be created
      as a MEMORY table while only the second table is a CACHED table. (b) The
      large objects can be retrieved individually using their identity,
      instead of getting loaded into memory for finding the rows during query
      processing. An example of two tables and a select query that exploits
      the separation between the two follows:</p><div class="informalexample"><pre class="programlisting">CREATE MEMORY TABLE MAINTABLE(MAINID INTEGER, ......);</pre><pre class="programlisting">CREATE CACHED TABLE LOBTABLE(LOBID INTEGER, LOBDATA LONGVARBINARY);</pre><pre class="programlisting">SELECT * FROM (SELECT * FROM MAINTABLE &lt;join any other table&gt; WHERE &lt;various conditions apply&gt;) JOIN LOBTABLE ON MAINID=LOBID;</pre></div><p>The inner SELECT finds the required rows without reference to the
      LOBTABLE and when it has found all the rows, retrieves the required
      large objects from the LOBTABLE.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10E15"></a>Deployment context</h3></div></div><div></div></div><p>The files used for storing HSQLDB database data are all in the
      same directory. New files are always created and deleted by the database
      engine. Two simple principles must be observed:</p><div class="itemizedlist"><ul type="disc"><li><p>The Java process running HSQLDB must have full privileges on
          the directory where the files are stored. This include create and
          delete privileges.</p></li><li><p>The file system must have enough spare room both for the
          'permanent' and 'temporary' files. The default maximum size of the
          .log file is 200MB. The .data file can grow to up to 8GB. The
          .backup file can be up to 50% of the .data file. The temporary file
          created at the time of a SHUTDOWN COMPACT can be equal in size to
          the .data file.</p></li></ul></div></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10E21"></a>Memory and Disk Use</h2></div></div><div></div></div><p>Memory used by the program can be thought of as two distinct pools:
    memory used for table data, and memory used for building result sets and
    other internal operations. In addition, when transactions are used, memory
    is utilised for storing the information needed for a rollback.</p><p>Since version 1.7.1, memory use has been significantly reduced
    compared to previous versions. The memory used for a MEMORY table is the
    sum of memory used by each row. Each MEMORY table row is a Java object
    that has 2 int or reference variables. It contains an array of objects for
    the fields in the row. Each field is an object such as
    <tt class="classname">Integer</tt>, <tt class="classname">Long</tt>,
    <tt class="classname">String</tt>, etc. In addition each index on the table
    adds a node object to the row. Each node object has 6 int or reference
    variables. As a result, a table with just one column of type INTEGER will
    have four objects per row, with a total of 10 variables of 4 bytes each -
    currently taking up 80 bytes per row. Beyond this, each extra column in
    the table adds at least a few bytes to the size of each row.</p><p>The memory used for a result set row has fewer overheads (fewer
    variables and no index nodes) but still uses a lot of memory. All the rows
    in the result set are built in memory, so very large result sets may not
    be possible. In server mode databases, the result set memory is released
    from the server once the database server has returned the result set.
    In-process databases release the memory when the application program
    releases the <tt class="classname">java.sql.ResultSet</tt> object. Server
    modes require additional memory for returning result sets, as they convert
    the full result set into an array of bytes which is then transmitted to
    the client.</p><p>When UPDATE and DELETE queries are performed on CACHED tables, the
    full set of rows that are affected, including those affected due to ON
    UPDATE actions, is held in memory for the duration of the operation. This
    means it may not be possible to perform deletes or updates involving very
    large numbers of rows of CACHED tables. Such operations should be
    performed in smaller sets.</p><p>When transactions support is enabled with SET AUTOCOMMIT OFF, lists
    of all insert, delete or update operations are stored in memory so that
    they can be undone when ROLLBACK is issued. Transactions that span
    hundreds of modification to data will take up a lot of memory until the
    next COMMIT or ROLLBACK clears the list.</p><p>Most JVM implementations allocate up to a maximum amount of memory
    (usually 64 MB by default). This amount is generally not adequate when
    large memory tables are used, or when the average size of rows in cached
    tables is larger than a few hundred bytes. The maximum amount of allocated
    memory can be set on the java ... command line that is used for running
    HSQLDB. For example, with Sun JVM version 1.3.0 the parameter -Xmx256m
    increases the amount to 256 MB.</p><p>1.8.0 uses a fast cache for immutable objects such as Integer or
    String that are stored in the database. In most circumstances, this
    reduces the memory footprint still further as fewer copies of the most
    frequently-used objects are kept in memory.</p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10E3E"></a>Cache Memory Allocation</h3></div></div><div></div></div><p>With CACHED tables, the data is stored on disk and only up to a
      maximum number of rows are held in memory at any time. The default is up
      to 3*16384 rows. The <span class="property">hsqldb.cache_scale</span> database
      property can be set to alter this amount. As any random subset of the
      rows in any of the CACHED tables can be held in the cache, the amount of
      memory needed by cached rows can reach the sum of the rows containing
      the largest field data. For example if a table with 100,000 rows
      contains 40,000 rows with 1,000 bytes of data in each row and 60,000
      rows with 100 bytes in each, the cache can grow to contain nearly 50,000
      rows, including all the 40,000 larger rows.</p><p>An additional property,
      <span class="property">hsqldb.cache_size_scale</span> can be used in conjunction
      with the <span class="property">hsqldb.cache_scale</span> property. This puts a
      limit in bytes on the total size of rows that are cached. When the
      default values is used for both properties, the limit on the total size
      of rows is approximately 50MB. (This is the size of binary images of the
      rows and indexes. It translates to more actual memory, typically 2-4
      times, used for the cache because the data is represented by Java
      objects.)</p><p>If memory is limited, the <span class="property">hsqldb.cache_scale</span>
      or <span class="property">hsqldb.cache_size_scale</span> database properties can
      be reduced. In the example above, if the
      <span class="property">hsqldb.cache_size_scale</span> is reduced from 10 to 8,
      then the total binary size limit is reduced from 50MB to 12.5 MB. This
      will allow the number of cached rows to reach 50,000 small rows, but
      only 12,500 of the larger rows.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10E5F"></a>Managing Database Connections</h2></div></div><div></div></div><p>In all running modes (server or in-process) multiple connections to
    the database engine are supported. In-process (standalone) mode supports
    connections from the client in the same Java Virtual Machine, while server
    modes support connections over the network from several different
    clients.</p><p>Connection pooling software can be used to connect to the database
    but it is not generally necessary. With other database engines, connection
    pools are used for reasons that may not apply to HSQLDB.</p><div class="itemizedlist"><ul type="disc"><li><p>To allow new queries to be performed while a time-consuming
        query is being performed in the background. This is not possible with
        HSQLDB 1.8.0 as it blocks while performing the first query and deals
        with the next query once it has finished it. This capability is under
        development and will be introduced in a future version.</p></li><li><p>To limit the maximum number of simultaneous connections to the
        database for performance reasons. With HSQLDB this can be useful only
        if your application is designed in a way that opens and closes
        connections for each small task.</p></li><li><p>To control transactions in a multi-threaded application. This
        can be useful with HSQLDB as well. For example, in a web application,
        a transaction may involve some processing between the queries or user
        action across web pages. A separate connection should be used for each
        HTTP session so that the work can be committed when completed or
        rolled back otherwise. Although this usage cannot be applied to most
        other database engines, HSQLDB is perfectly capable of handling over
        100 simultaneous HTTP sessions as individual JDBC connections.</p></li></ul></div><p>An application that is not both multi-threaded and transactional,
    such as an application for recording user login and logout actions, does
    not need more than one connection. The connection can stay open
    indefinitely and reopened only when it is dropped due to network
    problems.</p><p>When using an in-process database with versions prior to 1.7.2 the
    application program had to keep at least one connection to the database
    open, otherwise the database would have been closed and further attempts
    to create connections could fail. This is not necessary since 1.7.2, which
    does not automatically close an in-process database that is opened by
    establishing a connection. An explicit SHUTDOWN command, with or without
    an argument, is required to close the database. In version 1.8.0 a
    connection property can be used to revert to the old behaviour.</p><p>When using a server database (and to some extent, an in-process
    database), care must be taken to avoid creating and dropping JDBC
    Connections too frequently. Failure to observe this will result in
    unsuccessful connection attempts when the application is under heavy
    load.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10E76"></a>Upgrading Databases</h2></div></div><div></div></div><p>Any database not produced with the release version of HSQLDB 1.8.0
    must be upgraded to this version. This includes databases created with the
    RC versions of 1.8.0. The instructions under the <a href="#upgrade_via_script-section" title="Upgrading Using the SCRIPT

      Command">Upgrading Using the SCRIPT
      Command</a>
    section should be followed in all cases.</p><p>Once a database is upgraded to 1.8.0, it can no longer be used with
    Hypersonic or previous versions of HSQLDB.</p><p>There may be some potential legacy issues in the upgrade which
    should be resolved by editing the .script file:</p><div class="itemizedlist"><ul type="disc"><li><p>Version 1.8.0 does not accept duplicate names for indexes that
        were allowed before 1.7.2.</p></li><li><p>Version 1.8.0 does not accept duplicate names for table columns
        that were allowed before 1.7.0.</p></li><li><p>Version 1.8.0 does not create the same type of index for foreign
        keys as versions before 1.7.2.</p></li><li><p>Version 1.8.0 does not accept table or column names that are SQL
        identifiers without double quoting.</p></li></ul></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="upgrade_via_script-section"></a>Upgrading Using the SCRIPT
      Command</h3></div></div><div></div></div><p>To upgrade from 1.7.2 or 1.7.3 to 1.8.0, simply issue the SET
      SCRIPTFORMAT TEXT and SHUTDOWN SCRIPT commands with the old version,
      then open with the new version of the engine. The upgrade is then
      complete.</p><p>To upgrade from older version database files (1.7.1 and older)
      that do not contain CACHED tables, simple SHUTDOWN with the older
      version and open with the new version. If there is any error in the
      .script file, try again after editing the .script file.</p><p>To upgrade from older version database files (1.7.1 and older)
      that contain CACHED tables, use the SCRIPT procedure below. In all
      versions of HSQLDB and Hypersonic 1.43, the <tt class="literal">SCRIPT
      'filename'</tt> command (used as an SQL query) allows you to save a
      full record of your database, including database object definitions and
      data, to a file of your choice. You can export a script file using the
      old version of the database engine and open the script as a database
      with 1.8.0.</p><div class="procedure"><p class="title"><b>Procedure&nbsp;5.1.&nbsp;Upgrade Using SCRIPT procedure</b></p><ol type="1"><li><p>Open the original database in the old version of
          DatabaseManager</p></li><li><p>Issue the SCRIPT command, for example <tt class="literal">SCRIPT
          'newversion.script'</tt> to create a script file containing a
          copy of the database.</p></li><li><p>Use the 1.8.0 version of DatabaseManager to create a new
          database, in this example <tt class="literal">'newversion'</tt> in a
          different directory.</p></li><li><p>SHUTDOWN this database.</p></li><li><p>Copy the <tt class="filename">newversion.script</tt> file from step
          2 over the file of the same name for the new database created in
          4.</p></li><li><p>Try to open the new database using DatabaseManager.</p></li><li><p>If there is any inconsistency in the data, the script line
          number is reported on the console and the opening process is
          aborted. Edit and correct any problems in the
          <tt class="filename">newversion.script</tt> before attempting to open
          again. Use the guidelines in the next section (Manual Changes to the
          .script File). Use a programming editor that is capable of handling
          very large files and does not wrap long lines of text.</p></li></ol></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10ECE"></a>Manual Changes to the .script File</h3></div></div><div></div></div><p>In 1.8.0 the full range of ALTER TABLE commands is available to
      change the data structures and their names. However, if an old database
      cannot be opened due to data inconsistencies, or the use of index or
      column names that are not compatible with 1.8.0, manual editing of the
      SCRIPT file can be performed.</p><p>The following changes can be applied so long as they do not affect
      the integrity of existing data.</p><div class="itemizedlist"><ul type="disc"><li><p>Names of tables, columns and indexes can be changed.</p></li><li><p><tt class="literal">CREATE UNIQUE INDEX ...</tt> to <tt class="literal">CREATE
          INDEX ...</tt> and vice versa</p><p>A unique index can always be converted into a normal index. A
          non-unique index can only be converted into a unique index if the
          table data for the column(s) is unique in each row.</p></li><li><p>
            <tt class="literal">NOT NULL</tt>
          </p><p>A not-null constraint can always be removed. It can only be
          added if the table data for the column has no null values.</p></li><li><p>
            <tt class="literal">PRIMARY KEY</tt>
          </p><p>A primary key constraint can be removed or added. It cannot be
          removed if there is a foreign key referencing the column(s).</p></li><li><p>
            <tt class="literal">COLUMN TYPES</tt>
          </p><p>Some changes to column types are possible. For example an
          INTEGER column can be changed to BIGINT, or DATE, TIME and TIMESTAMP
          columns can be changed to VARCHAR.</p></li></ul></div><p>After completing the changes and saving the modified *.script
      file, you can open the database as normal.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10F02"></a>Backing Up Databases</h2></div></div><div></div></div><p>The data for each database consists of up to 5 files in the same
    directory. The endings are *.properties, *.script, *.data, *.backup and
    *.log (a file with the *.lck ending is used for controlling access to the
    database and should not be backed up). These should be backed up together.
    The files can be backed up while the engine is running but care should be
    taken that a CHECKPOINT or SHUTDOWN operation does not take place during
    the backup. It is more efficient to perform the backup immediately after a
    CHECKPOINT. The *.data file can be excluded from the backup. In this case,
    when restoring, a dummy *.data file is needed which can be an empty, 0
    length file. The engine will expand the *.backup file to replace this
    dummy file if the backup is restored. If the *.data file is not backed up,
    the *.properties file may have to be modified to ensure it contain
    modified=yes instead of modified=no prior to restoration. If a backup
    immediately follows a checkpoint, then the *.log file can also be
    excluded, reducing the significant files to *.properties, *.script and
    *.backup. Normal backup methods, such as archiving the files in a
    compressed bundle can be used.</p></div></div><div class="chapter" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="texttables-chapter"></a>Chapter&nbsp;6.&nbsp;Text Tables</h2></div><div><h3 class="subtitle"><i>Text Tables as a Standard Feature of Hsqldb</i></h3></div><div><div class="authorgroup"><div class="author"><h3 class="author"><span class="firstname">Bob</span> <span class="surname">Preston</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div></div><div class="author"><h3 class="author"><span class="firstname">Fred</span> <span class="surname">Toussi</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:ft@cluedup.com">ft@cluedup.com</a>&gt;</tt></div></div></div><div><div class="legalnotice"><p>Copyright 2002-2005 Bob Preston and Fred Toussi. Permission is
      granted to distribute this document without any alteration under the
      terms of the HSQLDB license. Additional permission is granted to the
      HSQLDB Development Group to distribute this document with or without
      alterations under the terms of the HSQLDB license.</p></div></div><div><p class="pubdate">$Date: 2005/06/29 23:15:13 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N10F46">The Implementation</a></span></dt><dd><dl><dt><span class="section"><a href="#N10F49">Definition of Tables</a></span></dt><dt><span class="section"><a href="#N10F58">Scope and Reassignment</a></span></dt><dt><span class="section"><a href="#N10F73">Null Values in Columns of Text Tables</a></span></dt><dt><span class="section"><a href="#N10F7F">Configuration</a></span></dt></dl></dd><dt><span class="section"><a href="#N11030">Text File Issues</a></span></dt><dt><span class="section"><a href="#N11055">Text File Global Properties</a></span></dt><dt><span class="section"><a href="#N11093">Importing from a Text Table file</a></span></dt></dl></div><p>Text Table support for HSQLDB was originally developed by Bob Preston
  independently from the Project. Subsequently Bob joined the Project and
  incorporated this feature into version 1.7.0, with a number of enhancements,
  especially the use of conventional SQL commands for specifying the files
  used for Text Tables.</p><p>In a nutshell, Text Tables are CSV or other delimited files treated as
  SQL tables. Any ordinary CSV or other delimited file can be used. The full
  range of SQL queries can be performed on these files, including SELECT,
  INSERT, UPDATE and DELETE. Indexes and unique constraints can be set up, and
  foreign key constraints can be used to enforce referential integrity between
  Text Tables themselves or with conventional tables.</p><p>HSQLDB with Text Table support is the only comprehensive solution that
  employs the power of SQL and the universal reach of JDBC to handle data
  stored in text files and will have wide-ranging use way beyond the currently
  established Java realm of HSQLDB.</p><div class="orderedlist"><p class="title"><b>Goals of the Implementation</b></p><ol type="1"><li><p>We aimed to finalise the DDL for Text Tables so that future
      releases of HSQLDB use the same DDL scripts.</p></li><li><p>We aimed to support Text Tables as GLOBAL TEMPORARY or GLOBAL BASE
      tables in the SQL domain.</p></li></ol></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N10F46"></a>The Implementation</h2></div></div><div></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10F49"></a>Definition of Tables</h3></div></div><div></div></div><p>Text Tables are defined similarly to conventional tables with the
      added TEXT keyword:</p><pre class="programlisting">
    CREATE TEXT TABLE &lt;tablename&gt; (&lt;column definition&gt; [&lt;constraint definition&gt;])</pre><p>In addition, a SET command specifies the file and the separator
      character that the Text table uses:</p><pre class="programlisting">
    SET TABLE &lt;tablename&gt; SOURCE &lt;quoted_filename_and_options&gt; [DESC]</pre><p>Text Tables cannot be created in memory-only databases (databases
      that have no script file).</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10F58"></a>Scope and Reassignment</h3></div></div><div></div></div><div class="itemizedlist"><ul type="disc"><li><p>A Text table without a file assigned to it is READ ONLY and
          EMPTY.</p></li><li><p>A Temporary Text table has the scope and the lifetime of the
          SQL session (a JDBC Connection).</p></li><li><p>Reassigning a Text Table definition to a new file has
          implications in the following areas:</p><div class="orderedlist"><ol type="1"><li><p>The user is required to be an administrator.</p></li><li><p>Existing transactions are committed at this point.</p></li><li><p>Constraints, including foreign keys referencing this
              table, are kept intact. It is the responsibility of the
              administrator to ensure their integrity.</p></li></ol></div><p>From version 1.7.2 the new source file is scanned and indexes
          are built when it is assigned to the table. At this point any
          violation of NOT NULL, UNIQUE or PRIMARY KEY constrainst are caught
          and the assignment is aborted. owever, foreign key constraints are
          not checked at the time of assignment or reassignment of the source
          file.</p></li></ul></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10F73"></a>Null Values in Columns of Text Tables</h3></div></div><div></div></div><p>This has changed since 1.7.2 to support both null values and empty
      strings.</p><div class="itemizedlist"><ul type="disc"><li><p>Empty fields are treated as NULL. These are fields where there
          is nothing or just spaces between the separators.</p></li><li><p>Quoted empty strings are treated as empty strings.</p></li></ul></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N10F7F"></a>Configuration</h3></div></div><div></div></div><p>The default field separator is a comma (,). A different field
      separator can be specified within the SET TABLE SOURCE statement. For
      example, to change the field separator for the table mytable to a
      vertical bar, place the following in the SET TABLE SOURCE statement, for
      example:</p><div class="informalexample"><pre class="programlisting">
    SET TABLE mytable SOURCE "myfile;fs=|"</pre></div><p>Since HSQLDB treats CHAR's, VARCHARs, and LONGVARCHARs the same,
      the ability to assign different separators to the latter two is
      provided. When a different separator is assigned to a VARCHAR or
      LONGVARCHAR field, it will terminate any CSV field of that type. For
      example, if the first field is CHAR, and the second field LONGVARCHAR,
      and the separator fs has been defined as the pipe (|) and vs as the
      period (.) then the data in the CSV file for a row will look
      like:</p><pre class="screen">
    First field data|Second field data.Third field data</pre><p>The following example shows how to change the default separator to
      the pipe (|), VARCHAR separator to the period (.) and the LONGVARCHAR
      separator to the tilde (~). Place the following within the SET TABLE
      SOURCE statement, for example:</p><div class="informalexample"><pre class="programlisting">
    SET TABLE mytable SOURCE "myfile;fs=|;vs=.;lvs=~"</pre></div><p>HSQLDB also recognises the following special indicators for
      separators:</p><div class="variablelist"><p class="title"><b>special indicators for separators</b></p><dl><dt><span class="term">\semi</span></dt><dd><p>semicolon</p></dd><dt><span class="term">\quote</span></dt><dd><p>qoute</p></dd><dt><span class="term">\space</span></dt><dd><p>space character</p></dd><dt><span class="term">\apos</span></dt><dd><p>apostrophe</p></dd><dt><span class="term">\n</span></dt><dd><p>newline - Used as an end anchor (like $ in regular
            expressions)</p></dd><dt><span class="term">\r</span></dt><dd><p>carriage return</p></dd><dt><span class="term">\t</span></dt><dd><p>tab</p></dd><dt><span class="term">\\</span></dt><dd><p>backslash</p></dd><dt><span class="term">\u####</span></dt><dd><p>a Unicode character specified in hexadecimal</p></dd></dl></div><p>Furthermore, HSQLDB provides csv file support with three
      additional boolean options: <tt class="literal">ignore_first</tt>,
      <tt class="literal">quoted</tt> and <tt class="literal">all_quoted</tt>. The
      <tt class="literal">ignore_first</tt> option (default false) tells HSQLDB to
      ignore the first line in a file. This option is used when the first line
      of the file contains column headings. The <tt class="literal">all_quoted</tt>
      option (default false) tells the program that it should use quotes
      around all character fields when writing to the source file. The
      <tt class="literal">quoted</tt> option (default true) uses quotes only when
      necessary to distinguish a field that contains the separator character.
      It can be set to false to prevent the use of quoting altogether and
      treat quote characters as normal characters. These options may be
      specified within the <tt class="literal">SET TABLE SOURCE</tt>
      statement:</p><pre class="programlisting">
    SET TABLE mytable SOURCE "myfile;ignore_first=true;all_quoted=true"</pre><p>When the default options <tt class="literal">all_quoted=</tt>
      <tt class="literal">false</tt> and <tt class="literal">quoted=true</tt> are in
      force, fields that are written to a line of the csv file will be quoted
      only if they contain the separator or the quote character. The quote
      character is doubled when used inside a string. When
      <tt class="literal">all_quoted=false</tt> and <tt class="literal">quoted=false</tt>
      the quote character is not doubled. With this option, it is not possible
      to insert any string containing the separator into the table, as it
      would become impossible to distinguish from a separator. While reading
      an existing data source file, the program treats each individual field
      separately. It determines that a field is quoted only if the first
      character is the quote character. It interprets the rest of the field on
      this basis.</p><p>The character encoding for the source file is<tt class="literal"> ASCII
      </tt>by default. To support UNICODE or source files preprared with
      different encodings this can be changed to <tt class="literal">UTF-8</tt> or
      any other encoding. The default is <tt class="literal">encoding=ASCII </tt>and
      the option <tt class="literal">encoding=UTF-8</tt> or other supported
      encodings can be used.</p><p>Finally, HSQLDB provides the ability to read a text file from the
      bottom up and making them READ ONLY, by placing the keyword "DESC" at
      the end of the SET TABLE SOURCE statement:</p><pre class="programlisting">
    SET TABLE mytable SOURCE "myfile" DESC</pre><p>This feature provides functionality similar to the Unix tail
      command, by re-reading the file each time a select is executed. Using
      this feature sets the table to read-only mode. Afterwards, it will no
      longer be possible to change the read-only status with <tt class="literal">SET
      TABLE &lt;tablename&gt; READONLY TRUE</tt>.</p><p>Text table source files are cached in memory. The maximum number
      of rows of data that are in memory at any time is controlled by the
      <tt class="literal">textdb.cache_scale </tt> property. The default value for
      <tt class="literal">textdb.cache_scale</tt> is 10 and can be changed by
      setting the property in the .properties file for the database. The
      number of rows in memory is calculated as 3*(2**scale), which translates
      to 3072 rows for the default textdb.cache_scale setting (10). The
      property can also be set for individual text tables:</p><pre class="programlisting">
    SET TABLE mytable SOURCE "myfile;ignore_first=true;all_quoted=true;cache_scale=12"</pre></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N11030"></a>Text File Issues</h2></div></div><div></div></div><div class="itemizedlist"><p class="title"><b>Text File Issues</b></p><ul type="disc"><li><p>File locations are restricted to below the directory that
        contains the database, unless the textdb.allow_full_path property is
        set true in the database properties file.</p></li><li><p>Blank lines are allowed anywhere in the text file, and are
        ignored.</p></li><li><p>The file location for a text table created with</p><pre class="programlisting">
    SELECT &lt;select list&gt; INTO TEXT &lt;tablename&gt; FROM</pre><p>is the directory that contains the database and the file name is
        based on the table name. The table name is converted into the file
        name by replacing all the non-alphanumeric characters with the
        underscore character, conversion into lowercase, and adding the ".csv"
        suffix.</p></li><li><p>From version 1.7.2 it is possible to define a primay key or
        identity column for text tables.</p></li><li><p>When a table source file is used with the<tt class="literal">
        ignore_first=true </tt>option, the first, ignored line is
        replaced with a blank line after a SHUTDOWN COMPACT.</p></li><li><p>An existing table source file may include CHARACTER fields that
        do not begin with the quote character but contain instances of the
        quote character. These fields are read as literal strings.
        Alternatively, if any field begins with the quote character, then it
        is interpreted as a quoted string that should end with the quote
        character and any instances of the quote character within the string
        is doubled. When any field containing the quote character or the
        separator is written out to the source file by the program, the field
        is enclosed in quote character and any instance of the quote character
        inside the field is doubled.</p></li><li><p>Inserts or updates of CHARACTER type field values are allowed
        with strings that contains the linefeed or the carriage return
        character. This feature is disabled when both quoted and all_quoted
        properties are false.</p></li></ul></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N11055"></a>Text File Global Properties</h2></div></div><div></div></div><div class="itemizedlist"><p class="title"><b>Complete list of supported global properties in *.properties
      files</b></p><ul type="disc"><li><p>
          <tt class="literal">textdb.fs</tt>
        </p></li><li><p>
          <tt class="literal">textdb.lvs</tt>
        </p></li><li><p>
          <tt class="literal">textdb.quoted</tt>
        </p></li><li><p>
          <tt class="literal">textdb.all_quoted</tt>
        </p></li><li><p>
          <tt class="literal">textdb.ignore_first</tt>
        </p></li><li><p>
          <tt class="literal">textdb.encoding</tt>
        </p></li><li><p>
          <tt class="literal">textdb.cache_scale</tt>
        </p></li><li><p>
          <tt class="literal">textdb.allow_full_path</tt>
        </p></li></ul></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N11093"></a>Importing a Text Table file in to a Traditional (non-Text Table)
    Table</h2></div></div><div></div></div><p>The directory <tt class="filename">src/org/hsqldb/sample</tt> in your
    HSQLDB distibution contains a file named
    <tt class="filename">load_binding_lu.sql</tt>. This is a working SQL file which
    imports a pipe-delimited text file from the database's file directory into
    an existing normal table. You can edit a copy of this file and use it
    directly with <a href="#sqltool-chapter" title="Chapter&nbsp;8.&nbsp;SqlTool">SqlTool</a>, or you can
    use the SQL therein as a model (using any SQL client at all).</p></div></div><div class="chapter" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="tls-chapter"></a>Chapter&nbsp;7.&nbsp;TLS</h2></div><div><h3 class="subtitle"><i>TLS Support (a.k.a. SSL)</i></h3></div><div><div class="authorgroup"><div class="author"><h3 class="author"><span class="firstname">Blaine</span> <span class="surname">Simpson</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:blaine.simpson@admc.com">blaine.simpson@admc.com</a>&gt;</tt></div></div></div><div><p class="pubdate">$Date: 2005/11/06 20:03:37 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N110D1">Requirements</a></span></dt><dt><span class="section"><a href="#N110EE">Encrypting your JDBC connection</a></span></dt><dd><dl><dt><span class="section"><a href="#N110F3">Client-Side</a></span></dt><dt><span class="section"><a href="#N1115E">Server-Side</a></span></dt></dl></dd><dt><span class="section"><a href="#jsse-section">JSSE</a></span></dt><dt><span class="section"><a href="#privatekey-section">Making a Private-key Keystore</a></span></dt><dd><dl><dt><span class="section"><a href="#N1119A">CA-Signed Cert</a></span></dt><dt><span class="section"><a href="#N111C3">Non-CA-Signed Cert</a></span></dt></dl></dd><dt><span class="section"><a href="#N111D0">Automatic Server or WebServer startup on UNIX</a></span></dt></dl></div><p>
        The instructions in this document are liable to change at any time.
        In particular, we will be changing the method to supply the server-side
        certificate password.
    </p><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N110D1"></a>Requirements</h2></div></div><div></div></div><div class="itemizedlist"><p class="title"><b>Hsqldb TLS Support Requirements</b></p><ul type="disc"><li><p>
                Sun Java 2.x and up.
                (This is probably possible with IBM's Java, but I don't think
                anybody has attempted to run HSQLDB with TLS under IBM's Java, 
                and I'm sure that nobody in the HSQLDB Development Group has
                documented how to set up the environment).
            </p></li><li><p>
                If Java 2.x or 3.x, then you will need need to
                <a href="#jsse-section" title="JSSE">install JSSE</a>.
                Your server and/or client will start up much slower than that 
                of Java 4.x users.
                Client-side users will not be able to use the https: JDBC 
                protocol (because the https protocol handler is not implemented 
                in 2.x/3.x Java JSSE;
                if there is demand, we could work around this).
            </p></li><li><p>
                A <a href="#privatekey-section" title="Making a Private-key Keystore">JKS keystore containing a 
                private key</a>, in order to run a server.
            </p></li><li><p>
                If you are running the server side, then you'll need to run a
                HSQLDB Server or WebServer.
                It doesn't matter if the underlying database instances are
                new, and it doesn't matter if you are making a new Server 
                configuration or encrypting an existing Server configuration.
                (You can turn encryption on and off at will).
            </p></li><li><p>
                You need a HSQLDB jar file that was built with JSSE present.
                If you got your HSQLDB 1.7.2 distribution from us, you are
                all set, because we build with Java 1.4 (which contains JSSE).
                If you build your own jar file with Java 1.3, make sure to
                install JSSE first.
            </p></li></ul></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N110EE"></a>Encrypting your JDBC connection</h2></div></div><div></div></div><p>
            At this time, only 1-way, server-cert encryption is tested.
        </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N110F3"></a>Client-Side</h3></div></div><div></div></div><p>
                Just use one of the following protocol prefixes.
            </p><div class="itemizedlist"><p class="title"><b>Hsqldb TLS URL Prefixes</b></p><ul type="disc"><li><p><tt class="literal">
                    jdbc:hsqldb:hsqls://
                </tt></p></li><li><p><tt class="literal">
                    jdbc:hsqldb:https://
                </tt></p></li></ul></div><p>
                At this time, the latter will only work for clients running 
                with Java 1.4.
            </p><p>
                If the server you wish to connect to is using a certificate 
                approved by your default trust keystores, then there is nothing 
                else to do.
                If not, then you need to tell Java to "trust" the server cert.
                (It's a slight over-simplification to say that if the server
                certificate was purchased, then you are all set;
                if somebody "signed their own" certificate by self-signing or
                using a private ca certificate, then you need to set up trust).
            </p><p>
                First, you need to obtain the cert (only the "public" part of 
                it).
                Since this cert is passed to all clients, you could obtain it 
                by writing a java client that dumps it to file, or perhaps by 
                using <span class="emphasis"><em>openssl s_client</em></span>.
                Since in most cases, if you want to trust a non-commercial 
                cert, you probably have access to the server keystore, I'll 
                show an example of how to get what you need from the 
                server-side JKS keystore.
            </p><p>
                    You may already have an X509 cert for your server.
                    If you have a server keystore, then you can generate a
                    X509 cert like this.
                <div class="example"><a name="N11110"></a><p class="title"><b>Example&nbsp;7.1.&nbsp;Exporting certificate from the server's keystore</b></p><pre class="screen">
    keytool -export -keystore server.store -alias existing_alias -file server.cer</pre></div>
                In this example, <tt class="filename">server.cer</tt> is the X509
                certificate that you need for the next step.
                </p><p>
                Now, you need to add this cert to one of the system trust 
                keystores or to a keystore of your own.
                See <a href="http://java.sun.com/j2se/1.4.2/docs/guide/security/jsse/JSSERefGuide.html#CustomizingStores" target="_top">
                the Customizing Stores section in JSSERefGuide.html</a> to 
                see where your system trust keystores are.
                You can put private keystores anywhere you want to.
                The following command will add the cert to an existing 
                keystore, or create a new keystore if 
                <tt class="filename">client.store</tt> doesn't exist.
            </p><div class="example"><a name="N11125"></a><p class="title"><b>Example&nbsp;7.2.&nbsp;Adding a certificate to the client keystore</b></p><pre class="screen">
keytool -import -trustcacerts -keystore trust.store -alias new_alias -file server.cer</pre></div><p>
                If you are making a new keystore, you probably want to start
                with a copy of your system default keystore which you can
                find somewhere under your JAVA_HOME directory (typically
                jre/lib/security/cacerts for a JDK, but I forget exactly
                where it is for a JRE).
            </p><p>
                Unless your OS can't stop other people from writing to your 
                files, you probably do not want to set a password on the trust 
                keystore.
            </p><p>
                If you added the cert to a system trust store, then you are 
                finished.
                Otherwise you will need to specify your custom trust keystore
                to your client program.
                The generic way to set the trust keystore is to set the sytem 
                property
                <tt class="classname">javax.net.ssl.trustStore</tt> every time that 
                you run your client program.
                For example
                <div class="example"><a name="N11134"></a><p class="title"><b>Example&nbsp;7.3.&nbsp;Specifying your own trust store to a JDBC client</b></p><pre class="screen">
    java -Djavax.net.ssl.trustStore=/home/blaine/trust.store -jar /path/to/hsqldb.jar dest-urlid</pre></div>
                This example runs the program
                <a href="#unix-chapter" title="Chapter&nbsp;3.&nbsp;UNIX Quick Start">SqlTool</a>.
                SqlTool has built-in TLS support, however, so, for SqlTool
                you can set <tt class="literal">truststore</tt> on a per-urlid
                basis in the SqlTool configuration file.
            </p><p>
                N.b.  The hostname in your database URL must match the 
                <span class="emphasis"><em>Common Name</em></span> of the server's certificate 
                exactly.
                That means that if a site certificate is 
                <tt class="literal">admc.com</tt>, you can not use
                <tt class="literal">jdbc:hsqldb:hsqls://localhost</tt> or
                <tt class="literal">jdbc:hsqldb:hsqls://www.admc.com:1100</tt> to 
                connect to it.
            </p><p>
                If you want more details on anything, see JSSERefGuide.html on
                <a href="http://java.sun.com/j2se/1.4.2/docs/guide/security/jsse/JSSERefGuide.html" target="_top">
                Sun's site</a>, or in the subdirectory 
                <tt class="filename">docs/guide/security/jsse</tt> of your Java SE 
                docs.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1115E"></a>Server-Side</h3></div></div><div></div></div><p>
                
                Get yourself a <a href="#privatekey-section" title="Making a Private-key Keystore">JKS keystore 
                containing a private key</a>.
                Then set the system property javax.net.ssl.keyStore to the path 
                to that file, and
                <tt class="classname">javax.net.ssl.keyStorePassword</tt> to the 
                password of the keystore (and to the private key-- they have 
                to be the same).
            </p><div class="example"><a name="N1116A"></a><p class="title"><b>Example&nbsp;7.4.&nbsp;Running an Hsqldb server with TLS encryption</b></p><pre class="screen">
    java -Djavax.net.ssl.keyStorePassword=secret  \
        -Djavax.net.ssl.keyStore=/usr/hsqldb/db/db3/server.store  \
        -cp /path/to/hsqldb.jar org.hsqldb.Server</pre></div><p>
                (This is a single command that I have broken into 2 lines using
                my shell's \ line-continuation feature.
                In this example, I'm using a server.properties file so that I
                don't need to give arguments to specify database instances or
                the server endpoint).
            </p><div class="caution" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title"><a name="tlspassword-caution"></a>Caution</h3><p>
                Specifying a password on the command-line is definitely
                <span class="bold"><b>not secure</b></span>.
                It's really only appropriate when untrusted users do not have 
                any access to your computer.
            </p></div><p>
                If there is any user demand, we will have a more secure way to 
                supply the password before long.
            </p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="jsse-section"></a>JSSE</h2></div></div><div></div></div><p>
            If you are running Java 4.x, then you are all set.
            Java 1.x users, you are on your own (Sun does not provide a JSSE 
            that will work with 1.x).
            Java 2.x and 3.x users continue...
        </p><p>
            Go to
            <a href="http://java.sun.com/products/jsse/index-103.html" target="_top">http://java.sun.com/products/jsse/index-103.html</a>.
            If you agree to the terms and meet the requirements, download the 
            domestic or global JSSE software.
            All you need from the software distro is the three jar files.
            If you have a JDK installation, then move the 3 jar files into the 
            directory <tt class="filename">$JAVA_HOME/jre/lib/ext</tt>.
            If you have a JRE installation, then move the 3 jar files into the 
            directory <tt class="filename">$JAVA_HOME/lib/ext</tt>.
        </p><p>
            Pretty painless.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="privatekey-section"></a>Making a Private-key Keystore</h2></div></div><div></div></div><p>
            There are two main ways to do this.
            Either you can use a certificate signed by a certificate authority,
            or you can make your own.
            One thing that you need to know in both cases is, the 
            <span class="emphasis"><em>Common Name</em></span> of the cert has to be the exact 
            hostname that JDBC clients will use in their database URL.
        </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1119A"></a>CA-Signed Cert</h3></div></div><div></div></div><p>
                I'm not going to tell you how to get a CA-signed SSL 
                certificate.
                That is well documented at many other places.
            </p><p>
                Assuming that you have a standard pem-style private key 
                certificate, here's how you can use
                <a href="http://www.openssl.org" target="_top">openssl</a> and the 
                program <tt class="classname">DERImport</tt> to get it into a JKS 
                keystore.
            </p><p>
                Because I have spent a lot of time on this document already, I 
                am just giving you an example.
            </p><div class="example"><a name="N111AA"></a><p class="title"><b>Example&nbsp;7.5.&nbsp;Getting a pem-style private key into a JKS keystore</b></p><pre class="screen">
openssl pkcs8 -topk8 -outform DER -in Xpvk.pem -inform PEM -out Xpvk.pk8 -nocrypt

openssl x509 -in Xcert.pem -out Xcert.der -outform DER

java DERImport new.keystore NEWALIAS Xpvk.pk8 Xcert.der</pre></div><div class="important" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Important</h3><p>
                Make sure to set the password of the key exactly the same as 
                the password for the keystore!
            </p></div><p>
                You need the program <tt class="filename">DERImport.class</tt> of 
                course.
                Do some internet searches to find
                <tt class="filename">DERImport.java</tt> or
                <tt class="filename">DERImport.class</tt> and download it.
            </p><p>
                If DERImport has become difficult to obtain, I can write a 
                program to do the same thing-- just let me know.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N111C3"></a>Non-CA-Signed Cert</h3></div></div><div></div></div><p>
                Run <tt class="literal">man keytool</tt> or see
                <a href="http://java.sun.com/j2se/1.4.2/docs/guide/security/jsse/JSSERefGuide.html#CreateKeystore" target="_top">
                the Creating a Keystore section of JSSERefGuide.html</a>.
            </p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N111D0"></a>Automatic Server or WebServer startup on UNIX</h2></div></div><div></div></div><p>
            If you are on UNIX and want to automatically start and stop a
            Server or WebServer running with encryption, follow the 
            instructions in the
            <a href="#unix-chapter" title="Chapter&nbsp;3.&nbsp;UNIX Quick Start">UNIX Quick Start</a> chapter, and
            remember to make the init script configuration file readable only
            to root and to set the variables
            <tt class="literal">TLS_PASSWORD</tt> and <tt class="literal">TLS_KEYSTORE</tt>.
        </p><p>
            If you are using a private server certificate, make sure to also
            set the trust store filepath as shown in the sample init script 
            configuration file.
        </p><p>
            The <a href="#tlspassword-caution">cautionary warning
            above</a> still applies.
            The password will be visible to any minimally competent local
            UNIX user who wants to see it.
        </p></div></div><div class="chapter" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="sqltool-chapter"></a>Chapter&nbsp;8.&nbsp;SqlTool</h2></div><div><h3 class="subtitle"><i>SqlTool Manual</i></h3></div><div><div class="authorgroup"><div class="author"><h3 class="author"><span class="firstname">Blaine</span> <span class="surname">Simpson</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:blaine.simpson@admc.com">blaine.simpson@admc.com</a>&gt;</tt></div><div class="author"><h3 class="author"><span class="firstname">Dan</span> <span class="surname">Shinton</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:dan@shinton.net">dan@shinton.net</a>&gt;</tt></div></div></div><div><p class="pubdate">$Date: 2006/03/16 22:47:19 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N11219">Purpose</a></span></dt><dd><dl><dt><span class="section"><a href="#N11222">Recent changes</a></span></dt></dl></dd><dt><span class="section"><a href="#baremin-section">The Bare Minimum</a></span></dt><dd><dl><dt><span class="section"><a href="#N112DD">Non-displayable Types</a></span></dt><dt><span class="section"><a href="#N11302">Desktop shortcuts</a></span></dt><dt><span class="section"><a href="#N11380">Loading sample data</a></span></dt></dl></dd><dt><span class="section"><a href="#auth-section">RC File Authentication Setup</a></span></dt><dt><span class="section"><a href="#ilauth-section">Using Inline RC Authentication</a></span></dt><dt><span class="section"><a href="#N11461">
            Using the current version of SqlTool with an older HSQLDB
            distribution.
        </a></span></dt><dt><span class="section"><a href="#int-section">Interactive</a></span></dt><dd><dl><dt><span class="section"><a href="#N114E7">Command Types</a></span></dt><dt><span class="section"><a href="#N11538">Special Commands</a></span></dt><dt><span class="section"><a href="#N115E6">Buffer Commands</a></span></dt><dt><span class="section"><a href="#interactive_pl_commands-section">PL Commands</a></span></dt><dt><span class="section"><a href="#binary_files-section">
                Storing and retrieving binary files</a></span></dt><dt><span class="section"><a href="#N1170A">SQL History</a></span></dt><dt><span class="section"><a href="#N11719">Shell scripting and command-line piping</a></span></dt><dt><span class="section"><a href="#N11722">Emulating Non-Interactive mode</a></span></dt></dl></dd><dt><span class="section"><a href="#nonint-section">Non-Interactive</a></span></dt><dd><dl><dt><span class="section"><a href="#sqlswitch-section">Giving SQL on the Command Line</a></span></dt><dt><span class="section"><a href="#N1177D">SQL Files</a></span></dt><dt><span class="section"><a href="#scripting-section">Piping and shell scripting</a></span></dt><dt><span class="section"><a href="#N117E5">Optimally Compatible SQL Files</a></span></dt><dt><span class="section"><a href="#N117F8">Comments</a></span></dt><dt><span class="section"><a href="#N1181B">Special Commands and Buffer Commands in SQL Files</a></span></dt><dt><span class="section"><a href="#N11880">Automation</a></span></dt><dt><span class="section"><a href="#N1188B">Getting Interactive Functionality with SQL Files</a></span></dt><dt><span class="section"><a href="#charencoding-section">
                Character Encoding</a></span></dt></dl></dd><dt><span class="section"><a href="#report-section">Generating Text or HTML Reports</a></span></dt><dt><span class="section"><a href="#pl-section">SqlTool Procedural Language</a></span></dt><dd><dl><dt><span class="section"><a href="#N11915">Variables</a></span></dt><dt><span class="section"><a href="#pl_alias-section">PL Aliases</a></span></dt><dt><span class="section"><a href="#N11993">Logical Expressions</a></span></dt><dt><span class="section"><a href="#N11A0C">Flow Control</a></span></dt></dl></dd><dt><span class="section"><a href="#chunk-section">Chunking</a></span></dt><dd><dl><dt><span class="section"><a href="#N11A6A">Why?</a></span></dt><dt><span class="section"><a href="#N11A71">How?</a></span></dt></dl></dd><dt><span class="section"><a href="#raw-section">Raw Mode</a></span></dt><dt><span class="section"><a href="#N11A9E">PL/SQL</a></span></dt><dt><span class="section"><a href="#N11ABF">Using hsqltool.jar and hsqldbutil.jar</a></span></dt><dt><span class="section"><a href="#N11B18">Character-Separated-Value Imports and Exports</a></span></dt><dd><dl><dt><span class="section"><a href="#N11B36">Simple CSV exports and imports using default settings</a></span></dt><dt><span class="section"><a href="#N11B7B">Specifying queries, delimiters, file names, table names,
                columns</a></span></dt></dl></dd></dl></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N11219"></a>Purpose</h2></div></div><div></div></div><p>
            This document explains how to use SqlTool, the main purpose of
            which is to read your SQL text file or stdin, and execute the SQL 
            commands therein against a JDBC database.
            There are also a great number of features to facilitate both
            interactive use (such as command-line editing and PL aliases)
            and automation (such as scripting variables and SQL transaction 
            control and error handling).
        </p><p>
            Some of the examples below use quoting which works exactly
            as-is for any Bourne-compatible UNIX shell.
            (Only line-continuation would need to be changed for C-compatible
            UNIX shells).
            I have not yet tested these commands on Windows, and I doubt
            whether the quoting will work just like this (though it is
            possible).
            SqlTool is still a very useful tool even if you have no quoting
            capability at all.
        </p><p>
            If you are using SqlTool from a HSQDLB distribution before
            version 1.8.0.0 final, you should use the documentation with that
            distribution
            (because, for brevity, I do not here indicate changes made to
            behavior before 1.8.0.0 final).
            This document is now updated for the current versions of SqlTool
            and SqlFile at the time I am writing this (versions 1.50 and
            1.130 correspondingly, SqlFile is the class which does most of the
            work for SqlTool).
            Therefore, if you are using a version of SqlTool or SqlFile that
            is more than a couple revisions greater, you should find a newer
            version of this document.
            (The imprecision is due to content-independent revision increments
            at build time, and the likelihood of one or two 
            behavior-independent bug fixes after public releases).
            The startup banner will report both versions when you run SqlTool
            interactively.
        </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11222"></a>Recent changes</h3></div></div><div></div></div><p>This section lists changes to SqlTool since the last
                major release of HSQLDB.
                For this revision of this document, this list consists of
                significant changes made to SqlTool AFTER the final 1.8.0.0
                HSQLDB release.
            </p><div class="itemizedlist"><ul type="disc"><li>
                    Fixed bug where PL "end" command was still requiring old 
                    syntax (wrt white space).
                    Fixed for HSQLDB v. 1.8.0.2.
                </li><li>
                    Fixed NPE sometimes encountered when fetching null 
                    Timestamp values.
                    Fixed for HSQLDB v. 1.8.0.2.
                </li><li>
                    Implemented new \dr command for HSQLDB and Sybase servers.
                    Implemented \du for Sybase.
                    Added for HSQLDB v. 1.8.0.3.
                </li><li>
                    Implemented CSV eXport and iMport commands \x and \m.
                    Added for HSQLDB v. 1.8.0.3.
                </li><li>
                    Implemented method for specifying RC file parameters as a
                    command-line switch. Modified SqlTool to now accepts case
                    insensitive command-line switches. Added for HSQLDB v. 1.8.1.
                </li></ul></div><p>
                When recently changed or added features (i.e, those items
                in the preceding list) are described in the main document 
                below, there is a <span class="emphasis"><em>Note</em></span> at that point
                indicating when the feature was added or changed.
            </p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="baremin-section"></a>The Bare Minimum You Need to Know to Run SqlTool</h2></div></div><div></div></div><div class="warning" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Warning</h3><p>
            If you are using an Oracle database server, it will commit your
            current transaction if you cleanly disconnect, regardless of
            whether you have set auto-commit or not.
            This will occur if you exit SqlTool (or any other client) in
            the normal way (as opposed to killing the process or using
            Ctrl-C, etc.).
            This is mentioned in this section only for brevity, so I don't
            need to mention it in the main text in the many places where
            auto-commit is discussed.
            This behavior has nothing to do with SqlTool.
            It is a quirk of Oracle.
        </p></div><p>
            If you want to use SqlTool, then you either have an SQL text file, 
            or you want to interactively type in SQL commands.
            If neither case applies to you, then you are looking at the wrong 
            program.
        </p><div class="procedure"><p class="title"><b>Procedure&nbsp;8.1.&nbsp;To run SqlTool...</b></p><ol type="1"><li><p>
                    Copy the file <tt class="filename">sqltool.rc</tt> from the
                    directory <tt class="filename">src/org/hsqldb/sample</tt> of 
                    your HSQLDB distribution
                    to your home directory and
                    secure access to it if your home directory is accessible
                    to anybody else.
                    This file will work as-is for a Memory Only database
                    instance; or if your target is a HSQLDB Server 
                    running on your local computer with default settings
                    and the password for the "sa" account is blank
                    (the sa password is blank when new HSQLDB database 
                    instances are created).
                    Edit the file if you need to change the target Server URL, 
                    username, password, character set, JDBC driver, or TLS 
                    trust store as documented in the 
                    <a href="#auth-section" title="RC File Authentication Setup">RC File Authentication Setup</a>
                    section.</p><p><span class="bold"><b>OR</b></span></p><p>Use the <tt class="literal">--inlineRc</tt> command-line
                    switch to specify your connection parameters as documented
                    in the <a href="#ilauth-section" title="Using Inline RC Authentication">Using Inline RC Authentication</a>
                    section.
                </p></li><li><p>
                    Find out where your hsqldb.jar file resides.
                    It typically resides at
<span class="bold"><b>HSQLDB_HOME</b></span><tt class="filename">/lib/hsqldb.jar</tt>
                    where <span class="bold"><b>HSQLDB_HOME</b></span> is the
                    base directory of your HSQLDB software installation.
                    For this reason, I'm going to use 
                    "$HSQLDB_HOME/lib/hsqldb.jar" as the path to
                    <tt class="filename">hsqldb.jar</tt> for my examples, but 
                    understand that you need to use the actual path to your
                    own <tt class="filename">hsqldb.jar</tt> file.
                </p></li><li><p>
                    Run 
                <div class="informalexample"><pre class="screen">
    java -jar $HSQLDB_HOME/lib/hsqldb.jar --help</pre></div>
                    to see what command-line arguments are available.
                    Note that you don't need to worry about setting the 
                    CLASSPATH when you use the <tt class="literal">-jar</tt> switch
                    to <tt class="filename">java</tt>.
                    Assuming that you set up your SqlTool RC file 
                    at the default location and you want to use the HSQLDB 
                    JDBC driver, you will want to run something like
                <div class="informalexample"><pre class="screen">
    java -jar $HSQLDB_HOME/lib/hsqldb.jar mem</pre></div>
                    for interactive use, or
                <div class="informalexample"><pre class="screen">
    java -jar $HSQLDB_HOME/lib/hsqldb.jar --sql 'SQL statement' mem</pre></div>
                    or
                    <div class="informalexample"><pre class="screen">
    java -jar $HSQLDB_HOME/lib/hsqldb.jar mem filepath1.sql...</pre></div>
                    where <tt class="literal">mem</tt> is an
                    <span class="emphasis"><em>urlid</em></span>,
                    and the following arguments are paths to text SQL files.
                    For the filepaths, you can use whatever wildcards your 
                    operating system shell supports.
                    </p><p>
                    The <span class="emphasis"><em>urlid</em></span> <tt class="literal">mem
                    </tt>in these commands is a key 
                    into your RC file, as explained in the 
                    <a href="#auth-section" title="RC File Authentication Setup">RC File Authentication Setup</a> section.
                    Since this is a Memory Only database, you can use SqlTool
                    with this urlid immediately with no database setup 
                    whatsoever (however, you can't persist any changes that 
                    you make to this database).
                    The sample sqltool.rc file also defines the urlid
                    "localhost-sa" for a local HSQLDB Server.
                    At the end of this section, I explain how you can load
                    some sample data to play with, if you want to.
                </p></li></ol></div><div class="important" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Important</h3><p>
            SqlTool does not <span class="emphasis"><em>commit</em></span> DML changes by default.
            This leaves it to the user's disgression whether to commit or
            rollback their modifications.
            Remember to either run the command <tt class="literal">commit;</tt>
            before quitting SqlTool, or use the <tt class="literal">--autoCommit</tt>
            command-line switch.
        </p></div><p>
            If you put a file named <tt class="filename">auto.sql</tt> into your
            home directory, this file will be executed automatically every
            time that you run SqlTool interactively and without the
            <tt class="literal">--noAutoFile</tt> switch.
        </p><p>
            To use a JDBC Driver other than the HSQLDB driver, you can't use
            the <tt class="literal">-jar</tt> switch because you need to modify the
            classpath.
            You must add the hsqldb.jar file and your JDBC driver classes to
            your classpath,
            and you must tell SqlTool what the JDBC driver class name is.
            The latter can be accomplished by either using the "--driver" 
            switch, or setting "driver" in your config file.
            The <a href="#auth-section" title="RC File Authentication Setup">RC File Authentication Setup</a> section.
            explains the second method.  Here's an example of the first method
            (after you have set the classpath appropriately).
        <div class="informalexample"><pre class="screen">
java org.hsqldb.util.SqlTool --driver oracle.jdbc.OracleDriver urlid</pre></div></p><div class="tip" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Tip</h3><p>
            If the tables of query output on your screen are all messy 
            because of lines wrapping, the best and easiest solution
            is usually to resize your terminal emulator window to make it
            wider.
            (With some terms you click &amp; drag the frame edges to resize,
            with others you use a menu system where you can enter the number
            of columns).
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N112DD"></a>Non-displayable Types</h3></div></div><div></div></div><p>
            There are many SQL types which SqlTool (being a text-based
            program) can't display properly.
            This includes the SQL types <tt class="literal">BLOB</tt>,
            <tt class="literal">JAVA_OBJECT</tt>, <tt class="literal">STRUCT</tt>,
            and <tt class="literal">OTHER</tt>.
            When you run a query that returns any of these, SqlTool will
            save the very first such value obtained to the binary buffer
            and will not display any output from this query.
            You can then save the binary value to a file, as explained in the
          <a href="#binary_files-section" title="

                Storing and retrieving binary files">
                Storing and retrieving binary files</a>
            section.
            </p><p>
            There are other types, such as <tt class="literal">BINARY</tt>, which
            JDBC can make displayable (by using ResultSet.getString()), but 
            which you may very well want to retrieve in raw binary format.
            You can use the \b command to retrieve any-column-type-at-all
            in raw binary format (so you can later store the value to a
            binary file).
            </p><p>
            Another restriction which all text-based database clients have
            is the practical inability for the user to type in binary data 
            such as photos, audio streams, and serialized Java objects.
            You can use SqlTool to load any binary object into a database
            by telling SqlTool to get the insert/update datum from a file.
            This is also explained in the
          <a href="#binary_files-section" title="

                Storing and retrieving binary files">
                Storing and retrieving binary files</a>
            section.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11302"></a>Desktop shortcuts</h3></div></div><div></div></div><p>
                Desktop shortcuts and quick launch icons are useful, especially 
                if you often run SqlTool with the same set of arguments.
                It's really easy to set up several of them-- one for each 
                way that you invoke SqlTool (i.e., each one would start
                SqlTool with all the arguments for one of your typical startup
                needs).
                One typical setup is to have one shortcut for each database 
                account which you normally use (use a different
                <tt class="literal">--urlid</tt> switch in each shortcut's
                <span class="guilabel">Target</span> specification.
            </p><p>
                Desktop icon setup varies depending on your Desktop manager,
                of course.
                I'll explain how to set up a SqlTool startup icon in Windows
                XP.
                Linux and Mac users should be able to take it from there, since
                it's easier with the common Linux and Mac desktops.
            </p><div class="procedure"><p class="title"><b>Procedure&nbsp;8.2.&nbsp;Creating a Desktop Shortcut for SqlTool</b></p><ol type="1"><li><p>
                    Right click in the main Windows background.
                </p></li><li><p>
                    <span class="guimenuitem">New</span>
                </p></li><li><p>
                    <span class="guimenuitem">Shortcut</span>
                </p></li><li><p>
                    <span class="guibutton">Browse</span>
                </p></li><li><p>
                    Navigate to where your good JRE lives.  For recent Sun
                    JRE's, it installs to 
                    <tt class="filename">C:\Program Files\Java\*\bin</tt>
                    by default (the * will be a JDK or JRE name and version 
                    number).
                </p></li><li><p>
                    Select <tt class="filename">java.exe</tt>.
                </p></li><li><p>
                    <span class="guibutton">OK</span>
                </p></li><li><p>
                    <span class="guimenuitem">Next</span>
                </p></li><li><p>
                    Enter any name
                </p></li><li><p>
                    <span class="guimenuitem">Finish</span>
                </p></li><li><p>
                    Right click the new icon.
                </p></li><li><p>
                    <span class="guimenuitem">Properties</span>
                </p></li><li><p>
                    Edit the <span class="guilabel">Target</span> field.
                </p></li><li><p>
                    Leave the path to java.exe exactly as it is, including the 
                    quotes, but append to what is there.
                    Beginning with a space, enter the command-line that you
                    want run.
                </p></li><li><p>
                    <span class="guibutton">Change Icon...</span> to a pretty icon.
                </p></li><li><p>
                    If you want a quick-launch icon instead of (or in addition 
                    to) a desktop shortcut icon, click and drag it to your 
                    quick launch bar.  (You may or may not need to edit the
                    Windows Toolbar properties to let you add new items).
                </p></li></ol></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11380"></a>Loading sample data</h3></div></div><div></div></div><p>
                If you want some sample database objects and data to play 
                with, execute the <tt class="filename">sampledata.sql</tt> SQL 
                file.
                <tt class="filename">sampledata.sql</tt> resides in the
                <tt class="filename">src/org/hsqldb/sample</tt> directory of your
                HSQLDB distribution.
                Run it like this from an SqlTool session
    <pre class="programlisting">\i HSQLDB_HOME/src/org/hsqldb/sample/sampledata.sql</pre>
                where <span class="bold"><b>HSQLDB_HOME</b></span> is the
                base directory of your HSQLDB software installation.
            </p><p>
                For memory-only databases, you'll need to run this every 
                time that you run SqlTool.
                For other (persistent) databases, the data will reside in 
                your database until you drop the tables.
            </p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="auth-section"></a>RC File Authentication Setup</h2></div></div><div></div></div><p>
            RC file authentication setup is accomplished by creating a text
            RC configuration file.
            In this section, when I say <span class="emphasis"><em>configuration</em></span>
            or <span class="emphasis"><em>config</em></span> file, I mean an RC configuration 
            file.
            RC files can be used by any JDBC client program that uses the
            org.hsqldb.util.RCData class-- this includes
            SqlTool, DatabaseManager, DatabaseManagerSwing.
            You can use it for your own JDBC client programs too.
        </p><p>
            The following sample RC file resides at 
            <tt class="filename">src/org/hsqldb/sample/sqltool.rc</tt> in your
            HSQLDB distribution.
        </p><div class="example"><a name="N113AE"></a><p class="title"><b>Example&nbsp;8.1.&nbsp;Sample RC File</b></p><pre class="programlisting"># $Id: sqltool.rc,v 1.17 2005/11/06 18:01:49 unsaved Exp $

# This is a sample RC configuration file used by SqlTool, DatabaseManager,
# and any other program that uses the org.hsqldb.util.RCData class.

# You can run SqlTool right now by copying this file to your home directory
# and running
#    java -jar /path/to/hsqldb.jar mem
# This will access the first urlid definition below in order to use a 
# personal Memory-Only database.

# If you have the least concerns about security, then secure access to
# your RC file.
# See the documentation for SqlTool for various ways to use this file.

# A personal Memory-Only database.
urlid mem
url jdbc:hsqldb:mem:memdbid
username sa
password

# This is for a hsqldb Server running with default settings on your local
# computer (and for which you have not changed the password for "sa").
urlid localhost-sa
url jdbc:hsqldb:hsql://localhost
username sa
password



# Template for a urlid for an Oracle database.
# You will need to put the oracle.jdbc.OracleDriver class into your 
# classpath.
# In the great majority of cases, you want to use the file classes12.zip
# (which you can get from the directory $ORACLE_HOME/jdbc/lib of any
# Oracle installation compatible with your server).
# Since you need to add to the classpath, you can't invoke SqlTool with
# the jar switch, like "java -jar .../hsqldb.jar..." or 
# "java -jar .../hsqlsqltool.jar...".
# Put both the HSQLDB jar and classes12.zip in your classpath (and export!)
# and run something like "java org.hsqldb.util.SqlTool...".

#urlid cardiff2
#url jdbc:oracle:thin:@aegir.admc.com:1522:TRAFFIC_SID
#username blaine
#password secretpassword
#driver oracle.jdbc.OracleDriver



# Template for a TLS-encrypted HSQLDB Server.
# Remember that the hostname in hsqls (and https) JDBC URLs must match the
# CN of the server certificate (the port and instance alias that follows 
# are not part of the certificate at all).
# You only need to set "truststore" if the server cert is not approved by
# your system default truststore (which a commercial certificate probably
# would be).

#urlid tls
#url jdbc:hsqldb:hsqls://db.admc.com:9001/lm2
#username blaine
#password asecret
#truststore /home/blaine/ca/db/db-trust.store


# Template for a Postgresql database
#urlid blainedb
#url jdbc:postgresql://idun.africawork.org/blainedb
#username blaine
#password losung1
#driver org.postgresql.Driver

# Template for a MySQL database.  MySQL has poor JDBC support.
#urlid mysql-testdb
#url jdbc:mysql://hostname:3306/dbname
#username root
#username blaine
#password hiddenpwd
#driver com.mysql.jdbc.Driver

# Note that "databases" in SQL Server and Sybase are traditionally used for
# the same purpose as "schemas" with more SQL-compliant databases.

# Template for a Microsoft SQL Server database
url jdbc:microsoft:sqlserver://hostname;DatabaseName=DbName;SelectMethod=Cursor
# The SelectMethod setting is required to do more than one thing on a JDBC
# session (I guess Microsoft thought nobody would really use Java for 
# anything other than a "hello world" program).
# This is for Microsoft's SQL Server 2000 driver (requires mssqlserver.jar
# and msutil.jar).
driver com.microsoft.jdbc.sqlserver.SQLServerDriver
username myuser
password hiddenpwd

# Template for a Sybase database
urlid sybase
url jdbc:sybase:Tds:hostname:4100/dbname
username blaine
password hiddenpwd
# This is for the jConnect driver (requires jconn3.jar).
driver com.sybase.jdbc3.jdbc.SybDriver
</pre></div><p>
            You can put this file anywhere you want to, and specify the 
            location to SqlTool/DatabaseManager/DatabaseManagerSwing by
            using the <tt class="literal">--rcfile</tt> argument.
            If there is no reason to not use the default location (and there 
            are situations where you would not want to), then use the default
            location and you won't have to give <tt class="literal">--rcfile</tt>
            arguments to SqlTool/DatabaseManager/DatabaseManagerSwing.
            The default location is <tt class="filename">sqltool.rc</tt> or
            <tt class="filename">dbmanager.rc</tt> in your home directory
            (corresponding to the program using it).
            If you have any doubt about where your home directory is, just 
            run SqlTool with a phony urlid and it will tell you where it 
            expects the configuration file to be.
        <div class="informalexample"><pre class="screen">
    java -jar $HSQLDB_HOME/lib/hsqldb.jar x</pre></div></p><p>
            The config file consists of stanza(s) like this:
        <div class="informalexample"><pre class="screen">
    urlid web
    url jdbc:hsqldb:hsql://localhost
    username web
    password webspassword</pre></div></p><p>
            These four settings are required for every urlid.
            (There are optional settings also, which are described a couple 
            paragraphs down).
            You can have as many blank lines and comments like
        <div class="informalexample"><pre class="screen">
    # This comment</pre></div>
        </p><p>
            in the file as you like.
            The whole point is that the <span class="emphasis"><em>urlid</em></span> that you 
            give in your SqlTool/DatabaseManager command must match a 
            <span class="emphasis"><em>urlid </em></span> in your configuration file.
        </p><div class="important" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Important</h3><p>
            Use whatever facilities are at  your disposal to protect your 
            configuration file.
        </p></div><p>
            It should be readable, both locally and remotely, only to users 
            who run programs that need it.
            On UNIX, this is easily accomplished by using <tt class="literal">chmod/chown
            </tt> commands and making sure that it is protected from 
            anonymous remote access (like via NFS, FTP or Samba).
        </p><p>
            You can also put the following optional settings into a urlid 
            stanza.  The setting will, of course, only apply to that urlid.
        </p><div class="variablelist"><dl><dt><span class="term">charset</span></dt><dd>
                This is used by the SqlTool program, but not by the
                DatabaseManager programs.
                See the <a href="#charencoding-section" title="

                Character Encoding">
                Character Encoding</a> section of the
                <a href="#nonint-section" title="Non-Interactive">Non-Interactive</a>
                section.
                You can, alternatively, set this for one SqlTool invocation 
                by setting the system property <span class="property">sqlfile.charset
                </span>.
                Defaults to <tt class="literal">US-ASCII</tt>.
            </dd><dt><span class="term">driver</span></dt><dd>
                Sets the JDBC driver class name.
                You can, alternatively, set this for one 
                SqlTool/DatabaseManager invocation by using the command 
                line switch <span class="emphasis"><em>--driver</em></span>.
                Defaults to <span class="emphasis"><em>org.hsqldb.jdbcDriver</em></span>.
            </dd><dt><span class="term">truststore</span></dt><dd>
                TLS trust keystore store file path as documented in the
                <a href="#tls-chapter" title="Chapter&nbsp;7.&nbsp;TLS">TLS</a> chapter.
                You usually only need to set this if the server is using a
                non-publicly-certified certificate (like a self-signed 
                self-ca'd cert).
            </dd></dl></div><p>
            Property and SqlTool command-line switches override settings made 
            in the configuration file.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="ilauth-section"></a>Using Inline RC Authentication</h2></div></div><div></div></div><p>
            Inline RC authentication setup is accomplished by using the
            <tt class="literal">--inlineRc</tt> command-line switch on SqlTool.
            The <tt class="literal">--inlineRc</tt> command-line switch takes 
            two required (URL and USER) and three optional arguments
            seperated by commas.
        </p><div class="variablelist"><dl><dt><span class="term"><tt class="literal">URL</tt></span></dt><dd>
                The JDBC URL of the database you wish to connect to.
            </dd><dt><span class="term"><tt class="literal">USER</tt></span></dt><dd>
                The username to connect to the database as.
            </dd><dt><span class="term"><tt class="literal">DRIVER</tt></span></dt><dd>
                The JDBC driver class name. Defaults to
                <span class="emphasis"><em>org.hsqldb.jdbcDriver</em></span>.
            </dd><dt><span class="term"><tt class="literal">CHARSET</tt></span></dt><dd>
                Sets the character encoding. Defaults to <tt class="literal">US-ASCII</tt>.
            </dd><dt><span class="term"><tt class="literal">TRUST</tt></span></dt><dd>
                The TLS trust keystore file path as documented in the TLS chapter.
            </dd></dl></div><p>
            Here is an example of invoking SqlTool to connect to a standalone database.
            <div class="informalexample"><pre class="screen">
    java -jar $HSQLDB_HOME/lib/hsqldb.jar
         --inlineRc URL=jdbc:hsqldb:file:/home/dan/dandb,USER=dan</pre></div>
        </p><p>
            For security reasons, you cannot specify the password as an argument. You
            will be prompted for a password as part of the login process.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N11461"></a>
            Using the current version of SqlTool with an older HSQLDB
            distribution.
        </h2></div></div><div></div></div><p>This procedure will allow users of a legacy version of
            HSQLDB to use all of the new features of SqlTool.
            You will also get the new versions of the DatabaseManagers!
            This procedure works for distros going back to 1.7.3.3 at least,
            probably much farther.
        </p><p>
            These instructions assume that you are capable of running an Ant
            build. 
            See the
            <a href="#building-appendix" title="Appendix&nbsp;A.&nbsp;Building HSQLDB">Building HSQLDB</a>
            chapter.
        </p><div class="procedure"><ol type="1"><li><p>
                Download and extract a current HSQLDB distribution.
                If you don't want to use the source code, documentation,
                etc., you can use a temporary directory and remove it
                afterwards.
            </p></li><li><p>
                Cd to the build directory under the root directory where
                you extracted the distribution to.
            </p></li><li><p>
                Run <tt class="literal">ant hsqldbutil</tt>.
                Do not run <tt class="literal">ant hsqltool</tt>, because 
                hsqlbutil.jar files contain the HSQLDB JDBC driver, and you 
                can not use a newer JDBC driver with an older HSQLDB database.
            </p></li><li><p>
                If you're going to wipe out the build directory, copy
                <tt class="filename">hsqldbutil.jar</tt> to a safe location first.
            </p></li><li><p>
                For now on, whenver you are going to run SqlTool, make sure
                that you have this <tt class="filename">hsqldbutil.jar</tt> as
                the first item in your CLASSPATH.
                You can't run SqlTool with the "-jar" switch (because the
                -jar switch doesn't permit setting your own class path).
            </p></li></ol></div><p>
            Here's a UNIX example where somebody wants to use the new SqlTool
            with their older HSQLDB database, as well as with Postgresql
            and a local application.
            <div class="informalexample"><pre class="screen">
CLASSPATH=/path/to/hsqldbutil.jar:/home/bob/classes:/usr/local/lib/pg.jdbc3.jar
export CLASSPATH
java org.hsqldb.util.SqlTool urlid</pre></div>
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="int-section"></a>Interactive</h2></div></div><div></div></div><p>
            Do read the
            <a href="#baremin-section" title="The Bare Minimum You Need to Know to Run SqlTool">The Bare Minimum</a>
            section before you read this section.
        </p><p>
            You run SqlTool interactively by specifying no SQL filepaths on 
            the SqlTool command line.  Like this.
        <div class="informalexample"><pre class="screen">
    java -jar $HSQLDB_HOME/lib/hsqldb.jar urlid</pre></div></p><div class="procedure"><p class="title"><b>Procedure&nbsp;8.4.&nbsp;What happens when SqlTool is run interactively
                (using all default settings)
            </b></p><ol type="1"><li><p>
                SqlTool starts up and connects to the specified database,
                using your SqlTool configuration file
                (as explained in the
                <a href="#auth-section" title="RC File Authentication Setup">RC File Authentication Setup</a> section).
            </p></li><li><p>
                SQL file <tt class="filename">auto.sql</tt> in your home directory 
                is executed (if there is one),
            </p></li><li><p>
                SqlTool displays a
                banner showing the SqlTool and SqlFile version numbers and 
                describes the different command types that you can give, as 
                well as commands to list all of the specific commands available 
                to you.
            </p></li></ol></div><p>
            You exit your session by using the "\q" special command or ending 
            input (like with Ctrl-D or Ctrl-Z).
        </p><div class="important" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Important</h3><p>
            Every command (regardless of type) and comment must begin at the
            beginning of a line (or immediately after a comment ends with
            "*/").
        </p><p>
            You can't nest commands or comments.
            You can only start new commands (and comments) after the preceding
            statement has been terminated.
            (Remember that if you're running SqlTool interactively, you 
            can terminate an SQL statement without executing it by entering a
            blank line).
        </p><p>
            (Special Commands, Buffer Commands and PL Commands always consist
            of just one line.
            Any of these commands or comments may be preceded by space 
            characters.)
        </p><p>
            These rules do not apply at all to
            <a href="#raw-section" title="Raw Mode">Raw Mode</a>.
            Raw mode is for use by advanced users when they want to completely
            bypass SqlTool processing in order to enter a chunk of text for
            direct transmission to the database engine.
        </p></div><p>
            When you are typing into SqlTool, you are always typing part of
            the <span class="emphasis"><em>current command</em></span>.
            The <span class="emphasis"><em>buffer</em></span> is the <span class="emphasis"><em>last SQL 
            command</em></span>.
            If you're typing an SQL command, then the previous SQL command
            will be in the buffer, not the one you are currently typing.
            The current command could be any type of command, but only SQL
           
            When you type command-editing commands, the <span class="emphasis"><em>current
            command</em></span> is the editing command (like
            "<tt class="literal">:s/tbl/table/</tt>"), the result of which is to
            modify the SQL command in the buffer (which can thereafter be
            executed).
            The ":a" command (with no argument) is special in that it takes a
            copy of the SQL command in the buffer and makes that the current 
            command, leaving you in a state where you are 
            <span class="emphasis"><em>appending</em></span> to that 
            <span class="emphasis"><em>now current</em></span> command.
            The buffer is the zeroeth item of the SQL command history.
        </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N114E7"></a>Command Types</h3></div></div><div></div></div><div class="variablelist"><p class="title"><b>Command types</b></p><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>
                Above, we said that if you enter an SQL command, one
                SQL command corresponds to one SqlTool command.
                This is the most typical usage, however,
                you can actually put multiple SQL statements into one
                SQL command.
                One example would be
        <div class="informalexample"><pre class="screen">
    INSERT INTO t1 VALUES(0); SELECT * FROM t1;</pre></div>
                This is one SqlTool command containing two SQL statements.
                See the 
                <a href="#chunk-section" title="Chunking">Chunking</a>
                section to see why you may want to <span class="emphasis"><em>chunk</em></span>
                SQL commands, how, and the implications.
            </p></div><dl><dt><span class="term">SQL Statement</span></dt><dd><p>
                Any command that you enter which does not begin with "\", ":", 
                or "* " is an SQL Statement.
                The command is not terminated when you hit ENTER, like most 
                OS shells.
                You terminate SQL Statements with either ";" at the end of a 
                line, or with a blank line.
                In the former case, the SQL Statement will be executed against 
                the SQL database and the command will go into the command 
                buffer and SQL command history for editing or viewing later on.
                In the former case, 
                <span class="emphasis"><em>execute against the SQL database</em></span> means
                to transmit the SQL text to the database engine for execution.
                In the latter case (you end an SQL Statement with a blank 
                line), the command will go to the buffer and SQL history, but 
                will not be executed (but you can execute it later from the 
                buffer).
                (See the note immediately above about multiple SQL statements 
                in one SqlTool command).
            </p><p>
                (Blank lines are only interpreted this way when SqlTool is
                run interactively.
                In SQL files, blank lines inside of SQL statements remain
                part of the SQL statement).
            </p><p>
                As a result of these termination rules, whenever you are 
                entering text that is not a Special Command, Buffer Command, 
                or PL Command, you are always 
                <span class="emphasis"><em>appending</em></span> lines to an SQL Statement.
                (In the case of the first line, you will be appending to an
                empty SQL statement.  I.e. you will be starting a new SQL 
                Statement).
            </p></dd><dt><span class="term">Special Command</span></dt><dd>
                Run the command "\?" to list the Special Commands.
                All of the Special Commands begin with "\".
                I'll describe some of the most 
                useful Special Commands below.
            </dd><dt><span class="term">Buffer Command</span></dt><dd>
                Run the command ":?" to list the Buffer Commands.
                All of the Buffer Commands begin with ":".
                Buffer commands operate upon the command "buffer", so that 
                you can edit and/or (re-)execute previously entered commands.
            </dd><dt><span class="term">PL Command</span></dt><dd><p>
                Procedural Langage commands.
                Run the command "*?" to list the PL Commands.
                All of the PL Commands begin with "*".
                PL commands are for setting and using scripting variables
                and conditional and flow control statements like
                <tt class="literal">* if</tt> and <tt class="literal">* while</tt>.
                A few PL features (such as PL aliases and updating and
                selecing data directly from/to files) can be a real 
                convenience for nearly all users, so these features will be
                discussed briefly in this section.
                More detailed explanation of PL variables and the other 
                PL features, with examples, are covered in the
                <a href="#pl-section" title="SqlTool Procedural Language">SqlTool Procedural Language</a> section.
            </p></dd><dt><span class="term">Raw Mode</span></dt><dd>
                The descriptions of command-types above do not apply to
                <a href="#raw-section" title="Raw Mode">Raw Mode</a>.
                In raw mode, SqlTool
                doesn't interpret what you type at all.  It all just
                goes into a buffer which you can send to the database
                engine.
                Beginners can safely ignore raw mode.
                You will never encounter it unless you run the "\."
                special command, or enter a PL/SQL command.
                See the 
                <a href="#raw-section" title="Raw Mode">Raw Mode</a> section
                for the details.
            </dd></dl></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11538"></a>Special Commands</h3></div></div><div></div></div><div class="variablelist"><p class="title"><b>Essential Special Commands</b></p><dl><dt><span class="term">\?</span></dt><dd>
                help
            </dd><dt><span class="term">\q</span></dt><dd>
                quit
            </dd><dt><span class="term">\dt [filter_substring]</span></dt><dd></dd><dt><span class="term">\dv [filter_substring]</span></dt><dd></dd><dt><span class="term">\ds [filter_substring]</span></dt><dd></dd><dt><span class="term">\di [table_name]</span></dt><dd></dd><dt><span class="term">\dS [filter_substring]</span></dt><dd></dd><dt><span class="term">\da [filter_substring]</span></dt><dd></dd><dt><span class="term">\dn [filter_substring]</span></dt><dd></dd><dt><span class="term">\du [filter_substring]</span></dt><dd></dd><dt><span class="term">\d* [filter_substring]</span></dt><dd><p>
                Lists available objects of the given type.
                <div class="itemizedlist"><ul type="disc"><li>t: non-system Table&#1109;</li><li>v: Views</li><li>s: Synonyms</li><li>i: Indexes</li><li>S: System table&#1109;</li><li>a: Aliases</li><li>n: schema Names</li><li>u: database Users</li><li>*: all table-like objects</li></ul></div>
                If your database supports schemas, then the schema name will
                also be listed.
                </p><p>
                If you supply an optional <span class="emphasis"><em>filter substring</em></span>,
                then only items which contain the given substring (in the object
                name or schema name) will be listed.
                </p><div class="important" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Important</h3><p>
                    The substring test is case-sensitive!
                    Even though in SQL queries and for the "\d objectname"
                    command object names are usually case-insensitive, for 
                    the \dX commands, you must capitalize the filter 
                    substring exactly as it will appear in the special
                    command output.
                    This is an inconvenience, since the database engine
                    will change names in SQL to default case unless you 
                    double-quote the name, but that is server-side 
                    functionality which cannot (portably) be reproduced by 
                    SqlTool.
                    You can use spaces and other special characters in
                    the string.
                </p></div><div class="tip" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Tip</h3><p>
                    Filter substrings ending with "." are special.
                    If a substring ends with ".", then this means to narrow
                    the search by the exact, case-sensitive schema name
                    given.
                    For example, if I run "\d* BLAINE.", this will list all
                    table-like database objects in the "BLAINE" schema.
                    The capitalization of the schema must be exactly the same 
                    as how the schema name is listed by the "\dn" command.
                    You can use spaces and other special characters in
                    the string.
                    (I.e., enter the name exactly how you would enter it 
                    inside of double-quotes in an SQL command).
                    This is an inconvenience, since the database engine
                    will change names in SQL to default case unless you 
                    double-quote the name, but that is server-side 
                    functionality which cannot (portably) be reproduced by 
                    SqlTool.
                </p></div><div class="important" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Important</h3><p>
                    Indexes may not be searched for by 
                    <span class="emphasis"><em>substring</em></span>, only by
                    exact target table name.
                    So if <tt class="literal">I1</tt> is an index on table
                    <tt class="literal">T1</tt>, then you list this index by running
                    "\di T1".
                    In addition, many database vendors will report on indexes 
                    only if a target table is identified.
                    Therefore, "\di" with no argument will fail if your database
                    vendor does not support it.
                </p></div></dd><dt><span class="term">\d objectname [filter]</span></dt><dd><p>
                Lists names of columns in the specified table or view.
                <tt class="literal">objectname</tt> may be a base table name or
                a schema.object name.
                </p><p>
                If you supply a filter string, then only columns with a name
                containing the given filter will be listed.
                The objectname is nearly always case-insensitive (depends on
                your database), but the filter is always case-sensitive.
                You'll find this filter is a great convenience compared to
                other database utilities, where you have to list all columns
                of large tables when you are only interested in one of them.
                </p><div class="tip" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Tip</h3><p>
                When working with real data (as opposed to learning or playing),
                I often find it useful to run two SqlTool sessions in two
                side-by-side terminal emulator windows.
                I do all of my real work in one window, and use the other
                mostly for \d commands.
                This way I can refer to the data dictionary while writing SQL
                commands, without having to scroll.
            </p></div></dd><dt><span class="term">\s</span></dt><dd>
                Shows the SQL command history.
                The SQL command history will show a number (a negative number) 
                for each SQL Statement that has made it into the buffer so 
                fare (by either executing or entering a blank line).
                You can then use the "\-" command (which is described next) to 
                retrieve commands from the SQL history to work with.
                To list just the very last command, you would use the ":l" 
                buffer command to list the buffer contents, instead of this 
                command.
            </dd><dt><span class="term">\-[3]</span></dt><dd><p>
                Enter "\" followed by the command number from SQL history, like
                "\-3".
                That command will be written to the buffer so that you can 
                execute it or edit it using buffer commands.
                </p><p>
                (You can append a semicolon to a recall command in order
                to execute the recalled buffer immediately, like "\-3;".
                This is actually just a shortcut for running the Special
                Command "\-3" and the Buffer Command ":;".)
            </p></dd></dl></div><p>
            This list here includes only the <span class="emphasis"><em>essential</em></span> 
            Special Commands, but n.b. that there are other useful Special 
            Commands which you can list by running <tt class="literal">\?</tt>.
            (You can, for example, execute SQL from external SQL files, and 
            save your interactive SQL commands to files).
            Some specifics of these other commands are specified immediately 
            below, and the 
            <a href="#report-section" title="Generating Text or HTML Reports">Generating Text or HTML Reports</a>
            section explains how to use the "\o" and "\H" special commands to 
            generate reports.
        </p><p>
            Be aware that the <tt class="literal">\!</tt> Special Command does
            not work for external programs that read from standard input.
            You can invoke non-interactive and graphical interactive programs, 
            but not command-line interactive programs.
        </p><p>
            SqlTool executes <tt class="literal">\!</tt> programs directly, it does 
            not run an operating system shell (this is to avoid OS-specific
            code in SqlTool).
            Because of this, you can give as many command-line arguments
            as you wish, but you can't use shell wildcards or redirection.
        </p><p>
            The \w command can be used to store any command in your SQL 
            history to a file.
            Just restore the command to the buffer (which is the 0th
            element of the history) with a command like "\-4" before you give
            the \w command.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N115E6"></a>Buffer Commands</h3></div></div><div></div></div><div class="variablelist"><p class="title"><b>Buffer Commands</b></p><dl><dt><span class="term">:?</span></dt><dd>
                help
            </dd><dt><span class="term">:;</span></dt><dd>
                Executes the SQL statement in the current buffer against the 
                database.
                This is an extremely useful command.
                It's easy to remember because it consists of
                ":", meaning <span class="emphasis"><em>Buffer Command</em></span>; plus a
                line-terminating ";", which sends the preceding SQL to the
                database engine for execution.
            </dd><dt><span class="term">:l</span></dt><dd>
                (This is a lower case L).
                List the current contents of the buffer.
            </dd><dt><span class="term">:a</span></dt><dd><p>
                Enter append mode with the contents of the buffer as the 
                current SQL Statement.
                Things will be exactly as if you physically re-typed 
                the command that is in the buffer.
                Whatever line you type next will be appended to the SQL 
                Statement.
                You can execute the command by terminating a line with ";",
                or send it back to the buffer by entering a blank line.
                </p><p>
                You can, optionally, put a string after the :a, in which
                case this text will be appended and you will remain in
                append mode.
                (Unless the text ends with ';', in which case the resultant
                statement will be executed immediately).
                Note that if you do put text after the "a",
                <span class="emphasis"><em>exactly</em></span> what you type immediately after
                "a" will be appended.
                If your buffer contains
                <tt class="literal">SELECT x FROM mytab</tt> and you run
                <tt class="literal">a:le</tt>, the resultant command will be
                <tt class="literal">SELECT x FROM mytable</tt>.
                If your buffer contains
                <tt class="literal">SELECT x FROM mytab</tt> and you run
                <tt class="literal">a: ORDER BY y</tt>, the resultant command will be
                <tt class="literal">SELECT x FROM mytab ORDER BY y</tt>.
                Notice that in the latter case the append text begins with a
                space character.
            </p></dd><dt><span class="term">:s/from string/to string/switches</span></dt><dd><p>
                This is the primary command for SqlTool command editing-- 
                it operates upon the current buffer.
                The "to string" and the "switches" are both optional.
                To start with, I'll discuss the use and behavior if you don't
                supply any substitution mode switches.
                </p><p>
                Don't use "/" if it occurs in either "from string" or "to 
                string".
                You can use any character that you want in place of "/", but 
                it must not occur in the <span class="emphasis"><em>from</em></span> or 
                <span class="emphasis"><em>to</em></span> strings.
                Example
                <div class="informalexample"><pre class="screen">
    :s@from string@to string@</pre></div></p><p>
                The <span class="emphasis"><em>to</em></span> string is substituted for the first 
                occurrence of the (case-specific)<span class="emphasis"><em>from</em></span>
                string.
                The replacement will consider the entire SQL statement, even
                if it is a multi-line statement.
                </p><p>
                All occurrences of "$" in the <span class="emphasis"><em>from</em></span> string
                and the <span class="emphasis"><em>to</em></span> string are treated as line 
                breaks.
                For example, <span class="emphasis"><em>from</em></span> string of
                "<tt class="literal">*$FROM mytable</tt>" would 
                actually look for occurrences of
                <div class="informalexample"><pre class="screen">
     *
     FROM mytable</pre></div></p><p>
                Here is a another meaningful example using $.
                <div class="informalexample"><pre class="screen">
    :s/e)$/e) WHERE col1 is not null$/</pre></div></p><p>
                This command appends
                "<tt class="literal">WHERE col1 is not null</tt>" to the 
                line(s) which end with "e)".
                </p><p>
                The <span class="emphasis"><em>to</em></span> string may be empty, in which case, 
                occurrences of the <span class="emphasis"><em>from</em></span> string are just 
                deleted.  For example
                <div class="informalexample"><pre class="screen">
    :s/this//</pre></div></p><p>
                would remove the first occurrence of "this".
                (With the "g" substitution mode switch, as explained below,
                it would remove all occurrences of "this").
                </p><p>
                Don't end a <span class="emphasis"><em>to</em></span> string with ";" in attempt to make a SQL
                statement execute.
                There is a substitution mode switch to use for that purpose.
                </p><p>
                You can use any combination of the substitution mode switches.
                <div class="itemizedlist"><ul type="disc"><li><p>
                        Use "i" to make the searches for 
                        <span class="emphasis"><em>from</em></span> string case insensitive.
                    </p></li><li><p>
                        Use "g" to substitute globally, i.e., for all 
                        occurrences of <span class="emphasis"><em>from</em></span> string which 
                        are found in the text under consideration.
                    </p></li><li><p>
                        Use ";" to execute the command immediately after the
                        substitution is performed.
                    </p></li><li><p>
                        Use an integer (from 1 to 9) to narrow the text under
                        consideration to a specific line of a multi-line
                        buffer.
                    </p></li></ul></div>
            </p><p>
                The substitution facility doesn't support any regular
                expressions at all.
                When we stop supporting Java versions older than 1.4, I'll
                start supporting regular expressions and other advanced
                string manipulation functions.
            </p></dd></dl></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="interactive_pl_commands-section"></a>PL Commands</h3></div></div><div></div></div><div class="variablelist"><p class="title"><b>Essential PL Command</b></p><dl><dt><span class="term">* VARNAME = value</span></dt><dd><p>
                Set the value of a variable.
                If the variable doesn't exist yet, it will be created.
                The most common use for this is so that you can later use
                it in SQL statements, print statements, and PL conditionals,
                by using the <tt class="literal">*{VARNAME}</tt> construct.
            </p><p>
                    If you set a variable to an SQL statement (without the
                    terminating ";") you can then use it as a PL alias like
                    <tt class="literal">*VARNAME</tt>, as shown in this example.
                <div class="example"><a name="alias-example"></a><p class="title"><b>Example&nbsp;8.2.&nbsp;Defining and using a PL alias (PL variable)</b></p><pre class="screen">
    * q = SELECT COUNT(*) FROM mytable
    \p The stored query is '*{q}'
    /q;
    /q WHERE mass &gt; 200;</pre></div>
            </p><p>
                If you put variable definitions into the SQL file
                <tt class="filename">auto.sql</tt> in your home directory, those
                aliases/variables will always be available for interactive use.
            </p></dd><dt><span class="term">* load VARNAME /file/path.txt</span></dt><dd>
                Sets VARNAME to the content of the specified ASCII file.
            </dd><dt><span class="term">* prepare VARNAME</span></dt><dd>
                Indicate that next command should be a SQL INSERT or UPDATE
                command containing one question mark.
                The value of VARNAME will be substuted for the ? variable.
                This does work for CLOB columns.
            </dd><dt><span class="term">* VARNAME _</span></dt><dd>
                When next SQL command is run, instead of displaying the rows,
                just store the very first column value to variable VARNAME.
                This works for CLOB columns.
                It also works with Oracle XML type columns if you use
                column labels and the <tt class="literal">getclobval</tt> function.
            </dd><dt><span class="term">* dump VARNAME /file/path.txt</span></dt><dd>
                Store the value of VARNAME to the specified ASCII file.
            </dd></dl></div><p>
            Note that PL commands are used to upload and download column
            values to/from local ASCII files, but the corresponding actions 
            for binary files use the special \b commands.
            This is because PL variables are used for ASCII values and
            you can store any number of column values in PL variables.
            This is not true for binary column values.
            The \b commands work with a single binary byte buffer.
        </p><p>
            See the <a href="#pl-section" title="SqlTool Procedural Language">SqlTool Procedural Language</a> section 
            below for information on using variables in other ways, and 
            information on the other PL commands and features.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="binary_files-section"></a>
                Storing and retrieving binary files</h3></div></div><div></div></div><p>
            You can upload binary files such as photographs, audio files,
            or serialized Java objects into database columns.
            SqlTool keeps one binary buffer which you can load from files
            with the \bl command, or from a database query by doing a
            one-row query for any non-displayable type (including
            <tt class="literal">BLOB</tt>, <tt class="literal">OBJECT</tt>, and
            <tt class="literal">OTHER</tt>).
            In the latter case, the data returned for the first
            non-displayable column of the first result row will be stored 
            into the binary buffer.
        </p><p>
            Once you have data in the binary buffer, you can upload it
            to a database column (including <tt class="literal">BLOB</tt>,
            <tt class="literal">OBJECT</tt>, and <tt class="literal">OTHER</tt> type
            columns), or save it to a file.
            The former is accomplished by the special command \bp followed
            by a <span class="emphasis"><em>prepared</em></span> SQL query containing one 
            question mark place-holder to indicate where the data gets
            inserted.
            The latter is accomplished with the \bd command.
        </p><p>
            You can also store the output from normal, displayable column
            into the binary buffer by using the special command \b.
            The very first column value from the first result row of the
            next SQL command will be stored to the binary byte buffer.
        </p><div class="example"><a name="N116F8"></a><p class="title"><b>Example&nbsp;8.3.&nbsp;Inserting binary data into database from a file</b></p><pre class="screen">
    \bl /tmp/favoritesong.mp3
    \bp
    INSERT INTO musictbl (id, stream) VALUES(3112, ?);</pre></div><div class="example"><a name="N116FE"></a><p class="title"><b>Example&nbsp;8.4.&nbsp;Downloading binary data from database to a file</b></p><pre class="screen">
    SELECT stream FROM musictbl WHERE id = 3112;
    \bd /tmp/favoritesong.mp3</pre></div><p>
            You can also store and retrieve text column values to/from
            ASCII files, as documented in the
            <a href="#interactive_pl_commands-section" title="PL Commands">Essential PL Command</a>
            section.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1170A"></a>SQL History</h3></div></div><div></div></div><p>
            The SQL history shown by the \s command, and used by other commands,
            is truncated to 20 entries, since the utility comes from being 
            able to quickly view the history list.
            You can change the history length by setting the system property
            <tt class="literal">sqltool.historyLength</tt> to an integer like
            <pre class="screen">
java -Dsqltool.historyLength=40 -jar $HSQLDB_HOME/lib/hsqldb.jar urlid</pre>
        </p><p>
            The SQL history list explicitly does not contain Special, Buffer,
            or PL commands.
            It only contains SQL commands, valid or invalid, successful or 
            unsuccessful.
            The reason for including bad SQL commands is so that you can 
            recall and edit them if you want to.
            The same applies to the editing buffer (which is element 0
            of the history).
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11719"></a>Shell scripting and command-line piping</h3></div></div><div></div></div><p>
            You normally use non-interactive mode for piping.  You specify
            "-" as the SQL file name.  
            See the <a href="#scripting-section" title="Piping and shell scripting">Piping and shell scripting</a>
            subsection of the Non-Interactive chapter.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11722"></a>Emulating Non-Interactive mode</h3></div></div><div></div></div><p>
            You can run SqlTool <span class="emphasis"><em>interactively</em></span>, but
            have SqlTool behave exactly as if it were processing an SQL
            file (i.e., no command-line prompts, error-handling
            that defaults to fail-upon-error, etc.).
            Just specify "-" as the SQL file name in the command line.
            This is a good way to test what SqlTool will do when it 
            encounters any specific command in an SQL file.
            See the <a href="#scripting-section" title="Piping and shell scripting">Piping and shell scripting</a>
            subsection of the Non-Interactive chapter for an example.
            </p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="nonint-section"></a>Non-Interactive</h2></div></div><div></div></div><p>
            Read the <a href="#int-section" title="Interactive">Interactive</a>
            section if you have not already, 
            because much of what is in this section builds upon that.
            Even if your plans are to run SqlTool non-interactively, you 
            should really learn to run it interactively because it's such a 
            powerful debugging tool, and you can use it to prototype sql 
            scripts.
        </p><div class="important" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Important</h3><p>
            If you're doing data updates, remember to issue a commit command
            or use the <tt class="literal">--autoCommit</tt> switch.
        </p></div><p>
            As you'll see, SqlTool has many features that are very 
            convenient for scripting.  But what really makes it superior for
            automation tasks (as compared to SQL tools from other vendors)
            is the ability to reliably detect errors and to control JDBC
            transactions.
        </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="sqlswitch-section"></a>Giving SQL on the Command Line</h3></div></div><div></div></div><p>
                If you just have a couple SQL commands to run, you can run them 
                directly from the comand-line or from a shell script without an 
                SQL file, like this.
            <div class="informalexample"><pre class="screen">
    java -jar $HSQLDB_HOME/lib/hsqldb.jar --sql 'SQL statement' urlid</pre></div>
            <div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>
                The <tt class="literal">--sql</tt> automatically implies
                <tt class="literal">--noinput</tt>, so if you want to execute the
                specified SQL before <span class="emphasis"><em>and in addition to</em></span> an
                interactive session (or stdin piping), then you must also give
                the <span class="emphasis"><em>--stdinput</em></span> switch.
            </p></div> <div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>
                SqlTool will automatically add a trailing semicolon to your
                <tt class="literal">--sql</tt> SQL.  You may still give the trailing
                semicolon if you wish to, and you must still delimit multiple
                SQL commands with a simicolon, of course.
            </p></div>
            </p><p>
                Since SqlTool transmits SQL statements to the database engine
                only when a line is terminated with ";", if you want feedback
                from multiple SQL statements in an --sql expression, you will
                need to use functionality of your OS shell to include
                linebreaks after the semicolons in the expression.
                With any Bourne-compatible shell, you can include linebreaks in 
                the SQL statements like this.
            <div class="informalexample"><pre class="screen">
    java -jar $HSQLDB_HOME/lib/hsqldb.jar --sql 'SQL statement' urlid '
        SQL statement number one;
        SQL statement
            number two;
        SQL statement three;
    ' urlid</pre></div>
                If you don't need feedback, just separate the SQL commands
                with semicolons and the entire expression will be
                <a href="#chunk-section" title="Chunking">chunked</a>.
            </p><p>
                The <span class="emphasis"><em>--sql</em></span> switch is very useful for 
                setting shell variables to the output of SQL Statements, like 
                this.
            <div class="informalexample"><pre class="programlisting">
    # A shell script
    USERCOUNT=`java -jar $HSQLDB_HOME/lib/hsqldb.jar --sql '
        select count(*) from usertbl
    ' urlid` || {
        # Handle the SqlTool error
    }
    echo "There are $USERCOUNT users registered in the database."
    [ "$USECOUNT" -gt 3 ] &amp;&amp; {   # If there are more than 3 users registered
        # Some conditional shell scripting</pre></div>
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1177D"></a>SQL Files</h3></div></div><div></div></div><p>
                Just give paths to sql text file(s) on the command line after 
                the <span class="emphasis"><em>urlid</em></span>.
            </p><p>
                Often, you will want to redirect output to a file, like
            <div class="informalexample"><pre class="screen">
java -jar $HSQLDB_HOME/lib/hsqldb.jar sql... &gt; /tmp/log.sql 2&gt;&amp;1</pre></div></p><p>
                (Skip the "2&gt;&amp;1" if you're on Windows).
            </p><p>
                You can also execute SQL files from an interactive session with
                the "\i"' Special Command,
                but be aware that the default behavior in an interactive 
                session is to continue upon errors.
                If the SQL file was written without any concern for error
                handling, then the file will continue to execute after errors
                occur.
                You could run <tt class="literal">\c false</tt> before 
                <tt class="literal">\i filename</tt>, but then your SqlTool session
                will exit if an error is encountered in the SQL file.
                If you have an SQL file without error handling, and you want
                to abort that file when an error occurs, but not exit 
                SqlTool, the easiest way to accomplish this is usually to add
                <tt class="literal">\c false</tt> to the top of the script.
            </p><p>
                If you specify multiple SQL files on the command-line, the
                default behavior is to exit SqlTool if any of the SQL files
                encounters an error.
            </p><p>
                <span class="bold"><b>
                SQL files themselves have ultimate control over error handling.
                </b></span>
                Regardless of what command-line options are set, or what 
                commands you give interactively, if a SQL file gives error
                handling statements, they will take precedence.
            </p><p>
                You can also use \i in SQL files.
                This results in nested SQL files.
            </p><p>
                You can use the following SQL file,
                <tt class="filename">sample.sql</tt>, which resides in the
                <tt class="filename">src/org/hsqldb/sample</tt> directory of your
                HSQLDB distribution.
                It contains SQL as well as Special Commands making good
                use of most of the Special Commands documented below.
            </p><pre class="programlisting">/*
    $Id: sample.sql,v 1.5 2005/05/02 15:07:27 unsaved Exp $
    Examplifies use of SqlTool.
    PCTASK Table creation
*/

/* Ignore error for these two statements */
\c true
DROP TABLE pctasklist;
DROP TABLE pctask;
\c false

\p Creating table pctask
CREATE TABLE pctask (
    id integer identity,
    name varchar(40),
    description varchar,
    url varchar,
    UNIQUE (name)
);

\p Creating table pctasklist
CREATE TABLE pctasklist (
    id integer identity,
    host varchar(20) not null,
    tasksequence int not null,
    pctask integer,
    assigndate timestamp default current_timestamp,
    completedate timestamp,
    show bit default true,
    FOREIGN KEY (pctask) REFERENCES pctask,
    UNIQUE (host, tasksequence)
);

\p Granting privileges
GRANT select ON pctask TO public;
GRANT all ON pctask TO tomcat;
GRANT select ON pctasklist TO public;
GRANT all ON pctasklist TO tomcat;

\p Inserting test records
INSERT INTO pctask (name, description, url) VALUES (
    'task one', 'Description for task 1', 'http://cnn.com');
INSERT INTO pctasklist (host, tasksequence, pctask) VALUES (
    'admc-masq', 101, SELECT id FROM pctask WHERE name = 'task one');

commit;
</pre><p>
                You can execute this SQL file with a Memory Only database with 
                a command like
            <div class="informalexample"><pre class="programlisting">
    java -jar $HSQLDB_HOME/lib/hsqldb.jar  --sql '
        create user tomcat password "x"
    ' mem path/to/hsqldb/src/org/hsqldb/sample/sample.sql</pre></div>
            </p><p>
                (The <tt class="literal">--sql "create..."</tt> arguments create an
                account which the script uses).
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="scripting-section"></a>Piping and shell scripting</h3></div></div><div></div></div><p>
                You can of course, redirect output
                <span class="emphasis"><em>from</em></span> SqlTool to a file
                or another program.
            <div class="informalexample"><pre class="screen">
    java -jar $HSQLDB_HOME/lib/hsqldb.jar urlid file.sql &gt; file.txt 2&gt;&amp;1

    java -jar $HSQLDB_HOME/lib/hsqldb.jar urlid file.sql 2&gt;&amp;1 | someprogram...</pre></div></p><p>
                You can type commands in to SqlTool while being in 
                non-interactive mode by supplying "-" as the file name.
                This is a good way to test how SqlTool will behave when 
                processing your SQL files.
            <div class="informalexample"><pre class="screen">
        java -jar $HSQLDB_HOME/lib/hsqldb.jar urlid -</pre></div></p><p>
                This is how you have SqlTool read its input from another 
                program:
            <div class="example"><a name="N117D5"></a><p class="title"><b>Example&nbsp;8.5.&nbsp;Piping input into SqlTool</b></p><pre class="screen">
        echo "Some SQL commands with '$VARIABLES';" |
        java -jar $HSQLDB_HOME/lib/hsqldb.jar urlid -</pre></div></p><p>
                Make sure that you also read the
                <a href="#sqlswitch-section" title="Giving SQL on the Command Line">Giving SQL on the Command Line</a>
                section.
                The <tt class="literal">--sql</tt> switch is a great facility to use
                with shell scripts.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N117E5"></a>Optimally Compatible SQL Files</h3></div></div><div></div></div><p>
                If you want your SQL scripts optimally compatible among other
                SQL tools, then don't use any Special or PL Commands.
                SqlTool has default behavior which I think is far superior to 
                the other SQL tools, but you will have to disable these 
                defaults in order to have optimally compatible behavior.
            </p><p>
                These switches provide compatibilty at the cost of poor 
                control and error detection.
                <div class="itemizedlist"><ul type="disc"><li><p>
                            --continueOnErr
                        </p><p>
                            The output will still contain error messages about
                            everything that SqlTool doesn't like
                            (malformatted commands, SQL command failures, 
                            empty SQL commands), but SqlTool will continue to
                            run.
                            Errors will not cause rollbacks (but that won't
                            matter because of the following setting).
                        </p></li><li>--autoCommit</li></ul></div>
            </p><p>
                You don't have to worry about accidental expansion of 
                PL variables, since SqlTool will never expand PL variables
                if you don't set any variables on the command line, or give 
                any "* " PL commands.
                (And you could not have "* " commands in a compatible SQL 
                file).
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N117F8"></a>Comments</h3></div></div><div></div></div><p>
                SQL comments of the form <tt class="literal">/*...*/</tt> must begin
                where a (SQL/Special/Buffer/PL) Command could begin, and they
                end with the very first "*/" (regardless of quotes, nesting,
                etc.
                You may have as many blank lines as you want inside of a
                comment.
            </p><div class="example"><a name="N11801"></a><p class="title"><b>Example&nbsp;8.6.&nbsp;Valid comment example</b></p><pre class="programlisting">
    SELECT count(*) FROM atable;
    /* Lots of
     comments interspersed among
     several lines */   SELECT count(*)
    FROM btable;</pre></div><p>
                Notice that a command can start immediate after the comment
                ends.
            </p><div class="example"><a name="N11809"></a><p class="title"><b>Example&nbsp;8.7.&nbsp;Invalid comment example</b></p><pre class="programlisting">
    SELECT count(*) FROM
    /* atable */
    btable;</pre></div><p>
                This comment is invalid because you could not start another
                command at the comment location (because it is within an SQL
                Statement).
            </p><p>
                You can try using <tt class="literal">/*...*/</tt> in other locations,
                and <tt class="literal">--</tt> style SQL comments, but SqlTool will
                not treat them as comments.
                If they occur within an SQL Statment, SqlTool will pass them to
                the database engine, and the DB engine will determine whether
                to parse them as comments.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1181B"></a>Special Commands and Buffer Commands in SQL Files</h3></div></div><div></div></div><p>
                Don't use Buffer Commands in your sql files, because they won't 
                work.
                Buffer Commands are for interactive use only.
                (But, see the 
                <a href="#raw-section" title="Raw Mode">Raw Mode</a> section 
                for an exception).
            </p><div class="variablelist"><dl><dt><span class="term">\q [abort message]</span></dt><dd><p>
                    Be aware that the \q command will cause SqlTool to 
                    completely exit.
                    If a script <tt class="filename">x.sql</tt> has a \q command in
                    it, then it doesn't matter if the script is executed like
                    <pre class="screen">
    java -jar .../hsqldb.jar urlid a.sql x.sql z.sql</pre> or if you use
                    \i to read it in interactively, or if another SQL file
                    uses \i to nest it.
                    If \q is encountered, SqlTool will quit.
                    See the <a href="#pl-section" title="SqlTool Procedural Language">SqlTool Procedural Language</a> 
                    section for commands to abort an SQL file (or even parts
                    of an SQL file) without causing SqlTool to exit.
                </p><p>
                    \q takes an optional argument, which is an abort message.
                    If you give an abort message, the message is displayed to
                    the user and SqlTool will exit with a failure status.
                    If you give no abort message, then SqlTool will exit 
                    quietly with successful status.
                </p></dd><dt><span class="term">\p [text to print]</span></dt><dd>
                    Print the given string to stdout.
                    Just give "\p" alone to print a blank line.
                </dd><dt><span class="term">\i /path/to/file.sql</span></dt><dd>
                    Include another SQL file at this location.
                    You can use this to nest SQL files.
                    For database installation scripts I often have a master
                    SQL file which includes all of the other SQL files in the
                    correct sequence.
                    Be aware that the current continue-upon-error behavior
                    will apply to included files until such point as the SQL
                    file runs its own error handling commands.
                </dd><dt><span class="term">\H</span></dt><dd><p>
                    Toggle HTML output mode.
                    If you redirect output to a file, this can make a long
                    session log much easier to view.
                    This will HTML-ify the entire session.
                    For example,
                    <div class="informalexample"><pre class="screen">
java -jar $HSQLDB_HOME/lib/hsqldb.jar urlid filepath1.sql... &gt; /tmp/log.html 2&gt;&amp;1</pre></div>
                    (See the
                    <a href="#report-section" title="Generating Text or HTML Reports">Generating Text or HTML Reports</a> 
                    section about how to easily store just the query output
                    to file.)
                </p></dd><dt><span class="term">\a [true|false]</span></dt><dd>
                    This turns on and off SQL transaction autocommits.
                    Auto-commit defaults to false, but you can change that
                    behavior by using the <tt class="literal">--autoCommit</tt>
                    command-line switch.
                </dd><dt><span class="term">\c [true|false]</span></dt><dd><p>
                    A "true" setting tells SqlTool to Continue when errors are 
                    encountered.
                    The current transaction will not be rolled back upon SQL
                    errors, so if \c is true, then run the
                    <tt class="literal">ROLLCACK;</tt> command yourself if that's 
                    what you want to happen.
                    The default for interactive use is to continue upon error, 
                    but the default for non-interactive use is to abort upon 
                    error.
                    You can override this behavior by using the
                    <tt class="literal">--continueOnErr</tt> or the
                    <tt class="literal">--abortOnErr</tt> command-line switch.
                    </p><p>
                    With database setup scripts, I usually find it convenient 
                    to set "true" before dropping tables (so that things will 
                    continue if the tables aren't there), then set it back to 
                    false so that real errors are caught.
                    <tt class="literal">DROP TABLE tablename IF EXISTS;</tt>
                    is a more elegant, but less portable, way to accomplish
                    the same thing.
                    </p><div class="tip" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Tip</h3><p>
                        It depends on what you want your SQL files to do, of
                        course, but I usually want my SQL files to abort when
                        an error is encountered, without necessarily killing 
                        the SqlTool session.
                        If this is the behavior that you want, then
                        put an explicit <tt class="literal">\c false</tt>
                        at the top of your SQL file and turn on
                        continue-upon-error only for sections where you really
                        want to permit errors, or where you are using PL
                        commands to handle errors manually.
                        This will give the desired behavior whether your 
                        script is called by
                        somebody interactively, from the SqlTool command-line, 
                        or included in another SQL file (i.e. nested).
                    </p></div><div class="important" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Important</h3><p>
                        The default settings are usually best for people who 
                        don't want to put in any explicit \c or error handling 
                        code at all.
                        If you run SQL files from the SqlTool command line,
                        then any errors will cause SqlTool to roll back and
                        abort immediately.
                        If you run SqlTool interactively and invoke SQL files
                        with \i commands, the scripts will continue to run
                        upon errors (and will not roll back).
                        This behavior was chosen because there are lots of
                        SQL files out there that produce errors which can be
                        ignored; but we don't want to ignore errors that a
                        user won't see.
                        I reiterate that any and all of this behavior can (and 
                        often should) be changed by Special Commands run in 
                        your interactive shell or in the SQL files.
                        Only you know whether errors in your SQL files can
                        safely be ignored.
                    </p></div></dd></dl></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11880"></a>Automation</h3></div></div><div></div></div><p>
                SqlTool is ideal for mission-critical automation because,
                unlike other SQL tools, SqlTool returns a dependable exit 
                status and gives you control over error handling and SQL 
                transactions.
                Autocommit is off by default, so you can build a completely
                dependable solution by intelligently using \c commands 
                (Continue upon Errors) and commit statements, and by
                verifying exit statuses.
            </p><p>
                Using the SqlTool Procedural Language, you have ultimate
                control over program flow, and you can use variables for
                database input and output as well as for many other purposes.
                See the <a href="#pl-section" title="SqlTool Procedural Language">SqlTool Procedural Language</a>
                section.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1188B"></a>Getting Interactive Functionality with SQL Files</h3></div></div><div></div></div><p>
                Some script developers may run into cases where they want to 
                run with sql files but they alwo want SqlTool's interactive 
                behavior.
                For example, they may want to do command recall in the sql file,
                or they may want to log SqlTool's command-line prompts (which 
                are not printed in non-interactive mode).
                In this case, do not give the sql file(s) as an argument to 
                SqlTool, but pipe them in instead, like
            <div class="informalexample"><pre class="screen">
java -jar $HSQLDB_HOME/lib/hsqldb.jar urlid &lt; filepath1.sql &gt; /tmp/log.html 2&gt;&amp;1</pre></div>
                or
            <div class="informalexample"><pre class="screen">
cat filepath1.sql... |
java -jar $HSQLDB_HOME/lib/hsqldb.jar urlid &gt; /tmp/log.html 2&gt;&amp;1</pre></div>
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="charencoding-section"></a>
                Character Encoding</h3></div></div><div></div></div><p>
                SqlTool defaults to the US-ASCII character set (for reading).
                You can use another character set by setting the system 
                property <span class="property">sqlfile.charset</span>, like
            <div class="informalexample"><pre class="screen">
java -Dsqlfile.charset=UTF-8 -jar $HSQLDB_HOME/lib/hsqldb.jar urlid file.sql...</pre></div></p><p>
                You can also set this per urlid in the SqlTool configuration 
                file.
                See the <a href="#auth-section" title="RC File Authentication Setup">RC File Authentication Setup</a>
                section about that.
            </p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="report-section"></a>Generating Text or HTML Reports</h2></div></div><div></div></div><p>
            This section is about making a file containing the output of 
            database queries.
            You can generate reports by using operating system facilities
            such as redirection, tee, and cutting and pasting.
            But it is much easier to use the "\o" and "\H" special commands.
        </p><div class="procedure"><p class="title"><b>Procedure&nbsp;8.5.&nbsp;Writing query output to an external file</b></p><ol type="1"><li><p>
                By default, everthing will be done in plain text.
                If you want your report to be in HTML format, then give the
                special command <tt class="literal">\H</tt>.
                If you do so, you will probably want to use filenames with an
                suffix of ".html" or ".htm" instead of ".txt" in the next step.
            </p></li><li><p>
                Run the command <tt class="literal">\o path/to/reportfile.txt</tt>.
                From this point on, output from your queries will be appended
                to the specified file.
                (I.e. another <span class="emphasis"><em>copy</em></span> of the output is
                generated.)
                This way you can continue to monitor or use output as usual as
                the report is generated.
            </p></li><li><p>
                When you want SqlTool to stop writing to the file, run
                <tt class="literal">\o</tt> (or just quit SqlTool if you have no 
                other work to do).
            </p></li><li><p>
                If you turned on HTML mode with <tt class="literal">\H</tt> before,
                you can run <tt class="literal">\H</tt> again to turn it back off,
                if you wish.
            </p></li></ol></div><p>
            It is not just the output of "SELECT" statements that will make
            it into the report file, but
            <div class="itemizedlist"><p class="title"><b>Kinds of output that get teed to \o files</b></p><ul type="disc"><li>
                    Output of SELECT statements.
                </li><li>
                    Output of all "\d" Special Commands.
                    (I.e., "\dt", "\dv", etc., and "\d OBJECTNAME").
                </li><li>
                    Output of "\p" Special Commands.
                    You will want to use this to add titles, and perhaps
                    spacing, for the output of individual queries.
                </li></ul></div>
            Other output will go to your screen or stdout, but will not make
            it into the report file.
            Be aware that no error messages will go into the report file.
            If SqlTool is run non-interactively (including if you give any
            SQL file(s) on the command line), SqlTool will abort with an error
            status if errors are encountered.
            The right way to handle errors is to check the SqlTool exit status.
            (The described error-handling behavior can be modified with
            SqlTool command-line switches and Special Commands).
        </p><div class="warning" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Warning</h3><p>
            Remember that \o <span class="emphasis"><em>appends</em></span> to the named file.
            If you want a new file, then use a new file name or remove the
            targe file ahead of time.
        </p></div><div class="tip" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Tip</h3><p>
            So that I don't end up with a bunch of junk in my report file, I
            usually leave \o off while I perfect my SQL.  With \o off,
            I perfect the SQL query until it produces on my screen exactly
            what I want saved to file.
            At this point I turn on \o and run ":;" to repeat the last SQL
            command.
            If I have several complex queries to run, I turn \o off and
            repeat until I'm finished.
            (Every time you turn \o on, it will append to the file, just
            like we need).
            </p><p>
            Usually it doesn't come to mind that I need a wider screen until
            a query produces lines that are too long.
            In this case, stretch your window and repeat the last command with
            the ":;" Buffer Command.
        </p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="pl-section"></a>SqlTool Procedural Language</h2></div><div><h3 class="subtitle">Aka PL</h3></div></div><div></div></div><p>
            Most importantly, run <tt class="filename">SqlTool</tt> interactively 
            and give the "*?" command to see what PL commands are available to 
            you.
        </p><p>
            PL variables will only be expanded after you run a PL command (or 
            set variable(s) from the command-line).
            We only want to turn on variable expansion if the user wants
            variable expansion.
            People who don't use PL don't have to worry about strings getting
            accidentally expanded.
        </p><p>
            All other PL commands imply the "*" command, so you only need to 
            use the "*" statement if your script uses PL variables
            and it is possible that no variables may be set before-hand (and
            no PL commands have been run previously).
            In this case, without "*", your script would silently use a
            literal value like "*{x}" instead of trying to expand it.
            With a preceding "*" command, PL will notice that the variable
            <tt class="literal">x</tt> has not been set and will generate an error.
            (If x had been set here will be no issue because setting a
            variable automatically turns on PL variable expansion).
        </p><p>
            PL is also used to upload and download column values to/from
            local ASCII files, analogously to the special \b commands
            for binary files.
            This is explained above in the Interactive
            <a href="#interactive_pl_commands-section" title="PL Commands">Essential PL Command</a>
            section above.
        </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11915"></a>Variables</h3></div></div><div></div></div><div class="itemizedlist"><ul type="disc"><li>
                    Use the <tt class="literal">* list</tt> command to list some or
                    all variables; or <tt class="literal">* listvalue</tt> to also
                    see the values.
                </li><li>
                    You can set variables using the
                    <tt class="literal">* VARNAME = value</tt> command.
                </li><li>
                    You can also set variables using the 
                    <tt class="literal">--setvar</tt> command-line switch.
                    I give a very brief but useful example of this below.
                </li><li>
                    Variables are always expanded in SQL, Special, and PL
                    commands if they are written like
                    <tt class="literal">*{VARNAME}</tt>
                    (assuming that a PL command has been run previously).
                    Your SQL scripts can give good feedback by echoing the
                    value of variables with the "\p" special command.
                </li><li><p>
                    A variable written like <tt class="literal">/VARNAME</tt> is
                    expanded if it <span class="emphasis"><em>begins</em></span> an SQL
                    Statement.
                    This usage is called <span class="emphasis"><em>PL Aliasing</em></span>.
                    See the 
                <a href="#pl_alias-section" title="PL Aliases">PL Aliases</a>
                    section below.
                </p></li><li>
                    Variables are normally written like 
                    <tt class="literal">*VARNAME</tt> in logical expressions to
                    prevent them from being evaluated too early.
                    See below about logical expressions.
                </li><li><p>
                    You can't do math with expression variables, but you
                    can get functionality like the traditional
                    <tt class="literal">for (i = 0; i &lt; x; i++)</tt> by appending
                    to a variable and testing the string length, like
                    <pre class="programlisting">
    * while (*i &lt; ${x})
        * i = *{i}.</pre>
                    <tt class="literal">i</tt> will be a growing line of dots.
                </p></li><li><p>
                Variable names must not contain white space, or
                the characters "}" or "=".
                </p></li></ul></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="pl_alias-section"></a>PL Aliases</h3></div></div><div></div></div><p>
                PL Aliasing just means the use of a PL variable as the first
                thing in an SQL statement, with the shortcut notation
                <tt class="literal">/VARNAME</tt>.
            </p><p>
                <tt class="literal">/VARNAME</tt> must be followed by whitespace
                or terminate the Statement, in order for SqlFile to tell
                where the variable name ends.
            </p><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>
                Note that PL aliases are a very different thing from
                SQL aliases or HSQLDB aliases, which are features of
                databases, not SqlFile.
            </p></div><p>
                If the value of a variable is an entire SQL command, you
                generally do not want to include the terminating ";" in
                the value.
                There is an example of this 
                <a href="#alias-example" title="Example&nbsp;8.2.&nbsp;Defining and using a PL alias (PL variable)">above</a>.
            </p><p>
            PL aliasing may only be used for SQL statements.
            You can define variables for everything in a Special or PL Command,
            except for the very first character ("\" or "*").
            Therefore, you can use variables other than alias variables in 
            Special and PL Commands.
            Here is a hyperbolically impractical example to show the extent to
            which PL variables can be used in Special commands even though you
            can not use them as PL aliases.
            <pre class="programlisting">
        sql&gt; * qq = p Hello Butch
        sql&gt; \*{qq} done now
        Hello Butch done now</pre>
            (Note that the \* here is not the special command "\*", but is
            the special command "\p" because "*{qq}" resolves to "p").
        </p></div><p>
                Here is a short SQL file that gives the specified user write
                permissions on some application tables.
            </p><div class="example"><a name="N11985"></a><p class="title"><b>Example&nbsp;8.8.&nbsp;Simple SQL file using PL</b></p><pre class="programlisting">
    /*
       grantwrite.sql

       Run SqlTool like this:
           java -jar path/to/hsqldb.jar -setvar USER=debbie grantwrite.sql
     */

    /* Explicitly turn on PL variable expansion, in case no variables have
       been set yet.  (Only the case if user did not set USER).
    */
    *

    GRANT all ON book TO *{USER};
    GRANT all ON category TO *{USER};</pre></div><p>
                Note that this script will work for any (existing) user just
                by supplying a different user name on the command-line.
                I.e., no need to modify the tested and proven script.
                There is no need for a <tt class="literal">commit</tt> statement
                in this SQL file since no DML is done.
                If the script is accidentally run without setting the
                USER variable, SqlTool will give a very clear notificaton of
                that.
            </p><p>
                The purpose of the plain "*" command is just
                so that the *{USER} variables will be expanded.
                (This would not be necessary if the USER variable, or any
                other variable, were set, but we don't want to depend upon 
                that).
            </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11993"></a>Logical Expressions</h3></div></div><div></div></div><p>
                Logical expressions occur only inside of logical expression
                parentheses in PL statements.
                For example, <tt class="literal">if (*var1 &gt; astring)</tt> and
                <tt class="literal">while (*checkvar)</tt>.
                (The parentheses after "foreach" do not enclose a logical
                expression, they just enclose a list).
            </p><p>
                There is a critical difference between 
                <tt class="literal">*{VARNAME}</tt> and <tt class="literal">*VARNAME</tt>
                inside logical expressions.
                <tt class="literal">*{VARNAME}</tt> is expanded one time when the
                parser first encounters the logical expression.
                <tt class="literal">*VARNAME</tt> is re-expanded every time that the
                expression is evaluated.
                So, you would never want to code
                <tt class="literal">* while (*{X} &lt; 5)</tt> because the statement
                will always be true or always be false.
                (I.e. the following block will loop infinitely or will never
                run).
            </p><p>
                Don't use quotes or whitespace of any kind in
                <tt class="literal">*{VARNAME}</tt> variables in expressions.
                (They would expand and then the expression would most likely
                no longer be a valid expression as listed in the table below).
                Quotes and whitespace are fine in <tt class="literal">*VARNAME</tt>
                variables, but it is the entire value that will be used in
                evaluations, regardless of whether quotes match up, etc.
                I.e. quotes and whitespace are not <span class="emphasis"><em>special</em></span>
                to the token evaluator.
            </p><div class="variablelist"><p class="title"><b>Logical Operators</b></p><dl><dt><span class="term">TOKEN</span></dt><dd>
                    The token may be a literal, a <tt class="literal">*{VARNAME}</tt>
                    which is expanded early, or a *VARNAME which is expanded 
                    late.
                    (You usually do not want to use 
                    <tt class="literal">*{VARNAME}</tt> in logical expressions).
                    False if the token is not set, empty, or "0".
                    True otherwise.
                </dd><dt><span class="term">TOKEN1 == TOKEN2</span></dt><dd>
                    True if the two tokens are equivalent "strings".
                </dd><dt><span class="term">TOKEN1 &lt;&gt; TOKEN2</span></dt><dd>
                    Ditto.
                </dd><dt><span class="term">TOKEN1 &gt;&lt; TOKEN2</span></dt><dd>
                    Ditto.
                </dd><dt><span class="term">TOKEN1 &gt; TOKEN2</span></dt><dd>
                    True if the TOKEN1 string is longer than TOKEN2 or is
                    the same length but is greater according to a string sort.
                </dd><dt><span class="term">TOKEN1 &lt; TOKEN2</span></dt><dd>
                    Similarly to TOKEN1 &gt; TOKEN2.
                </dd><dt><span class="term">! LOGICAL_EXPRESSION</span></dt><dd>
                    Logical negation of any of the expressions listed above.
                </dd></dl></div><p>
                *VARNAMEs in logical expressions, where the VARNAME variable
                is not set, evaluate to an empty string.
                Therefore <tt class="literal">(*UNSETVAR = 0)</tt> would be false,
                even though <tt class="literal">(*UNSETVAR)</tt> by itself is false
                and <tt class="literal">(0)</tt> by itself is false.
            </p><p>
                When developing scripts, you definitely use SqlTool 
                interactively to verify that SqlTool evaluates logical 
                expressions as you expect.
                Just run <tt class="literal">* if</tt> commands that print something
                (i.e. \p) if the test expression is true.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11A0C"></a>Flow Control</h3></div></div><div></div></div><p>
                Flow control works by conditionally executing blocks of 
                Commands according to conditions specified by logical 
                expressions.
            </p><p>
                The conditionally executed blocks are called 
                <span class="emphasis"><em>PL Blocks</em></span>.
                These PL Blocks always occur between a PL flow control 
                statement (like <tt class="literal">* foreach, *while, * if</tt>)
                and a corresponding <tt class="literal">* end</tt> PL Command
                (like <tt class="literal">* end foreach</tt>).
            </p><div class="caution" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Caution</h3><p>
                Be aware that the PL block reader is ignorant about SQL 
                statements and comments when looking for the end of the block.
                It just looks for lines beginning with some specific PL commands.
                Therefore, if you put a comment line before a PL statement, 
                or if a line of a multi-line SQL statement has a line beginning
                with a PL command, things may break.
                </p><p>
                I am not saying that you shouldn't use PL commands or SQL
                commands inside of PL blocks-- you definitely should!
                I'm saying that in PL blocks you should not have lines inside 
                of SQL statments or comments which could be mistaken for PL 
                commands.
                (Especially, "commenting out" PL end statements will not work
                if you leave <tt class="literal">* end</tt> at the beginning of the
                line).
                </p><p>
                (This limitation will very likely be removed in a future 
                version of SqlTool).
            </p></div><p>
                The values of control variables for foreach and while PL
                blocks will change as expected.
            </p><p>
                There are <tt class="literal">* break</tt> and 
                <tt class="literal">* continue</tt>, which work as any shell
                scripter would expect them to.
                The <tt class="literal">* break</tt> command can also be used to
                quit the current SQL file without triggering any error 
                processing.
                (I.e. processing will continue with the next line in the 
                <span class="emphasis"><em>including</em></span> SQL file or interactive 
                session, or with the next SQL file if you supplied multiple on 
                the command-line).
            </p></div><p>
            Below is an example SQL File that shows how to use most PL 
            features.  If you have a question about how to use a particular PL 
            feature, check this example before asking for help.
            This file resides in the
            <tt class="filename">src/org/hsqldb/sample</tt> directory with the
            name <tt class="filename">pl.sql</tt>.
            Definitely give it a run, like <pre class="screen">
java -jar $HSQLDB_HOME/lib/hsqldb.jar mem $HSQLDB_HOME/src/org/hsqldb/sample/pl.jar</pre>
        </p><div class="example"><a name="N11A4E"></a><p class="title"><b>Example&nbsp;8.9.&nbsp;SQL File showing use of most PL features</b></p><pre class="programlisting">/*
    $Id: pl.sql,v 1.4 2005/05/02 15:07:26 unsaved Exp $
    SQL File to illustrate the use of SqlTool PL features.
    Invoke like
        java -jar .../hsqldb.jar .../pl.sql mem
                                                         -- blaine
*/

* if (! *MYTABLE)
    \p MYTABLE variable not set!
    /* You could use \q to Quit SqlTool, but it's often better to just
       break out of the current SQL file.
       If people invoke your script from SqlTool interactively (with
       \i yourscriptname.sql) any \q will kill their SqlTool session. */
    \p Use arguments "--setvar MYTABLE=mytablename" for SqlTool
    * break
* end if

/* Turning on Continue-upon-errors so that we can check for errors ourselves.*/
\c true

\p
\p Loading up a table named '*{MYTABLE}'...

/* This sets the PL variable 'retval' to the return status of the following
   SQL command */
* retval ~
CREATE TABLE *{MYTABLE} (
    i int,
    s varchar
);
\p CREATE status is *{retval}
\p

/* Validate our return status.  In logical expressions, unset variables like
   *unsetvar are equivalent to empty string, which is not equal to 0
   (though both do evaluate to false on their own, i.e. (*retval) is false
   and (0) is false */
* if (*retval != 0)
    \p Our CREATE TABLE command failed.
    * break
* end if

/* Default Continue-on-error behavior is what you usually want */
\c false
\p

/* Insert data with a foreach loop.
   These values could be from a read of another table or from variables
   set on the command line like
*/
\p Inserting some data int our new table (you should see 3 row update messages)
* foreach VALUE (12 22 24 15)
    * if (*VALUE &gt; 23)
        \p Skipping *{VALUE} because it is greater than 23
        * continue
        \p YOU WILL NEVER SEE THIS LINE, because we just 'continued'.
    * end if
    INSERT INTO *{MYTABLE} VALUES (*{VALUE}, 'String of *{VALUE}');
* end foreach
\p

* themax ~
/* Can put Special Commands and comments between "* VARNAME ~" and the target 
   SQL statement. */
\p We're saving the max value for later.  You'll still see query output here:
SELECT MAX(i) FROM *{MYTABLE};

/* This is usually unnecessary because if the SELECT failed, retval would
   be undefined and the following print statement would make SqlTool exit with
   a failure status */
* if (! *themax)
    \p Failed to get the max value.
    /* It's possible that the query succeeded but themax is "0".
       You can check for that if you need to. */
    * break
    \p YOU WILL NEVER SEE THIS LINE, because we just 'broke'.
* end if

\p
\p ##############################################################
\p The results of our work:
SELECT * FROM *{MYTABLE};
\p MAX value is *{themax}

\p
\p Everything worked.
</pre></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="chunk-section"></a>Chunking</h2></div></div><div></div></div><p>
            We hereby call the ability to transmit multiple SQL commands to
            the database in one transmission <span class="emphasis"><em>chunking</em></span>.
            Unless you are in Raw mode, SqlTool only transmits commands to the
            database engine when it reads in a ";" at the end of a line of an
            SQL command.
            Therefore, you normally want to end each and every SQL command 
            with ";" at the end of a line.
            This is because the database can only send one status reply to
            each JDBC transmission.
            So, while you could run
        <div class="informalexample"><pre class="screen">
    SELECT * FROM t1; SELECT * FROM t2;</pre></div>
            SqlTool can only display the results from the last query.
            This is a limitation of the client/server nature of JDBC, and
            applies to any JDBC client.
            There are, however, situations where you don't need immediate
            feedback from every SQL command.  For example,
        <div class="example"><a name="N11A63"></a><p class="title"><b>Example&nbsp;8.10.&nbsp;Single-line chunking example</b></p><pre class="screen">
    INSERT INTO t1 VALUES(0); SELECT * FROM t1;</pre></div>
            It's useful because the output of the second SQL command will tell
            you whether the first SQL command succeeded.  So, you won't miss
            the status output from the first command.
        </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11A6A"></a>Why?</h3></div></div><div></div></div><p>
                The first general reason to chunk SQL commands is performance.
                For standalone databases, the most common performance 
                bottleneck is network latency.
                Chunking SQL commands can dramatically reduce network traffic.
            </p><p>
                The second general reason to chunk SQL commands is if your
                database requires you to send multiple commands in one
                transmission.
                This is often the case when you need to tell the database
                the SQL or PL/SQL commands that comprise a stored procedure,
                function, trigger, etc.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11A71"></a>How?</h3></div></div><div></div></div><p>
                The most simple way is enter as many SQL commands as you 
                want, but just do not end a line with ";" until you want
                the chunk to transmit.
                <div class="example"><a name="N11A76"></a><p class="title"><b>Example&nbsp;8.11.&nbsp;Multi-line chunking example</b></p><pre class="screen">
    INSERT INTO t1 VALUES (1)
    ; INSERT INTO t1 VALUES (2)
    ; SELECT * FROM t1;</pre></div>
                If you list your command history with \s, you will see that
                all 3 SQL commands in 3 lines are in one SqlTool command.
                You can recall this SqlTool command from history to
                re-execute all three SQL commands.
            </p><p>
                The other method is by using 
                <a href="#raw-section" title="Raw Mode">Raw Mode</a>.
                Go to the
                <a href="#raw-section" title="Raw Mode">Raw Mode</a> section
                to see how.
                You can enter any text at all, exactly how you want it to
                be sent to the database engine.
                Therefore, in addition to chunking SQL commands, you can
                give commands for non-SQL extensions to the database.
                For example, you could enter JavaScript code to be used
                in a stored procedure.
            </p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="raw-section"></a>Raw Mode</h2></div></div><div></div></div><p>
            You begin raw mode by issuing the Special Command "\.".
            You can then enter as much text in any format you want.
            When you are finished, enter a line consisting of only ".".
            If you are running SqlTool interactively, you'll notice that
            your prompt will be the continuation prompt until you enter
            the "." line.
        </p><p>
            When you terminate raw entry with the "\." line, the command
            does not <span class="emphasis"><em>execute</em></span>, it just goes into the
            command buffer.
            If running interactively, you can look at the buffer with the
            ":l" Buffer Command.
            What you will normally want to do is to enter the Buffer Command
            ":;" to transmit the buffer to the database engine.
        </p><p>
            <div class="example"><a name="N11A95"></a><p class="title"><b>Example&nbsp;8.12.&nbsp;Raw Mode example</b></p><pre class="screen">
    sql&gt; \.
    Enter RAW SQL.  No \, :, * commands.  End with a line containing only ".":
    raw&gt; line one;
      +&gt; line two;
      +&gt; line three;
      +&gt; .
    Raw SQL chunk moved into buffer.  Run ":;" to execute the chunk.
    sql&gt; :;
    Executing command from buffer:
    line one;
    line two;
    line three;

    SQL Error at 'stdin' line 13:
    "line one;
    line two;
    line three;"
    Unexpected token: LINE in statement [line]
    sql&gt;</pre></div>
            The error message "Unexpected token: LINE in statement [line]"
            comes from the database engine, not SqlTool.
            All three lines were transmitted to the database engine.
        </p><p>
            Buffer Commands are generally unavailable when runninb SqlTool
            interactively.
            However, the command ":;", and the command buffer have been
            enabled for non-interactive use, because they are required for
            using raw mode, and it is definitely useful to be able to
            use raw mode in SQL files.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N11A9E"></a>PL/SQL</h2></div></div><div></div></div><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>
            PL/SQL is <span class="bold"><b>not</b></span> the same as
            PL.  PL is the procedural language of SqlFile and is 
            independent of your back-end database.
            PL commands always begin with *.
            PL/SQL is processed on the server side and you can only use
            it of your database supports it.
            You can not intermix PL and PL/SQL (except for setting a
            PL variable to the output of PL/SQL execution), because when
            you enter PL/SQL to SqlTool that input is not processed
            by SqlFile.
        </p></div><p>
            Use <a href="#raw-section" title="Raw Mode">Raw Mode</a> to send
            PL/SQL code blocks to the database engine.
            You do not need to enter the "\." command to enter raw mode.
            Just begin a new SqlTool command line with "DECLARE" or 
            "BEGIN", and SqlTool will automatically put you into raw mode.
            See the <a href="#raw-section" title="Raw Mode">Raw Mode</a>
            section for details.
        </p><p>
            The following sample SQL file resides at 
            <tt class="filename">src/org/hsqldb/sample/plsql.sql</tt> in your
            HSQLDB distribution.
            This script will only work if your database engine supports
            standard PL/SQL, if you have permission to create the table
            "T1" in the default schema, and if that object does not 
            already exist.
            <div class="example"><a name="N11AB8"></a><p class="title"><b>Example&nbsp;8.13.&nbsp;PL/SQL Example</b></p><pre class="programlisting">/*
 * $Id: plsql.sql,v 1.3 2005/05/02 15:09:11 unsaved Exp $
 *
 * This example is copied from the "Simple Programs in PL/SQL"
 * example by Yu-May Chang, Jeff Ullman, Prof. Jennifer Widom at
 * the Standord University Database Group's page
 * http://www-db.stanford.edu/~ullman/fcdb/oracle/or-plsql.html .
 * I have only removed some blank lines (because you can't use blank
 * lines inside of SQL commands in non-raw mode SqlTool when running
 * it interactively); and, at the bottom I have  replaced the
 * client-specific, non-standard command "run;" with SqlTool's
 * corresponding command ":;" and added a plain SQL SELECT command
 * to show whether the PL/SQL code worked.  - Blaine
 */

CREATE TABLE T1(
    e INTEGER,
    f INTEGER
);

DELETE FROM T1;

INSERT INTO T1 VALUES(1, 3);

INSERT INTO T1 VALUES(2, 4);

/* Above is plain SQL; below is the PL/SQL program. */
DECLARE

    a NUMBER;

    b NUMBER;

BEGIN

    SELECT e,f INTO a,b FROM T1 WHERE e&gt;1;

    INSERT INTO T1 VALUES(b,a);

END;

.

/**************************************************************************/
/* Remaining SqlTool-specific code added by Blaine Simpson of the 
 * HSQLDB Development Group.
 */

:;

/* This should show 3 rows, one containing values 4 and 2 (in this order)...*/
SELECT * FROM t1;
</pre></div>
            Note that, inside of raw mode, you can use any kind of formatting
            you want:  Whatever you enter--  blank lines, comments,
            everything-- will be transmitted to the database engine.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N11ABF"></a>Using hsqltool.jar and hsqldbutil.jar</h2></div></div><div></div></div><p>
            This section is only for those users who want to use SqlTool
            but without the overhead of hsqldb.jar.
        </p><p>
            If you do not need to directly use JDBC URLs like
            <tt class="literal">jdbc:hsqldb:mem:</tt> + something,
            <tt class="literal">jdbc:hsqldb:file:</tt> + something, or
            <tt class="literal">jdbc:hsqldb:res:</tt> + something,
            then you can use <tt class="filename">hsqltool.jar</tt> in place of
            the much larger <tt class="filename">hsqldb.jar</tt> file.
            <tt class="filename">hsqltool.jar</tt> will work for all JDBC
            databases other than HSQLDB Memory-only and In-process databases
            (the latter are fine if you access them via a HSQLB Server or
            WebServer).
            You will have to supply the JDBC driver for non-HSQLDB URLs, of
            course.
        </p><p>
            <tt class="filename">hsqltool.jar</tt> includes the HSQLDB JDBC
            driver.
            If you do not need to connect to HSQLDB databases at all, 
            then <tt class="filename">hsqldbutil.jar</tt> is what you need.
            <tt class="filename">hsqldbutil.jar</tt> contains everything you
            need to run <tt class="filename">SqlTool</tt> and
            <tt class="filename">DatabaseManagerSwing</tt> against non-HSQLDB
            databases... well, besides the JDBC drivers for the target
            databases.
        </p><p>
            The HSQLDB distribution doesn't "come with" a pre-built 
            <tt class="filename">hsqltool.jar</tt> and
            <tt class="filename">hsqldbutil.jar</tt> files.
            You should build the <span class="emphasis"><em>hsqltool</em></span> 
            or <span class="emphasis"><em>hsqldbutil</em></span> target, as explained in the 
            <a href="#building-appendix" title="Appendix&nbsp;A.&nbsp;Building HSQLDB">Building HSQLDB</a>
            appendix.
        </p><p>
            If you are using the HSQLDB JDBC driver (i.e., you're connecting
            up to a URL like jdbc:hsqldb:hsql + something or
            jdbc:hsqldb:http + something), you run SqlTool exactly as with
            hsqldb.jar except you use the file path to your new jar file
            instead of the path to <tt class="filename">hsqldb.jar</tt>.
        </p><p>
            If you are using a non-HSQLDB JDBC driver, follow the instructions
            at the end of the
            <a href="#baremin-section" title="The Bare Minimum You Need to Know to Run SqlTool">The Bare Minimum</a> section,
            but use your new file in place of <tt class="filename">hsqldb.jar</tt>.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N11B18"></a>Character-Separated-Value Imports and Exports</h2></div></div><div></div></div><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>
            These features were added for version 1.8.0.3 of HSQLDB.
        </p></div><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>
            This feature is independent of HSQLDB 
            <a href="#texttables-chapter" title="Chapter&nbsp;6.&nbsp;Text Tables">Text Tables</a>,
            a server-side feature of HSQLDB.
            It makes no difference to SqlTool whether the source or target
            table of your export/import is a memory, cache, or text table.
            Indeed, like all features of SqlTool, it works fine with other
            JDBC databases.
            It works great, for example to migrate data from a table
            of one type to a table of another type, or to another schema,
            or to another database instance, or to another database system.
        </p></div><p>
            Because of common usage of the term, I call this feature
            <span class="emphasis"><em>CSV</em></span> imports and exports, even though the
            delimiters are not constrained to single characters, but
            may be any String.
            Use the <tt class="literal">\x</tt> command to eXport a table to a
            CSV file, and the <tt class="literal">\m</tt> command to iMport a
            CSV file into a pre-existing table.
        </p><p>
            Just as the delimiter capability is more general than traditional
            CSV delimiters, the export function is also more general than
            just a table data exporter.
            Besides the trivial generalization that you may specify a
            view or other virtual table name in place of a table name,
            you can alternatively export the output of any query which 
            produces normal text output.
            A benefit to this approach is that it allows you to export only
            some columns of a table, and to specify a WHERE clause to narrow 
            down the rows to be exported (or perform any other SQL 
            transformation, mapping, join, etc.).
            One specific use for this would be to exclude columns of
            binary data (which can be exported by other means, such as
            a PL loop to store binary values to files with the \bd command).
        </p><p>
            Note that the import command will not create a new table.
            This is because of the impossibility of guessing appropriate
            types and constraints based only on column names and a data
            sampling (which is all that a CSV-importer has access to).
            Therefore, if you wish to populate a new table, create the
            table before running the import.
            The import file does not need to have data for all columns of a
            table.
            The only required columns are those required by non-null and
            FK constraints.
            One specific reason to omit columns is if you want values of
            some columns to be created automatically by column DEFAULT
            settings, triggers, HSQLDB identity sequences, etc.
            Another reason would be to skip binary columns.
        </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11B36"></a>Simple CSV exports and imports using default settings</h3></div></div><div></div></div><p>
                Even if you need to change delimiters, table names, or file
                names from the defaults, I suggest that you run one export
                and import with default settings as a practice run.
                A memory-only HSQLDB instance is ideal for test runs like this.
            </p><p>
                This command exports the table <tt class="literal">icf.projects</tt>
                to the file <tt class="filename">projects.csv</tt> in the current
                directory (where you invoked SqlTool from).
                By default, the output file name will be the specified source
                table name plus the extension <tt class="literal">.csv</tt>.
                <div class="example"><a name="N11B49"></a><p class="title"><b>Example&nbsp;8.14.&nbsp;CSV Export Example</b></p><pre class="screen">    SET SCHEMA icf;
    \x projects
</pre></div>
                We could also have run <tt class="literal">\x icf.projects</tt>
                (which would have created a file named 
                <tt class="filename">icf.projects.csv</tt>)
                instead of changing the session schema.
                In this example we have chosen to make the export file name
                independent of the schema to facilitate importing it into
                a different schema.
            </p><p>
                Take a look at the output file.
                Notice that the first line consists of column names, not
                data.
                This line is present because it will be needed if the file is
                to used for a CSV import.
                Notice the following characterstics about the export data.
                The column delimiter is the pipe character "|".
                The record delimiter is the default line delimiter character(s)
                for your operating system.
                The string used to represent database <tt class="literal">NULL</tt>s
                is <tt class="literal">[null]</tt>.
                See the next section for how to change these from their default
                values.
            </p><p>
                This command imports the data from the file
                <tt class="filename">projects.csv</tt> in the current
                directory (where you invoked SqlTool from) into the table
                <tt class="literal">newschema.projects</tt>.
                By default, the output table name will be the input filename
                after removing optional leading directory and trailing final
                extension.
                <div class="example"><a name="N11B6C"></a><p class="title"><b>Example&nbsp;8.15.&nbsp;CSV Import Example</b></p><pre class="screen">    SET SCHEMA newschema;
    \m projects.csv
</pre></div>
                If the CSV file was named with the target schema, you would
                have skipped the <tt class="literal">SET SCHEMA</tt> command, like
                <tt class="literal">\m newschema.projects.csv</tt>.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11B7B"></a>Specifying queries, delimiters, file names, table names,
                columns</h3></div></div><div></div></div><p>
                The header line in the CSV file is required at this time.
                (If there is user demand, it can be made optional for
                exporting, but it will remain required for importing).
            </p><p>
                Your export will fail if the column or record delimiter, or
                the null representation value occurs in the data being
                exported.
                You change these values by setting the PL variables
                <tt class="literal">*CSV_COL_DELIM</tt>,
                <tt class="literal">*CSV_ROW_DELIM</tt>,
                <tt class="literal">*CSV_NULL_REP</tt>.
                Notice that the asterisk is part of the variable names, to
                indicate that these variables are used by SqlTool internally.
                You can use the escape sequences \n, \r, and \t in the
                usual manner.
                For example, to change the column delimiter to the tab character,
                you would give the command
                <div class="informalexample"><pre class="screen">
    * *CSV_COL_DELIM = \t</pre></div>
            </p><p>
                For imports, you must always specify the source CSV file path.
                If you want to <span class="emphasis"><em>export</em></span> to a different file 
                than one in the current directory named according to the source
                table, set the PL variable <tt class="literal">*CSV_FILEPATH</tt>,
                like
                <div class="informalexample"><pre class="screen">
    * *CSV_FILEPATH = /tmp/dtbl.csv</pre></div>
            </p><p>
                For exports, you must always specify the source table name
                or query.
                If you want to <span class="emphasis"><em>import</em></span> to a table other 
                than that derived from
                the input CSV file name, set the PL variable
                <tt class="literal">*CSV_TABLENAME</tt>.
                The table name may contain a schema name prefix.
            </p><p>
                At this time, you must import all columns that have data in
                the CSV file.
                If there is demand to specify an optional list of columns to
                import, I'll gladly add that feature.
            </p><p>
                You can specify a query instead of a tablename with the
                \x command in order to filter or transform data from a table
                or view, or to export the output of a join, etc.
                You must set the PL variable <tt class="literal">*CSV_FILEPATH</tt>,
                as explained above (since there is no table name from which to
                automatically map a file name).
                <div class="example"><a name="N11BB2"></a><p class="title"><b>Example&nbsp;8.16.&nbsp;CSV Export of an Arbitrary SELECT Statement</b></p><pre class="screen">    * *CSV_FILEPATH = outfile.txt
    \x SELECT entrydate, 2 * aval "Double aval", modtime from bs.dtbl</pre></div>
                Note that I specified the column label alias "Double aval"
                so that the label for that column in the CSV file header will 
                not be blank.
            </p></div></div></div><div class="chapter" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="sqlsyntax-chapter"></a>Chapter&nbsp;9.&nbsp;SQL Syntax</h2></div><div><div class="authorgroup"><h3 class="corpauthor">The Hypersonic SQL Group</h3><div class="author"><h3 class="author"><span class="firstname">Fred</span> <span class="surname">Toussi</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:ft@cluedup.com">ft@cluedup.com</a>&gt;</tt></div><div class="author"><h3 class="author"><span class="firstname">Peter</span> <span class="surname">Hudson</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div></div><div class="author"><h3 class="author"><span class="firstname">Joe</span> <span class="surname">Maher</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:jrmaher@ameritech.net">jrmaher@ameritech.net</a>&gt;</tt></div><h4 class="editedby">Edited by</h4><h3 class="editor"><span class="firstname">Blaine</span> <span class="surname">Simpson</span></h3></div></div><div><p class="pubdate">$Date: 2005/11/06 22:13:26 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N11BFC">Notational Conventions Used in this Chapter</a></span></dt><dt><span class="section"><a href="#N11C19">SQL Commands</a></span></dt><dd><dl><dt><span class="section"><a href="#alter_index-section">ALTER INDEX</a></span></dt><dt><span class="section"><a href="#alter_sequence-section">ALTER SEQUENCE</a></span></dt><dt><span class="section"><a href="#N11C38">ALTER SCHEMA</a></span></dt><dt><span class="section"><a href="#alter_table-section">ALTER TABLE</a></span></dt><dt><span class="section"><a href="#alter_user-section">ALTER USER</a></span></dt><dt><span class="section"><a href="#call-section">CALL</a></span></dt><dt><span class="section"><a href="#checkpoint-section">CHECKPOINT</a></span></dt><dt><span class="section"><a href="#commit-section">COMMIT</a></span></dt><dt><span class="section"><a href="#connect-section">CONNECT</a></span></dt><dt><span class="section"><a href="#create_alias-section">CREATE ALIAS</a></span></dt><dt><span class="section"><a href="#create_index-section">CREATE INDEX</a></span></dt><dt><span class="section"><a href="#create_role-section">CREATE ROLE</a></span></dt><dt><span class="section"><a href="#N11D63">CREATE SCHEMA</a></span></dt><dt><span class="section"><a href="#create_sequence-section">CREATE SEQUENCE</a></span></dt><dt><span class="section"><a href="#create_table-section">CREATE TABLE</a></span></dt><dt><span class="section"><a href="#create_trigger-section">CREATE TRIGGER</a></span></dt><dt><span class="section"><a href="#create_user-section">CREATE USER</a></span></dt><dt><span class="section"><a href="#create_view-section">CREATE VIEW</a></span></dt><dt><span class="section"><a href="#delete-section">DELETE</a></span></dt><dt><span class="section"><a href="#disconnect-section">DISCONNECT</a></span></dt><dt><span class="section"><a href="#drop_index-section">DROP INDEX</a></span></dt><dt><span class="section"><a href="#N11ED7">DROP ROLE</a></span></dt><dt><span class="section"><a href="#drop_sequence-section">DROP SEQUENCE</a></span></dt><dt><span class="section"><a href="#N11EF1">DROP SCHEMA</a></span></dt><dt><span class="section"><a href="#drop_table-section">DROP TABLE</a></span></dt><dt><span class="section"><a href="#drop_trigger-section">DROP TRIGGER</a></span></dt><dt><span class="section"><a href="#drop_user-section">DROP USER</a></span></dt><dt><span class="section"><a href="#drop_view-section">DROP VIEW</a></span></dt><dt><span class="section"><a href="#explain-section">EXPLAIN PLAN</a></span></dt><dt><span class="section"><a href="#grant-section">GRANT</a></span></dt><dt><span class="section"><a href="#insert-section">INSERT</a></span></dt><dt><span class="section"><a href="#revoke-section">REVOKE</a></span></dt><dt><span class="section"><a href="#rollback-section">ROLLBACK</a></span></dt><dt><span class="section"><a href="#savepoint-section">SAVEPOINT</a></span></dt><dt><span class="section"><a href="#script-section">SCRIPT</a></span></dt><dt><span class="section"><a href="#select-section">SELECT</a></span></dt><dt><span class="section"><a href="#set_autocommit-section">SET AUTOCOMMIT</a></span></dt><dt><span class="section"><a href="#collation-section">SET DATABASE COLLATION</a></span></dt><dt><span class="section"><a href="#N1208B">SET CHECKPOINT DEFRAG</a></span></dt><dt><span class="section"><a href="#set_ignorecase-section">SET IGNORECASE</a></span></dt><dt><span class="section"><a href="#set_initialschema-section">SET INITIAL SCHEMA </a></span></dt><dt><span class="section"><a href="#set_logsize-section">SET LOGSIZE</a></span></dt><dt><span class="section"><a href="#set_password-section">SET PASSWORD</a></span></dt><dt><span class="section"><a href="#set_property-section">SET PROPERTY</a></span></dt><dt><span class="section"><a href="#set_refint-section">SET REFERENTIAL INTEGRITY</a></span></dt><dt><span class="section"><a href="#set_schema-section">SET SCHEMA</a></span></dt><dt><span class="section"><a href="#set_scriptformat-section">SET SCRIPTFORMAT</a></span></dt><dt><span class="section"><a href="#set_table_index-section">SET TABLE INDEX</a></span></dt><dt><span class="section"><a href="#set_table_readonly-section">SET TABLE READONLY</a></span></dt><dt><span class="section"><a href="#set_table_source-section">SET TABLE SOURCE</a></span></dt><dt><span class="section"><a href="#set_write_delay-section">SET WRITE DELAY</a></span></dt><dt><span class="section"><a href="#shutdown-section">SHUTDOWN</a></span></dt><dt><span class="section"><a href="#update-section">UPDATE</a></span></dt></dl></dd><dt><span class="section"><a href="#schemanaming-section">Schema object naming</a></span></dt><dt><span class="section"><a href="#datatypes-section">Data Types</a></span></dt><dt><span class="section"><a href="#N12364">SQL Comments</a></span></dt><dt><span class="section"><a href="#stored-section">Stored Procedures / Functions</a></span></dt><dt><span class="section"><a href="#N12395">Built-in Functions and Stored Procedures</a></span></dt><dt><span class="section"><a href="#expression-section">SQL Expression</a></span></dt></dl></div><p>HSQLDB version 1.8.0 supports the SQL statements and syntax described
  in this chapter.</p><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N11BFC"></a>Notational Conventions Used in this Chapter</h2></div></div><div></div></div><p><tt class="literal">[A]</tt> means A is optional.</p><p><tt class="literal">{ B | C }</tt> means either B or C must be
    used.</p><p><tt class="literal">[{ B | C }]</tt> means either B or C may optionally be
    used, or nothing at all.</p><p><tt class="literal">(</tt> and <tt class="literal">)</tt> are the actual
    characters '(' and ')' used in statements.</p><p>UPPERCASE words are keywords</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N11C19"></a>SQL Commands</h2></div></div><div></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="alter_index-section"></a>ALTER INDEX<sup>[<a href="#ftn.posthyper" name="posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">ALTER INDEX &lt;indexname&gt; RENAME TO &lt;newname&gt;;</pre><p>Index names can be changed so long as they do not conflict with
      other user-defined or sytem-defined names.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="alter_sequence-section"></a>ALTER SEQUENCE<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">ALTER SEQUENCE &lt;sequencename&gt; RESTART WITH &lt;value&gt;;</pre><p>Resets the next value to be returned from the sequence.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11C38"></a>ALTER SCHEMA<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">ALTER SCHEMA &lt;schemaname&gt; RENAME TO &lt;newname&gt;;</pre><p>Renames the schema as specified. All objects of the schema will
      hereafter be accessible only with the new schema name.</p><p>Requires Administrative privileges.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="alter_table-section"></a>ALTER TABLE<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">ALTER TABLE &lt;tablename&gt; ADD [COLUMN] &lt;columnname&gt; <a href="#datatypes-section" title="Data Types">Datatype</a>
    [(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;];</pre><p>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;.</p><p>It accepts a <a href="#columnDef-entry">columnDefinition</a> 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.</p><p>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.</p><pre class="programlisting">ALTER TABLE &lt;tablename&gt; DROP [COLUMN] &lt;columnname&gt;;</pre><p>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.</p><p>It will also fail if an SQL view includes the column.</p><pre class="programlisting">ALTER TABLE &lt;tablename&gt; ALTER COLUMN &lt;columnname&gt; RENAME TO &lt;newname&gt; </pre><p>Changes a column name.</p><pre class="programlisting">ALTER TABLE &lt;tablename&gt; ALTER COLUMN &lt;columnname&gt; SET DEFAULT &lt;defaultvalue&gt;};</pre><p>Adds the specified default value to the column. Use NULL to remove
      a default.</p><pre class="programlisting">ALTER TABLE &lt;tablename&gt; ALTER COLUMN &lt;columnname&gt; SET [NOT] NULL</pre><p>Sets or removes a NOT NULL constraint for the column.</p><pre class="programlisting">ALTER TABLE &lt;tablename&gt; ALTER COLUMN &lt;columnDefinition&gt;;</pre><p>This form of ALTER TABLE ALTER COLUMN accepts a <a href="#columnDef-entry">columnDefinition</a> as in a CREATE
      TABLE command, with the following restrictions.</p><div class="itemizedlist"><p class="title"><b>Restrictions</b></p><ul type="disc"><li>The column must be already be a PK column to accept an
        IDENTITY definition.</li><li>If the column is already an IDENTITY column and there is no
        IDENTITY definition, the existing IDENTITY attribute is
        removed.</li><li>The default expression will be that of the new definition,
        meaning an existing default can be dropped by ommission, or a new
        default added.</li><li>The NOT NULL attribute will be that of the new definition
        (similar to previous item).</li><li>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.</li></ul></div><pre class="programlisting">ALTER TABLE &lt;tablename&gt; ALTER COLUMN &lt;columnname&gt;
    RESTART WITH &lt;new sequence value&gt;</pre><p>This form is used exclusively for IDENTITY columns and changes the
      next automatic value for the identity sequence.</p><pre class="programlisting">ALTER TABLE &lt;tablename&gt; ADD [CONSTRAINT &lt;constraintname&gt;]
    CHECK (&lt;search condition&gt;);</pre><p>Adds a check constraint to the table. In the current version, a
      check constraint can reference only the row being inserted or
      updated.</p><pre class="programlisting">ALTER TABLE &lt;tablename&gt; ADD [CONSTRAINT &lt;constraintname&gt;] UNIQUE (&lt;column list&gt;);</pre><p>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;.</p><p>This will work only if the values of the column list for the
      existing rows are unique or include a null value.</p><pre class="programlisting">ALTER TABLE &lt;tablename&gt; ADD [CONSTRAINT &lt;constraintname&gt;]
    PRIMARY KEY (&lt;column list&gt;);</pre><p>Adds a primary key constraint to the table, using the same
      constraint syntax as when the primary key is specified in a table
      definition.</p><pre class="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}];</pre><p>Adds a foreign key constraint to the table, using the same
      constraint syntax as when the foreign key is specified in a table
      definition.</p><p>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.</p><pre class="programlisting">ALTER TABLE &lt;tablename&gt; DROP CONSTRAINT &lt;constraintname&gt;;</pre><p>Drop a named unique, check or foreign key constraint from the
      table.</p><pre class="programlisting">ALTER TABLE &lt;tablename&gt; RENAME TO &lt;newname&gt;;</pre></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="alter_user-section"></a>ALTER USER<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">ALTER USER &lt;username&gt; SET PASSWORD &lt;password&gt;;</pre><p>Changes the password for an existing user. Password must be double
      quoted. Use "" for an empty password.</p><p>DBA's may change users' base default schema name with the comand
      <pre class="programlisting">ALTER USER &lt;username&gt; SET INITIAL SCHEMA &lt;schemaname&gt;;</pre>
      This is the schema which database object names will resolve to for this
      user, unless overridden as explained in <a href="#schemanaming-section" title="Schema object naming">Schema object naming</a>. 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).</p><p>Only an administrator may use these commands.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="call-section"></a>CALL</h3></div></div><div></div></div><pre class="programlisting">CALL <a href="#expression-section" title="SQL Expression">Expression</a>;</pre><p>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.</p><p>See also: <a href="#stored-section" title="Stored Procedures / Functions">Stored Procedures / Functions</a>, <a href="#expression-section" title="SQL Expression">SQL Expression</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="checkpoint-section"></a>CHECKPOINT</h3></div></div><div></div></div><pre class="programlisting">CHECKPOINT [DEFRAG<sup>[<a href="#ftn.posthyper">1</a>]</sup>];</pre><p>Closes the database files, rewrites the script file, deletes the
      log file and opens the database.</p><p>If DEFRAG is specified, this command also shrinks the .data file
      to its minimal size.</p><p>See also: <a href="#shutdown-section" title="SHUTDOWN">SHUTDOWN</a>, <a href="#set_logsize-section" title="SET LOGSIZE">SET LOGSIZE</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="commit-section"></a>COMMIT</h3></div></div><div></div></div><pre class="programlisting">COMMIT [WORK];</pre><p>Ends a transaction and makes the changes permanent.</p><p>See also: <a href="#rollback-section" title="ROLLBACK">ROLLBACK</a>, <a href="#set_autocommit-section" title="SET AUTOCOMMIT">SET AUTOCOMMIT</a>, <a href="#set_logsize-section" title="SET LOGSIZE">SET LOGSIZE</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="connect-section"></a>CONNECT</h3></div></div><div></div></div><pre class="programlisting">CONNECT USER &lt;username&gt; PASSWORD &lt;password&gt;;</pre><p>Connects to the database as a different user. Password should be
      double quoted. Use "" for an empty password.</p><p>See also: <a href="#grant-section" title="GRANT">GRANT</a>,
      <a href="#revoke-section" title="REVOKE">REVOKE</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="create_alias-section"></a>CREATE ALIAS</h3></div></div><div></div></div><pre class="programlisting">CREATE ALIAS &lt;function&gt; FOR &lt;javaFunction&gt;;</pre><p>Creates an alias for a static Java function to be used as a
          <a href="#stored-section" title="Stored Procedures / Functions">Stored Procedure</a>.
          The function must be accessible from the JVM in which the database 
          runs. Example:</p><div class="informalexample"><pre class="programlisting">    CREATE ALIAS ABS FOR "java.lang.Math.abs";</pre></div><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>
          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.
      </p></div><p>See also: <a href="#call-section" title="CALL">CALL</a>,
      <a href="#stored-section" title="Stored Procedures / Functions">Stored Procedures / Functions</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="create_index-section"></a>CREATE INDEX</h3></div></div><div></div></div><pre class="programlisting">CREATE [UNIQUE] INDEX &lt;index&gt; ON &lt;table&gt; (&lt;column&gt; [DESC] [, ...]) [DESC];</pre><p>Creates an index on one or more columns in a table.</p><p>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.</p><p>See also: <a href="#create_table-section" title="CREATE TABLE">CREATE TABLE</a>, <a href="#drop_index-section" title="DROP INDEX">DROP INDEX</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="create_role-section"></a>CREATE ROLE<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">CREATE ROLE &lt;rolename&gt;;</pre><p>Creates the named role with no members. Requires Administrative
      privileges.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11D63"></a>CREATE SCHEMA<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">CREATE SCHEMA &lt;schemaname&gt; AUTHORIZATION &lt;grantee&gt;
    [&lt;createStatement&gt; [&lt;grantStatement&gt;] [...];</pre><p>Creates the named schema, with ownership of the specified
      <span class="emphasis"><em>authorization</em></span>. The authorization grantee may be a
      database user or a role.</p><p>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.<div class="informalexample"><pre class="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;
</pre></div>
        Note that this example consists of one CREATE SCHEMA statement which
        is terminated by a semicolon.
    </p><p>Requires Administrative privileges.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="create_sequence-section"></a>CREATE SEQUENCE<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">CREATE SEQUENCE &lt;sequencename&gt; [AS {INTEGER | BIGINT}]
    [START WITH &lt;startvalue&gt;] [INCREMENT BY &lt;incrementvalue&gt;];</pre><p>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.</p><p>The next value for a sequence can be included in SELECT, INSERT
      and UPDATE statements as in the following example:</p><p>
        <div class="informalexample"><pre class="programlisting">SELECT [...,] NEXT VALUE FOR &lt;sequencename&gt; [, ...] FROM &lt;tablename&gt;;</pre></div>
      </p><p>In the proposed SQL 200n and in the current version, there is no
      way of retreiving the last returned value of a sequence.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="create_table-section"></a>CREATE TABLE</h3></div></div><div></div></div><pre class="programlisting">CREATE [MEMORY | CACHED | [GLOBAL] TEMPORARY | TEMP <sup>[<a href="#ftn.posthyper">1</a>]</sup> | TEXT<sup>[<a href="#ftn.posthyper">1</a>]</sup>] TABLE &lt;name&gt;
    ( &lt;columnDefinition&gt; [, ...] [, &lt;constraintDefinition&gt;...] )
    [ON COMMIT {DELETE | PRESERVE} ROWS];</pre><p>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.</p><div class="variablelist"><p class="title"><b>Components of a CREATE TABLE command</b></p><dl><dt><a name="columnDef-entry"></a><span class="term"><a name="columnDef-title"></a>columnDefinition</span></dt><dd><pre class="programlisting">columnname <a href="#datatypes-section" title="Data Types">Datatype</a> [(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]</pre><p>Default values that are allowed are constant values or
            certain SQL datetime functions.</p><div class="itemizedlist"><p class="title"><b>Allowed Default Values in Column Definitions</b></p><ul type="disc"><li><p>For character column, a single-quoted string or NULL.
                The only SQL function that can be used is CURRENT_USER.</p></li><li><p>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.</p></li><li><p>For BOOLEAN columns, the literals FALSE, TRUE,
                NULL.</p></li><li><p>For numeric columns, any valid number or NULL.</p></li><li><p>For binary columns, any valid hex string or NULL.</p></li></ul></div><p>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):</p><div class="informalexample"><pre class="programlisting">INSERT INTO Test (Id, Name) VALUES (NULL,'Test');
    CALL IDENTITY();</pre></div></dd><dt><span class="term">constraintDefinition</span></dt><dd><pre class="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}]<sup>[<a href="#ftn.posthyper">1</a>]</sup> |
    CHECK(&lt;search condition&gt;)<sup>[<a href="#ftn.posthyper">1</a>]</sup></pre><p>Both ON DELETE and ON UPDATE clauses can be used in a single
            foreign key definition.</p></dd><dt><span class="term">search condition</span></dt><dd><p>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 
            <tt class="literal">TestSelfCheckConstraints.txt</tt>. This file is in
            the /hsqldb/testrun/hsqldb/ directory of the zip.</p></dd><dt><span class="term">General syntax limitations</span></dt><dd><p>HSQLDB databases are initially created in a legacy mode that
            does not enforce column size and precision. You can set the
            property: <tt class="code">sql.enforce_strict_size=true</tt> 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, <tt class="code">SET PROPERTY
            "sql.enforce_strict_size" TRUE</tt> once before defining the
            tables.</p><p>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.</p><p>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.</p></dd></dl></div><p>See also: <a href="#drop_table-section" title="DROP TABLE">DROP TABLE</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="create_trigger-section"></a>CREATE TRIGGER<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="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;;</pre><p>TriggerClass is an application-supplied class that implements the
      <tt class="classname">org.hsqldb.Trigger</tt> 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.</p><p>Since 1.7.2 the implementation has been changed and enhanced. When
      the 'fire' method is called, it is passed the following
      arguments:</p><div class="informalexample"><pre class="programlisting">    fire (String name, String table, Object row1[], Object row2[])
</pre></div><p>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
      <a href="#datatypes-section" title="Data Types">Data Types</a>. For
      example, BIGINT is represented by a <tt class="filename">java.lang.Long
      Object</tt>. 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.</p><p>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
      <tt class="literal">jdbc:default:connection:</tt> URL is not currently
      supported.</p><p>Implementation note:</p><p>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.</p><p>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.</p><p>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.</p><p>Please refer to the code for <a href="../src/org/hsqldb/Trigger.html" target="_top">
          <tt class="classname">org.hsqldb.sample.Trigger</tt>
        </a> and <a href="../src/org/hsqldb/sample/TriggerSample.html" target="_top">
          <tt class="classname">org.hsqldb.sample.TriggerSample</tt>
        </a> for more information on how to write a trigger class.</p><p>See also: <a href="#drop_trigger-section" title="DROP TRIGGER">DROP TRIGGER</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="create_user-section"></a>CREATE USER</h3></div></div><div></div></div><pre class="programlisting">CREATE USER &lt;username&gt; PASSWORD &lt;password&gt; [ADMIN];</pre><p>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 <a href="#alter_user-section" title="ALTER USER">ALTER USER<sup>[<a href="#ftn.posthyper">1</a>]</sup></a> command.</p><p>Only an administrator can do this.</p><p>See also: <a href="#connect-section" title="CONNECT">CONNECT</a>, <a href="#grant-section" title="GRANT">GRANT</a>, <a href="#revoke-section" title="REVOKE">REVOKE</a>. <a href="#alter_user-section" title="ALTER USER">ALTER USER<sup>[<a href="#ftn.posthyper">1</a>]</sup></a>,</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="create_view-section"></a>CREATE VIEW<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="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;]];</pre><p>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:</p><div class="itemizedlist"><ul type="disc"><li><p>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.</p></li><li><p>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.</p></li><li><p>Join columns from multiple tables so that they look like a
          single table.</p></li><li><p>Aggregate information instead of supplying details. For
          example, present the sum of a column, or the maximum or minimum
          value from a column.</p></li></ul></div><p>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:</p><div class="informalexample"><pre class="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;</pre></div><p>You can then reference mealsjv in statements in the same way you
      would reference a table:</p><div class="informalexample"><pre class="programlisting">    SELECT * FROM mealsjv;</pre></div><p>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:</p><div class="informalexample"><pre class="programlisting">    CREATE VIEW mealswebv AS SELECT name, author FROM mealsjv;</pre></div><p>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.</p><div class="informalexample"><pre class="programlisting">    CREATE VIEW aview (new_name, new_author) AS
      SELECT name, author
      FROM mealsjv</pre></div><p>See also: <a href="#expression-section" title="SQL Expression">SQL Expression</a>, <a href="#select-section" title="SELECT">SELECT<sup>[<a href="#ftn.posthyper">1</a>]</sup></a>, <a href="#drop_view-section" title="DROP VIEW">DROP VIEW<sup>[<a href="#ftn.posthyper">1</a>]</sup></a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="delete-section"></a>DELETE</h3></div></div><div></div></div><pre class="programlisting">DELETE FROM table [WHERE Expression];</pre><p>Removes rows in a table.</p><p>See also: <a href="#expression-section" title="SQL Expression">SQL Expression</a>, <a href="#insert-section" title="INSERT">INSERT</a>, <a href="#select-section" title="SELECT">SELECT<sup>[<a href="#ftn.posthyper">1</a>]</sup></a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="disconnect-section"></a>DISCONNECT</h3></div></div><div></div></div><pre class="programlisting">DISCONNECT;</pre><p>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.</p><p>See also: <a href="#connect-section" title="CONNECT">CONNECT</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="drop_index-section"></a>DROP INDEX</h3></div></div><div></div></div><pre class="programlisting">DROP INDEX index [IF EXISTS];</pre><p>Removes the specified index from the database. Will not work if
      the index backs a UNIQUE of FOREIGN KEY constraint.</p><p>See also: <a href="#create_index-section" title="CREATE INDEX">CREATE INDEX</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11ED7"></a>DROP ROLE<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">DROP ROLE &lt;rolename&gt;;</pre><p>Removes all members from specified role, then removes the role
      itself.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="drop_sequence-section"></a>DROP SEQUENCE<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">DROP SEQUENCE &lt;sequencename&gt; [IF EXISTS] [RESTRICT | CASCADE];</pre><p>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
      <tt class="literal">CASCADE</tt> option to silently drop all dependent
      database objects.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N11EF1"></a>DROP SCHEMA<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">DROP SCHEMA &lt;schemaname&gt; [RESTRICT | CASCADE];</pre><p>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 <tt class="literal">CASCADE</tt> option to silently drop all
      database objects in the schema.</p><p>Requires Administrative privileges.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="drop_table-section"></a>DROP TABLE</h3></div></div><div></div></div><pre class="programlisting">DROP TABLE &lt;table&gt; [IF EXISTS] [RESTRICT | CASCADE];</pre><p>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.</p><p>The RESTRICT option is in effect by default, meaning that DROP
      will fail if any tables or views refer to this table. Specify the
      <tt class="literal">CASCADE</tt> option to silently drop all dependent views,
      and to drop any foreign key constraint that links this table with other
      tables.</p><p>See also:</p><p><a href="#create_table-section" title="CREATE TABLE">CREATE TABLE</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="drop_trigger-section"></a>DROP TRIGGER</h3></div></div><div></div></div><pre class="programlisting">DROP TRIGGER &lt;trigger&gt;;</pre><p>Removes a trigger from the database.</p><p>See also: <a href="#create_trigger-section" title="CREATE TRIGGER">CREATE TRIGGER<sup>[<a href="#ftn.posthyper">1</a>]</sup></a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="drop_user-section"></a>DROP USER</h3></div></div><div></div></div><pre class="programlisting">DROP USER &lt;username&gt;;</pre><p>Removes a user from the database.</p><p>Only an administrator do this.</p><p>See also: <a href="#create_user-section" title="CREATE USER">CREATE USER</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="drop_view-section"></a>DROP VIEW<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">DROP VIEW &lt;viewname&gt; [IF EXISTS] [RESTRICT | CASCADE];</pre><p>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
      <tt class="literal">CASCADE</tt> option to silently drop all dependent
      views.</p><p>See also: <a href="#create_view-section" title="CREATE VIEW">CREATE VIEW<sup>[<a href="#ftn.posthyper">1</a>]</sup></a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="explain-section"></a>EXPLAIN PLAN</h3></div></div><div></div></div><pre class="programlisting">EXPLAIN PLAN FOR { SELECT ... | DELETE ... | INSERT ... | UPDATE ..};</pre><p>EXPLAIN PLAN FOR can be used with any query to get a detailed list
      of the elements in the execution plan.</p><p>This list includes the indexes used for performing the query and
      can be used to optimise the query or to add indexes to tables.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="grant-section"></a>GRANT</h3></div></div><div></div></div><pre class="programlisting">GRANT { SELECT | DELETE | INSERT | UPDATE | ALL } [,...]
ON { table | CLASS "package.class" } TO &lt;grantee&gt;;</pre><pre class="programlisting">GRANT &lt;rolename&gt; [,...] TO &lt;grantee&gt;<sup>[<a href="#ftn.posthyper">1</a>]</sup>;</pre><p>&lt;grantee&gt; is either a user name, a role name, or
      <tt class="literal">PUBLIC</tt>. <tt class="literal">PUBLIC</tt> means <span class="emphasis"><em>all
      users</em></span>.</p><p>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 
      <a href="#stored-section" title="Stored Procedures / Functions">Store Procedure</a> static
      function, the right ALL must be used. Examples: <div class="informalexample"><pre class="programlisting">    GRANT SELECT ON Test TO GUEST;
    GRANT ALL ON CLASS "java.lang.Math.abs" TO PUBLIC;</pre></div></p><div class="warning" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Warning</h3><p>
          Even though the command is GRANT ALL ON CLASS, you must
          specify a static <span class="emphasis"><em>method name</em></span>.  You are actually
          granting access to a static method, not to a class.
      </p></div><p>The second form of the GRANT command gives the specified
      &lt;grantee&gt; membership in the specified role.</p><p>Requires Administrative privileges.</p><p>See also: <a href="#revoke-section" title="REVOKE">REVOKE</a>, <a href="#create_user-section" title="CREATE USER">CREATE USER</a>, <a href="#create_role-section" title="CREATE ROLE">CREATE ROLE<sup>[<a href="#ftn.posthyper">1</a>]</sup></a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="insert-section"></a>INSERT</h3></div></div><div></div></div><pre class="programlisting">INSERT INTO table [( column [,...] )]
{ VALUES(<a href="#expression-section" title="SQL Expression">Expression</a> [,...]) | <a href="#select-section" title="SELECT">SelectStatement</a>};</pre><p>Adds one or more new rows of data into a table.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="revoke-section"></a>REVOKE</h3></div></div><div></div></div><pre class="programlisting">REVOKE { SELECT | DELETE | INSERT | UPDATE | ALL } [,...]
ON { table | CLASS "package.class" } FROM &lt;grantee&gt;;</pre><pre class="programlisting">REVOKE &lt;rolename&gt; [,...] FROM &lt;grantee&gt;<sup>[<a href="#ftn.posthyper">1</a>]</sup>;</pre><p>&lt;grantee&gt; is either a user name, a role name, or
      <tt class="literal">PUBLIC</tt>. <tt class="literal">PUBLIC</tt> means <span class="emphasis"><em>all
      users</em></span>.</p><p>The first form of the REVOKE command withdraws privileges from a
      grantee for a table or for a class.</p><p>The second form of the REVOKE command withdraws membership of the
      specified &lt;grantee&gt; from the specified role.</p><p>Both forms require Administrative privileges.</p><p>See also: <a href="#grant-section" title="GRANT">GRANT</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="rollback-section"></a>ROLLBACK</h3></div></div><div></div></div><pre class="programlisting">ROLLBACK [TO SAVEPOINT &lt;savepoint name&gt;<sup>[<a href="#ftn.posthyper">1</a>]</sup> |  WORK}];</pre><p>ROLLBACK used on its own, or with WORK, undoes changes made since
      the last COMMIT or ROLLBACK.</p><p><tt class="literal">ROLLBACK TO SAVEPOINT &lt;savepoint name&gt;</tt>
      undoes the change since the named savepoint. It has no effect if the
      savepoint is not found.</p><p>See also: <a href="#commit-section" title="COMMIT">COMMIT</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="savepoint-section"></a>SAVEPOINT<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">SAVEPOINT &lt;savepoint name&gt;;</pre><p>Sets up a SAVEPOINT for use with ROLLBACK TO SAVEPOINT.</p><p>See also: <a href="#commit-section" title="COMMIT">COMMIT</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="script-section"></a>SCRIPT</h3></div></div><div></div></div><pre class="programlisting">SCRIPT ['file'];</pre><p>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.</p><p>Only an administrator may do this.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="select-section"></a>SELECT<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">SELECT [{LIMIT &lt;offset&gt; &lt;limit&gt; | TOP &lt;limit&gt;}<sup>[<a href="#ftn.posthyper">1</a>]</sup>][ALL | DISTINCT]
{ selectExpression | table.* | * } [, ...]
[INTO [CACHED | TEMP  | TEXT]<sup>[<a href="#ftn.posthyper">1</a>]</sup> newTable]
FROM tableList
[WHERE <a href="#expression-section" title="SQL Expression">Expression</a>]
[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;]];</pre><p>Retrieves information from one or more tables in the
      database.</p><div class="variablelist"><p class="title"><b>Components of a SELECT command</b></p><dl><dt><span class="term">tableList</span></dt><dd><pre class="programlisting">table [{CROSS | INNER | LEFT OUTER | RIGHT OUTER}
    JOIN table ON Expression] [, ...]</pre></dd><dt><span class="term">table</span></dt><dd><pre class="programlisting">{ (selectStatement) [AS] label | tableName}</pre></dd><dt><span class="term">selectExpression</span></dt><dd><pre class="programlisting">{ Expression | COUNT(*) | {
    COUNT | MIN | MAX | SUM | AVG | SOME | EVERY |
    VAR_POP | VAR_SAMP | STDDEV_POP | STDDEV_SAMP
} ([ALL | DISTINCT]<sup>[<a href="#ftn.posthyper">1</a>]</sup>] Expression) } [[AS] label]</pre><p>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.</p><p>If CROSS JOIN is specified no ON expression is allowed for
            the join.</p></dd><dt><span class="term">orderExpression</span></dt><dd><pre class="programlisting">{ columnNr | columnAlias | selectExpression }
    [ASC | DESC]</pre></dd><dt><span class="term">LIMIT n m</span></dt><dd><p>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.</p></dd><dt><span class="term">LIMIT m OFFSET n</span></dt><dd><p>This form is used at the end of the SELECT statement. The
            OFFSET term is optional.</p></dd><dt><span class="term">TOP m</span></dt><dd><p>Equivalent to LIMIT 0 m.</p></dd><dt><span class="term">UNION and other set operations</span></dt><dd><p>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.</p></dd></dl></div><p>See also: <a href="#insert-section" title="INSERT">INSERT</a>, <a href="#update-section" title="UPDATE">UPDATE</a>, <a href="#delete-section" title="DELETE">DELETE</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_autocommit-section"></a>SET AUTOCOMMIT</h3></div></div><div></div></div><pre class="programlisting">SET AUTOCOMMIT { TRUE | FALSE };</pre><p>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 <a href="#commit-section" title="COMMIT">COMMIT</a> or
      <a href="#rollback-section" title="ROLLBACK">ROLLBACK</a>. 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).</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="collation-section"></a>SET DATABASE COLLATION<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">SET DATABASE COLLATION &lt;double quoted collation name&gt;;</pre><p>Each database can have its own collation. Sets the collation from
      the set of collations in the source for org.hsqldb.Collation.
      </p><p>Once this command has been issued, the database can be opened in
      any JVM and will retain its collation.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1208B"></a>SET CHECKPOINT DEFRAG<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">SET CHECKPOINT DEFRAG &lt;size&gt;;</pre><p>The parameter <tt class="literal">size</tt> 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.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_ignorecase-section"></a>SET IGNORECASE</h3></div></div><div></div></div><pre class="programlisting">SET IGNORECASE { TRUE | FALSE };</pre><p>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 <tt class="literal">VARCHAR_IGNORECASE</tt> in new tables.
      Alternatively, you can specify the <tt class="literal">VARCHAR_IGNORECASE</tt>
      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.</p><p>Only an administrator may do this.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_initialschema-section"></a>SET INITIAL SCHEMA <sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><p>Users may change their base default schema name with the comand
      <pre class="programlisting">SET INITIAL SCHEMA &lt;schemaname&gt;;</pre>
      This is the schema which database object names will resolve to for the
      current user, unless overridden as explained in <a href="#schemanaming-section" title="Schema object naming">Schema object naming</a>. 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).</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_logsize-section"></a>SET LOGSIZE</h3></div></div><div></div></div><pre class="programlisting">SET LOGSIZE &lt;size&gt;;</pre><p>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.</p><p>See also: <a href="#checkpoint-section" title="CHECKPOINT">CHECKPOINT</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_password-section"></a>SET PASSWORD</h3></div></div><div></div></div><pre class="programlisting">SET PASSWORD &lt;password&gt;;</pre><p>Changes the password of the currently connected user. Password
      must be double quotedEmpty password can be set using "".</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_property-section"></a>SET PROPERTY<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">SET PROPERTY &lt;double quoted name&gt; &lt;value&gt;;</pre><p>Sets a database property. Properties that can be set using this
      command are either boolean or integral and are listed in the <a href="#advanced-chapter" title="Chapter&nbsp;4.&nbsp;Advanced Topics">Advanced Topics</a> chapter.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_refint-section"></a>SET REFERENTIAL INTEGRITY</h3></div></div><div></div></div><pre class="programlisting">SET REFERENTIAL_INTEGRITY { TRUE | FALSE };</pre><p>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.</p><div class="warning" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Warning</h3><p>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.</p></div><p>Only an administrator may do this.</p><p>See also: <a href="#create_table-section" title="CREATE TABLE">CREATE TABLE</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_schema-section"></a>SET SCHEMA<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">SET SCHEMA &lt;schemaname&gt;;</pre><p>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 <tt class="literal">SELECT * FROM atbl;</tt>, HSQLDB will
      look for the table or view named <tt class="literal">atbl</tt> in the
      session's current schema.</p><p>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.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_scriptformat-section"></a>SET SCRIPTFORMAT<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">SET SCRIPTFORMAT {TEXT | BINARY | COMPRESSED};</pre><p>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.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_table_index-section"></a>SET TABLE INDEX</h3></div></div><div></div></div><pre class="programlisting">SET TABLE tableName INDEX 'index1rootPos index2rootPos ... ';</pre><p>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.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_table_readonly-section"></a>SET TABLE READONLY<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">SET TABLE &lt;tablename&gt; READONLY {TRUE | FALSE};</pre><p>Sets the table as read only.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_table_source-section"></a>SET TABLE SOURCE<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">SET TABLE &lt;tablename&gt; SOURCE &lt;file and options&gt; [DESC];</pre><p>For details see the <a href="#texttables-chapter" title="Chapter&nbsp;6.&nbsp;Text Tables">Text Tables</a> chapter.</p><p>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:</p><pre class="programlisting">    &lt;file and options&gt;::= &lt;doublequote&gt; &lt;filepath&gt;
        [&lt;semicolon&gt; &lt;option&gt;...] &lt;doublequote&gt;</pre><p>Example:</p><div class="informalexample"><pre class="programlisting">    SET TABLE mytable SOURCE "myfile;fs=|;vs=.;lvs=~"</pre></div><div class="variablelist"><p class="title"><b>Supported Properties</b></p><dl><dt><span class="term">quoted = { true | false }</span></dt><dd><p>default is true. If false, treats double quotes as normal
            characters</p></dd><dt><span class="term">all_quoted = { true | false }</span></dt><dd><p>default is false. If true, adds double quotes around all
            fields.</p></dd><dt><span class="term">encoding = &lt;encoding name&gt;</span></dt><dd><p>character encoding for text and character fields, for
            example, encoding=UTF-8</p></dd><dt><span class="term">ignore_first = { true | false }</span></dt><dd><p>default is false. If true ignores the first line of the
            file</p></dd><dt><span class="term">cache_scale= &lt;numeric value&gt;</span></dt><dd><p>exponent to calculate rows of the text file in cache.
            Default is 8, equivalent to nearly 800 rows</p></dd><dt><span class="term">cache_size_scale = &lt;numeric value&gt;r</span></dt><dd><p>exponent to calculate average size of each row in cache.
            Default is 8, equivalent to 256 bytes per row.</p></dd><dt><span class="term">fs = &lt;unquoted character&gt;</span></dt><dd><p>field separator</p></dd><dt><span class="term">vs = &lt;unquoted character&gt;</span></dt><dd><p>varchar separator</p></dd><dt><span class="term">lvs = &lt;unquoted character&gt;</span></dt><dd><p>long varchar separator</p></dd></dl></div><div class="variablelist"><p class="title"><b>Special indicators for Hsqldb Text Table separators</b></p><dl><dt><span class="term">\semi</span></dt><dd><p>semicolon</p></dd><dt><span class="term">\quote</span></dt><dd><p>quote</p></dd><dt><span class="term">\space</span></dt><dd><p>space character</p></dd><dt><span class="term">\apos</span></dt><dd><p>apostrophe</p></dd><dt><span class="term">\n</span></dt><dd><p>newline - Used as an end anchor (like $ in regular
            expressions)</p></dd><dt><span class="term">\r</span></dt><dd><p>carriage return</p></dd><dt><span class="term">\t</span></dt><dd><p>tab</p></dd><dt><span class="term">\\</span></dt><dd><p>backslash</p></dd><dt><span class="term">\u####</span></dt><dd><p>a Unicode character specified in hexadecimal</p></dd></dl></div><p>Only an administrator may do this.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="set_write_delay-section"></a>SET WRITE DELAY<sup>[<a href="#ftn.posthyper">1</a>]</sup></h3></div></div><div></div></div><pre class="programlisting">SET WRITE_DELAY {{ TRUE | FALSE } | &lt;seconds&gt; | &lt;milliseconds&gt; MILLIS};</pre><p>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.</p><p>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.</p><p>A write delay of 0 impacts performance in high load situations, as
      the engine has to wait for the file system to catch up.</p><p>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.</p><p>Each time a SET WRITE_DELAY is issued with any value, a sync is
      immediately performed.</p><p>Only an administrator may do this.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="shutdown-section"></a>SHUTDOWN</h3></div></div><div></div></div><pre class="programlisting">SHUTDOWN [IMMEDIATELY | COMPACT | SCRIPT<sup>[<a href="#ftn.posthyper">1</a>]</sup>];</pre><p>Closes the current database.</p><div class="variablelist"><p class="title"><b>Varieties of the SHUTDOWN command</b></p><dl><dt><span class="term">SHUTDOWN</span></dt><dd><p>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.</p></dd><dt><span class="term">SHUTDOWN IMMEDIATELY</span></dt><dd><p>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.</p></dd><dt><span class="term">SHUTDOWN COMPACT</span></dt><dd><p>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.</p></dd><dt><span class="term">SHUTDOWN SCRIPT</span></dt><dd><p>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.</p><p>This command produces a full script of the database which
            can be edited for special purposes prior to the next
            startup.</p></dd></dl></div><p>Only an administrator may use the SHUTDOWN command.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="update-section"></a>UPDATE</h3></div></div><div></div></div><pre class="programlisting">UPDATE table SET column = Expression [, ...] [WHERE Expression];</pre><p>Modifies data of a table in the database.</p><p>See also: <a href="#select-section" title="SELECT">SELECT<sup>[<a href="#ftn.posthyper">1</a>]</sup></a>, <a href="#insert-section" title="INSERT">INSERT</a>, <a href="#delete-section" title="DELETE">DELETE</a>.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="schemanaming-section"></a>Schema object naming</h2></div></div><div></div></div><p><span class="emphasis"><em>Schema</em></span> 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 <tt class="literal">schemaname.objectname</tt>.
    All HSQLDB database objects are schema objects, other than the
    following.</p><table summary="Simple list" border="0" class="simplelist"><tr><td>
        <p>Users</p>
      </td></tr><tr><td>
        <p>Roles</p>
      </td></tr><tr><td>
        <p>Store Procedure Java Classes</p>
      </td></tr><tr><td>
        <p>HSQL Aliases</p>
      </td></tr></table><p>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.</p><p>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.
    </p><p>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
    <span class="emphasis"><em>initial schema</em></span>, or whatever you last set it to with
    <a href="#set_schema-section" title="SET SCHEMA">SET SCHEMA<sup>[<a href="#ftn.posthyper">1</a>]</sup></a> in your
    <span class="emphasis"><em>current</em></span> JDBC session with the SET SCHEMA command.
    (Your initial schema is "PUBLIC" unless changed with the <a href="#alter_user-section" title="ALTER USER"> ALTER USER SET INITIAL SCHEMA</a> or the
    <a href="#set_initialschema-section" title="SET INITIAL SCHEMA ">SET INITIAL SCHEMA <sup>[<a href="#ftn.posthyper">1</a>]</sup></a> command).</p><p>In addition to namespace scoping, there are permission aspects to
    the schema of a database object. The <span class="emphasis"><em>authorization</em></span> of
    a schema is a role or user that is basically the
    <span class="emphasis"><em>owner</em></span> 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 <span class="emphasis"><em>DBA</em></span>.</p><p>An important implication to database objects being
    <span class="emphasis"><em>owned</em></span> 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.</p><p>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.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="datatypes-section"></a>Data Types</h2></div></div><div></div></div><div class="table"><a name="N12272"></a><p class="title"><b>Table&nbsp;9.1.&nbsp;Data Types. The types on the same line are equivalent.</b></p><table summary="Data Types. The types on the same line are equivalent." width="100%" border="1"><colgroup><col><col><col></colgroup><thead><tr><th align="left">Name</th><th align="left">Range</th><th align="left">Java Type</th></tr></thead><tbody><tr><td align="left">INTEGER | INT</td><td align="left">as Java type</td><td align="left"><tt class="literal">int</tt> |
            <tt class="classname">java.lang.Integer</tt></td></tr><tr><td align="left">DOUBLE [PRECISION] | FLOAT</td><td align="left">as Java type</td><td align="left"><tt class="literal">double</tt> |
            <tt class="classname">java.lang.Double</tt></td></tr><tr><td align="left">VARCHAR</td><td align="left">as Integer.MAXVALUE</td><td align="left"><tt class="classname">java.lang.String</tt></td></tr><tr><td align="left">VARCHAR_IGNORECASE</td><td align="left">as Integer.MAXVALUE</td><td align="left"><tt class="classname">java.lang.String</tt></td></tr><tr><td align="left">CHAR | CHARACTER</td><td align="left">as Integer.MAXVALUE</td><td align="left"><tt class="classname">java.lang.String</tt></td></tr><tr><td align="left">LONGVARCHAR</td><td align="left">as Integer.MAXVALUE</td><td align="left"><tt class="classname">java.lang.String</tt></td></tr><tr><td align="left">DATE</td><td align="left">as Java type</td><td align="left"><tt class="classname">java.sql.Date</tt></td></tr><tr><td align="left">TIME</td><td align="left">as Java type</td><td align="left"><tt class="classname">java.sql.Time</tt></td></tr><tr><td align="left">TIMESTAMP | DATETIME</td><td align="left">as Java type</td><td align="left"><tt class="classname">java.sql.Timestamp</tt></td></tr><tr><td align="left">DECIMAL</td><td align="left">No limit</td><td align="left"><tt class="classname">java.math.BigDecimal</tt></td></tr><tr><td align="left">NUMERIC</td><td align="left">No limit</td><td align="left"><tt class="classname">java.math.BigDecimal</tt></td></tr><tr><td align="left">BOOLEAN | BIT</td><td align="left">as Java type</td><td align="left"><tt class="literal">boolean</tt> |
            <tt class="classname">java.lang.Boolean</tt></td></tr><tr><td align="left">TINYINT</td><td align="left">as Java type</td><td align="left"><tt class="literal">byte</tt> |
            <tt class="classname">java.lang.Byte</tt></td></tr><tr><td align="left">SMALLINT</td><td align="left">as Java type</td><td align="left"><tt class="literal">short</tt> |
            <tt class="classname">java.lang.Short</tt></td></tr><tr><td align="left">BIGINT</td><td align="left">as Java type</td><td align="left"><tt class="filename">long</tt> |
            <tt class="classname">java.lang.Long</tt></td></tr><tr><td align="left">REAL</td><td align="left">as Java type</td><td align="left"><tt class="literal">double</tt> |
            <tt class="classname">java.lang.Double</tt><sup>[<a href="#ftn.posthyper">1</a>]</sup></td></tr><tr><td align="left">BINARY</td><td align="left">as Integer.MAXVALUE</td><td align="left"><tt class="literal">byte[]</tt></td></tr><tr><td align="left">VARBINARY</td><td align="left">as Integer.MAXVALUE</td><td align="left"><tt class="literal">byte[]</tt></td></tr><tr><td align="left">LONGVARBINARY</td><td align="left">as Integer.MAXVALUE</td><td align="left"><tt class="literal">byte[]</tt></td></tr><tr><td align="left">OTHER | OBJECT</td><td align="left">as Integer.MAXVALUE</td><td align="left"><tt class="classname">java.lang.Object</tt></td></tr></tbody></table></div><p>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.</p><p>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.</p><p>VARCHAR_IGNORECASE is a special case-insensitive type of VARCHAR.
    This type is not portable.</p><p>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).</p><p>TIMESTAMP(p) can take only 0 or 6 as precision. Zero indicates no
    subsecond part. Without the precision, the default is 6.</p><p>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:</p><pre class="programlisting">    SET PROPERTY "sql.enforce_strict_size" true</pre><p>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.</p><p>CHAR and VARCHAR and LONGVARCHAR columns are by default compared and
    sorted according to POSIX standards. See the <a href="#collation-section" title="SET DATABASE COLLATION">SET DATABASE COLLATION<sup>[<a href="#ftn.posthyper">1</a>]</sup></a> section above to
    modify this behavior. The property
    <tt class="literal">sql.compare_in_locale</tt> is no longer supported. Instead,
    you can define a collation to be used for all character
    comparisons.</p><p>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.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12364"></a>SQL Comments</h2></div></div><div></div></div><table summary="Simple list" border="0" class="simplelist"><tr><td>
        <tt class="literal">-- SQL style line comment</tt>
      </td></tr><tr><td>
        <tt class="literal">// Java style line comment</tt>
      </td></tr><tr><td>
        <tt class="literal">/* C style line comment */</tt>
      </td></tr></table><p>All these types of comments are ignored by the database.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="stored-section"></a>Stored Procedures / Functions</h2></div></div><div></div></div><p>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:</p><pre class="programlisting">    "java.lang.Math.sqrt"(2.0)</pre><p>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).</p><p>An alias can be created using the command CREATE ALIAS:</p><pre class="programlisting">    CREATE ALIAS SQRT FOR "java.lang.Math.sqrt";</pre><p>When an alias is defined, then the function can be called
    additionally using this alias:</p><pre class="programlisting">    SELECT SQRT(A) , B FROM MYTABLE;</pre><p>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.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12395"></a>Built-in Functions and Stored Procedures</h2></div></div><div></div></div><div class="variablelist"><p class="title"><b>Numerical built-in Functions / Stored Procedures</b></p><dl><dt><span class="term">ABS(d)</span></dt><dd><p>returns the absolute value of a double value</p></dd><dt><span class="term">ACOS(d)</span></dt><dd><p>returns the arc cosine of an angle</p></dd><dt><span class="term">ASIN(d)</span></dt><dd><p>returns the arc sine of an angle</p></dd><dt><span class="term">ATAN(d)</span></dt><dd><p>returns the arc tangent of an angle</p></dd><dt><span class="term">ATAN2(a,b)</span></dt><dd><p>returns the tangent of a/b</p></dd><dt><span class="term">BITAND(a,b)</span></dt><dd><p>return a &amp; b</p></dd><dt><span class="term">BITOR(a,b)</span></dt><dd><p>returns a | b</p></dd><dt><span class="term">CEILING(d)</span></dt><dd><p>returns the smallest integer that is not less than d</p></dd><dt><span class="term">COS(d)</span></dt><dd><p>returns the cosine of an angle</p></dd><dt><span class="term">COT(d)</span></dt><dd><p>returns the cotangent of an angle</p></dd><dt><span class="term">DEGREES(d)</span></dt><dd><p>converts radians to degrees</p></dd><dt><span class="term">EXP(d)</span></dt><dd><p>returns e (2.718...) raised to the power of d</p></dd><dt><span class="term">FLOOR(d)</span></dt><dd><p>returns the largest integer that is not greater than d</p></dd><dt><span class="term">LOG(d)</span></dt><dd><p>returns the natural logarithm (base e)</p></dd><dt><span class="term">LOG10(d)</span></dt><dd><p>returns the logarithm (base 10)</p></dd><dt><span class="term">MOD(a,b)</span></dt><dd><p>returns a modulo b</p></dd><dt><span class="term">PI()</span></dt><dd><p>returns pi (3.1415...)</p></dd><dt><span class="term">POWER(a,b)</span></dt><dd><p>returns a raised to the power of b</p></dd><dt><span class="term">RADIANS(d)</span></dt><dd><p>converts degrees to radians</p></dd><dt><span class="term">RAND()</span></dt><dd><p>returns a random number x bigger or equal to 0.0 and smaller
          than 1.0</p></dd><dt><span class="term">ROUND(a,b)</span></dt><dd><p>rounds a to b digits after the decimal point</p></dd><dt><span class="term">ROUNDMAGIC(d)</span></dt><dd><p>solves rounding problems such as 3.11-3.1-0.01</p></dd><dt><span class="term">SIGN(d)</span></dt><dd><p>returns -1 if d is smaller than 0, 0 if d==0 and 1 if d is
          bigger than 0</p></dd><dt><span class="term">SIN(d)</span></dt><dd><p>returns the sine of an angle</p></dd><dt><span class="term">SQRT(d)</span></dt><dd><p>returns the square root</p></dd><dt><span class="term">TAN(A)</span></dt><dd><p>returns the trigonometric tangent of an angle</p></dd><dt><span class="term">TRUNCATE(a,b)</span></dt><dd><p>truncates a to b digits after the decimal point</p></dd></dl></div><div class="variablelist"><p class="title"><b>String built-in Functions / Stored Procedures</b></p><dl><dt><span class="term">ASCII(s)</span></dt><dd><p>returns the ASCII code of the leftmost character of s</p></dd><dt><span class="term">BIT_LENGTH(str)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>returns the length of the string in bits</p></dd><dt><span class="term">CHAR(c)</span></dt><dd><p>returns a character that has the ASCII code c</p></dd><dt><span class="term">CHAR_LENGTH(str)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>returns the length of the string in characters</p></dd><dt><span class="term">CONCAT(str1,str2)</span></dt><dd><p>returns str1 + str2</p></dd><dt><span class="term">DIFFERENCE(s1,s2)</span></dt><dd><p>returns the difference between the sound of s1 and s2</p></dd><dt><span class="term">HEXTORAW(s1)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>returns translated string</p></dd><dt><span class="term">INSERT(s,start,len,s2)</span></dt><dd><p>returns a string where len number of characters beginning at
          start has been replaced by s2</p></dd><dt><span class="term">LCASE(s)</span></dt><dd><p>converts s to lower case</p></dd><dt><span class="term">LEFT(s,count)</span></dt><dd><p>returns the leftmost count of characters of s) - requires
          double quoting - use SUBSTRING() instead</p></dd><dt><span class="term">LENGTH(s)</span></dt><dd><p>returns the number of characters in s</p></dd><dt><span class="term">LOCATE(search,s,[start])</span></dt><dd><p>returns the first index (1=left, 0=not found) where search is
          found in s, starting at start</p></dd><dt><span class="term">LTRIM(s)</span></dt><dd><p>removes all leading blanks in s</p></dd><dt><span class="term">OCTET_LENGTH(str)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>returns the length of the string in bytes (twice the number of
          characters)</p></dd><dt><span class="term">RAWTOHEX(s1)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>returns translated string</p></dd><dt><span class="term">REPEAT(s,count)</span></dt><dd><p>returns s repeated count times</p></dd><dt><span class="term">REPLACE(s,replace,s2)</span></dt><dd><p>replaces all occurrences of replace in s with s2</p></dd><dt><span class="term">RIGHT(s,count)</span></dt><dd><p>returns the rightmost count of characters of s</p></dd><dt><span class="term">RTRIM(s)</span></dt><dd><p>removes all trailing spaces</p></dd><dt><span class="term">SOUNDEX(s)</span></dt><dd><p>returns a four character code representing the sound of
          s</p></dd><dt><span class="term">SPACE(count)</span></dt><dd><p>returns a string consisting of count spaces</p></dd><dt><span class="term">SUBSTR(s,start[,len])</span></dt><dd><p>alias for substring</p></dd><dt><span class="term">SUBSTRING(s,start[,len])</span></dt><dd><p>returns the substring starting at start (1=left) with length
          len</p></dd><dt><span class="term">UCASE(s)</span></dt><dd><p>converts s to upper case</p></dd><dt><span class="term">LOWER(s)</span></dt><dd><p>converts s to lower case</p></dd><dt><span class="term">UPPER(s)</span></dt><dd><p>converts s to upper case</p></dd></dl></div><div class="variablelist"><p class="title"><b>Date/Time built-in Functions / Stored Procedures</b></p><dl><dt><span class="term">CURDATE()</span></dt><dd><p>returns the current date</p></dd><dt><span class="term">CURTIME()</span></dt><dd><p>returns the current time</p></dd><dt><span class="term">DATEDIFF(string, datetime1, datetime2)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>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.</p></dd><dt><span class="term">DAYNAME(date)</span></dt><dd><p>returns the name of the day</p></dd><dt><span class="term">DAYOFMONTH(date)</span></dt><dd><p>returns the day of the month (1-31)</p></dd><dt><span class="term">DAYOFWEEK(date)</span></dt><dd><p>returns the day of the week (1 means Sunday)</p></dd><dt><span class="term">DAYOFYEAR(date)</span></dt><dd><p>returns the day of the year (1-366)</p></dd><dt><span class="term">HOUR(time)</span></dt><dd><p>return the hour (0-23)</p></dd><dt><span class="term">MINUTE(time)</span></dt><dd><p>returns the minute (0-59)</p></dd><dt><span class="term">MONTH(date)</span></dt><dd><p>returns the month (1-12)</p></dd><dt><span class="term">MONTHNAME(date)</span></dt><dd><p>returns the name of the month</p></dd><dt><span class="term">NOW()</span></dt><dd><p>returns the current date and time as a timestamp) - use
          CURRENT_TIMESTAMP instead</p></dd><dt><span class="term">QUARTER(date)</span></dt><dd><p>returns the quarter (1-4)</p></dd><dt><span class="term">SECOND(time)</span></dt><dd><p>returns the second (0-59)</p></dd><dt><span class="term">WEEK(date)</span></dt><dd><p>returns the week of this year (1-53)</p></dd><dt><span class="term">YEAR(date)</span></dt><dd><p>returns the year</p></dd><dt><span class="term">CURRENT_DATE<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>returns the current date</p></dd><dt><span class="term">CURRENT_TIME<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>returns the current time</p></dd><dt><span class="term">CURRENT_TIMESTAMP<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>returns the current timestamp</p></dd></dl></div><div class="variablelist"><p class="title"><b>System/Connection built-in Functions / Stored Procedures</b></p><dl><dt><span class="term">DATABASE()</span></dt><dd><p>returns the name of the database of this connection</p></dd><dt><span class="term">USER()</span></dt><dd><p>returns the user name of this connection</p></dd><dt><span class="term">CURRENT_USER</span></dt><dd><p>SQL standard function, returns the user name of this
          connection</p></dd><dt><span class="term">IDENTITY()</span></dt><dd><p>returns the last identity values that was inserted by this
          connection</p></dd></dl></div><div class="variablelist"><p class="title"><b>System built-in Functions / Stored Procedures</b></p><dl><dt><span class="term">IFNULL(exp,value)</span></dt><dd><p>if exp is null, value is returned else exp) - use COALESCE()
          instead</p></dd><dt><span class="term">CASEWHEN(exp,v1,v2)</span></dt><dd><p>if exp is true, v1 is returned, else v2) - use CASE WHEN
          instead</p></dd><dt><span class="term">CONVERT(term,type)</span></dt><dd><p>converts exp to another data type</p></dd><dt><span class="term">CAST(term AS type)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>converts exp to another data type</p></dd><dt><span class="term">COALESCE(expr1,expr2,expr3,...)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>if expr1 is not null then it is returned else, expr2 is
          evaluated and if not null it is returned and so on</p></dd><dt><span class="term">NULLIF(v1,v2)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>if v1 equals v2 return null, otherwise v1</p></dd><dt><span class="term">CASE v1 WHEN...<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>
            <tt class="literal">CASE v1 WHEN v2 THEN v3 [ELSE v4] END</tt>
          </p><p>when v1 equals v2 return v3 [otherwise v4 or null if there is
          no ELSE]</p></dd><dt><span class="term">CASE WHEN...<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>
            <tt class="literal">CASE WHEN expr1 THEN v1[WHEN expr2 THEN v2] [ELSE v4]
            END</tt>
          </p><p>when expr1 is true return v1 [optionally repeated for more
          cases] [otherwise v4 or null if there is no ELSE]</p></dd><dt><span class="term">EXTRACT<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>
            <tt class="literal">EXTRACT ({YEAR | MONTH | DAY | HOUR | MINUTE | SECOND}
            FROM &lt;datetime value&gt;)</tt>
          </p></dd><dt><span class="term">POSITION (... IN ..)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>
            <tt class="literal">POSITION(&lt;string expression&gt; IN &lt;string
            expression&gt;)</tt>
          </p><p>if the first string is a sub-string of the second one, returns
          the position of the sub-string, counting from one; otherwise
          0</p></dd><dt><span class="term">SUBSTRING(... FROM ... FOR ...)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>
            <tt class="literal">SUBSTRING(&lt;string expression&gt; FROM &lt;numeric
            expression&gt; [FOR &lt;numeric expression&gt;])</tt>
          </p></dd><dt><span class="term">TRIM( LEDING ... FROM ...)<sup>[<a href="#ftn.posthyper">1</a>]</sup></span></dt><dd><p>
            <tt class="literal">TRIM([{LEADING | TRAILING | BOTH}] FROM &lt;string
            expression&gt;)</tt>
          </p></dd></dl></div><p>See also: <a href="#call-section" title="CALL">CALL</a>,
    <a href="#create_alias-section" title="CREATE ALIAS">CREATE ALIAS</a>.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="expression-section"></a>SQL Expression</h2></div></div><div></div></div><pre class="programlisting">[NOT] condition [{ OR | AND } condition]</pre><div class="variablelist"><p class="title"><b>Components of SQL Expressions</b></p><dl><dt><span class="term">condition</span></dt><dd><pre class="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 }</pre></dd><dt><span class="term">value</span></dt><dd><pre class="programlisting">   [+ | -] { term [{ + | - | * | / | || } term]
  | ( condition )
  | function ( [parameter] [,...] )
  | selectStatement giving one value
  | {ANY|ALL} (selectStatement giving single column)</pre></dd><dt><span class="term">term</span></dt><dd><pre class="programlisting">   { 'string' | number | floatingpoint
  | [table.]column | TRUE | FALSE | NULL }</pre></dd><dt><span class="term">sequence</span></dt><dd><pre class="programlisting">   NEXT VALUE FOR &lt;sequence&gt;</pre><p>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.</p></dd><dt><span class="term">string</span></dt><dd><p>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).</p><p>String contatenation should be performed with the standard SQL
          operator || rather than the non-standard + operator.</p><p>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.</p></dd><dt><span class="term">name</span></dt><dd><p>The character set for quoted identifiers (names) in HSQLDB is
          Unicode.</p><p>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.</p><p>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:</p><div class="informalexample"><pre class="programlisting">    CREATE TABLE "Address" ("Nr" INTEGER,"Name" VARCHAR);
    SELECT "Nr", "Name" FROM "Address";</pre></div><p>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.</p><p>Quoting can sometimes be used for identifiers, aliases or
          functions when there is an ambiguity. For example:</p><div class="informalexample"><pre class="programlisting">    SELECT COUNT(*) "COUNT" FROM MYTABLE;
    SELECT "LEFT"(COL1, 2) FROM MYTABLE;</pre></div><p>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.</p><p>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).</p><p>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.</p></dd><dt><span class="term">password</span></dt><dd><p>Passwords must be double quoted and used consistently.
          Passwords are case insensitive only for backward compatibility. This
          may change in future versions.</p></dd><dt><span class="term">values</span></dt><dd><div class="itemizedlist"><ul type="disc"><li><p>A DATE literal starts and ends with ' (singlequote), the
              format is yyyy-mm-dd (see
              <tt class="classname">java.sql.Date</tt>.</p></li><li><p>A TIME liteal starts and ends with ' (singlequote), the
              format is hh:mm:ss (see
              <tt class="classname">java.sql.Time</tt>).</p></li><li><p>A TIMESTAMP or DATETIME literal starts and ends with '
              (singlequote), the format is yyyy-mm-dd hh:mm:ss.SSSSSSSSS (see
              <tt class="classname">java.sql.Timestamp</tt>).</p></li></ul></div><p>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:</p><pre class="programlisting">    CREATE TABLE T(D DATE DEFAULT CURRENT_DATE);
    CREATE TABLE T1(TS TIMESTAMP DEFAULT CURRENT_TIMESTAMP);</pre><p>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).</p></dd></dl></div><p>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.</p></div><div class="footnotes"><br><hr align="left" width="100"><div class="footnote"><p><sup>[<a href="#posthyper" name="ftn.posthyper">1</a>] </sup>These features were added by HSQL Development Group since
          April 2001</p></div></div></div><div class="appendix" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="building-appendix"></a>Appendix&nbsp;A.&nbsp;Building HSQLDB</h2></div><div><div class="authorgroup"><div class="author"><h3 class="author"><span class="firstname">Fred</span> <span class="surname">Toussi</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:ft@cluedup.com">ft@cluedup.com</a>&gt;</tt></div></div></div><div><p class="pubdate">$Date: 2005/05/26 23:22:06 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N1269A">Purpose</a></span></dt><dt><span class="section"><a href="#N126A3">Building with Ant</a></span></dt><dd><dl><dt><span class="section"><a href="#N126AA">Obtaining Ant</a></span></dt><dt><span class="section"><a href="#N126C2">Building Hsqldb with Ant</a></span></dt></dl></dd><dt><span class="section"><a href="#N12771">Building with DOS Batch Files</a></span></dt><dt><span class="section"><a href="#N1278A">Hsqldb CodeSwitcher</a></span></dt><dt><span class="section"><a href="#N127B6">Building documentation</a></span></dt></dl></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N1269A"></a>Purpose</h2></div></div><div></div></div><p>From 1.8.0, the supplied <tt class="filename">hsqldb.jar</tt> file is
    built with Java 1.5. If you want to run the engine under JDK1.3 or
    earlier, you should rebuild the jar with Ant.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N126A3"></a>Building with Ant, from the Apache Jakarta Project</h2></div></div><div></div></div><p>Ant (Another Neat Tool) is used for building hsqldb. The version
    currently used to test the build script is 1.6.1 but versions since 1.5.1
    should also be compatible.</p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N126AA"></a>Obtaining Ant</h3></div></div><div></div></div><p>Ant is a part of the Jakarta/Apache Project.</p><div class="itemizedlist"><ul type="disc"><li><p>
            <a href="http://ant.apache.org" target="_top">Home of the Apache Ant
            project</a>
          </p></li><li><p>The <a href="http://ant.apache.org/manual/install.html#installing" target="_top">
          Installing Ant</a> page of the <a href="http://ant.apache.org/manual" target="_top">Ant Manual </a>. Follow the
          directions for your platform.</p></li></ul></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N126C2"></a>Building Hsqldb with Ant</h3></div></div><div></div></div><p>Once you have unpacked the zip package for hsqldb, under the
      <tt class="filename">/hsqldb</tt> folder, in <tt class="filename">/build</tt>
      there is a <tt class="filename">build.xml</tt> file that builds the
      <tt class="filename">hsqldb.jar</tt> with Ant (Ant must be already
      installed). To use it, change to <tt class="filename">/build</tt> then
      type:</p><div class="informalexample"><pre class="screen"> ant -projecthelp</pre></div><p>This displays the available ant targets, which you can supply as
      command line arguments to ant. These include</p><div class="variablelist"><dl><dt><span class="term">hsqldb</span></dt><dd><p>to make the <tt class="filename">hsqldb.jar</tt></p></dd><dt><span class="term">explainjars</span></dt><dd><p>Lists all targets which build jar files, with an explanation
            of the purposes of the different jars.</p></dd><dt><span class="term">clean</span></dt><dd><p>to clean up the /classes directory that is created</p></dd><dt><span class="term">cleanall</span></dt><dd><p>to remove the old jar as well</p></dd><dt><span class="term">javadoc</span></dt><dd><p>to build javadoc</p></dd><dt><span class="term">hsqldbmain</span></dt><dd><p>to build a smaller jar for HSQLDB that does not contain
            utilities</p></dd><dt><span class="term">hsqljdbc</span></dt><dd><p>to build an extremely small jar containing only the
            client-side JDBC driver (does not support direct connection to
            HSQLDB URLs of the form jdbc:hsldb:mem:*, jdbc:hsqldb:file:*, nor
            jdbc:hsqldb:res:*).</p></dd><dt><span class="term">hsqldbmin</span></dt><dd><p>to build a small jar that supports HSQLDB URLs of the form
            jdbc:hsqldb:mem:*, jdbc:hsqld:file*, jdbc:hsqldb:res:*; but not
            network URLs like jdbc:hsql* or jdbc:http*.</p></dd><dt><span class="term">hsqldbtest</span></dt><dd><p>to build a larger jar for hsqldb that contains tests</p></dd><dt><span class="term">...</span></dt><dd><p>Many more targets are available. Run <tt class="literal">ant
            -projecthelp</tt> and <tt class="literal">ant
            explainjars</tt>.</p></dd></dl></div><p>HSQLDB can be built in any combination of three JRE (Java Runtime
      Environment) versions and many jar file sizes. The smallest jar
      size(<tt class="filename">hsqljdbc.jar</tt>) contains only the HSQLDB JDBC
      Driver client. The default size (<tt class="filename">hsqldb.jar</tt>) also
      contains server mode support and the utilities. The largest size
      (<tt class="filename">hsqldbtest.jar</tt>)includes some test classes as well.
      Before building the <tt class="filename">hsqldbtest.jar</tt> package, you
      should download the junit jar from <a href="http://www.junit.org" target="_top">http://www.junit.org</a>
      and put it in the <tt class="filename">/lib</tt> directory, alongside
      <tt class="filename">servlet.jar</tt>, which is included in the .zip
      package.</p><p>Just run <tt class="literal">ant explainjars</tt> for a concise list of
      all available jar files.</p><p>If you want your code built for debugging, as opposed to high
      performance, make a file named <tt class="filename">build.properties</tt> in
      your build directory with the contents <div class="informalexample"><pre class="screen">build.debug: true</pre></div>The resulting Java binaries will be larger and
      slower, but exception stack traces will contain source code line
      numbers, which can be extremely useful for debugging.</p><p>The preferred method of rebuilding the jar is with Ant. After
      installing Ant on your system use the following command from the
      <tt class="filename">/build</tt> directory:</p><div class="informalexample"><pre class="screen">ant explainjars</pre></div><p>The command displays a list of different options for building
      different sizes of the HSQLDB Jar. The default is built using:</p><div class="example"><a name="N12763"></a><p class="title"><b>Example&nbsp;A.1.&nbsp;Buiding the standard Hsqldb jar file with Ant</b></p><pre class="screen">ant hsqldb</pre></div><p>The Ant method always builds a jar with the JDK that is used by
      Ant and specified in its JAVA_HOME environment variable. Building with
      JDK 1.4.x or 1.5.x will result in a jar that is not backward compatible.
      </p><p>From version 1.7.2, use of JDK 1.1.x is not recommended for
      building the JAR, even for running under JDK 1.1.x -- use JDK 1.3.1 for
      compatibility with 1.1.x. This is done in the following way. JDK 1.3.1
      should be used as the JAVA_HOME for ant. You then issue the following
      commands. The first command will make the sources compatible with JDK
      1.3, the second command modifies the sources further so that the
      compiled result can run under jdk 1.1 as well. The third command builds
      the jar.<div class="informalexample"><pre class="screen">ant switchtojdk12
ant switchtojava1target
ant hsqldb
</pre></div></p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12771"></a>Building with DOS Batch Files</h2></div></div><div></div></div><p>UNIX users must use Ant to build hsqldb.</p><p>For DOS/Windows users, a set of MSDOS batch files is provided as an
    example. These files produce only the default jar size. The path and
    classpath variables for the JDK should of course be set before running any
    of the batch files. These files are not currently maintained and will
    probably need some additions and changes to work correctly. Please see the
    build.xml file for up-to-date file</p><p>If you are compiling for JDK's other than 1.4.x, you should use the
    appropriate <tt class="filename">switchToJDK11.bat</tt> or
    <tt class="filename">switchToJDK12.bat</tt> to adapt the source files to the
    target JDK before running the appropriate
    <tt class="filename">buildJDK11.bat</tt> or <tt class="filename">buildJDK12.bat</tt>
    JDK and JRE versions.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N1278A"></a>Hsqldb CodeSwitcher</h2></div></div><div></div></div><p>CodeSwitcher is a tool to manage different version of Java source
    code. It allows to compile HSQLDB for different JDKs. It is something like
    a precompiler in C but it works directly on the source code and does not
    create intermediate output or extra files.</p><p>CodeSwitcher is used internally in HSQLDB build scripts. You do not
    have to use it separately to compile HSQLDB.</p><p>CodeSwitcher reads the source code of a file, removes comments where
    appropriate and comments out the blocks that are not used for a particular
    version of the file. This operation is done for all files of a defined
    directory, and all subdirectories.</p><div class="example"><a name="N12793"></a><p class="title"><b>Example&nbsp;A.2.&nbsp;Example source code before CodeSwitcher is run</b></p><pre class="programlisting">
        ...

    //#ifdef JAVA2

        properties.store(out,"hsqldb database");

    //#else

    /*

        properties.save(out,"hsqldb database");

    */

    //#endif

        ...</pre></div><p>The next step is to run CodeSwitcher.</p><div class="example"><a name="N1279B"></a><p class="title"><b>Example&nbsp;A.3.&nbsp;CodeSwitcher command line invocation</b></p><pre class="screen">
    java org.hsqldb.util.CodeSwitcher . -JAVA2</pre></div><p>The '.' means the program works on the current directory (all
    subdirectories are processed recursively). <tt class="literal">-JAVA2</tt> means
    the code labelled with JAVA2 must be switched off.</p><div class="example"><a name="N127A7"></a><p class="title"><b>Example&nbsp;A.4.&nbsp;Source code after CodeSwitcher processing</b></p><pre class="programlisting">
        ...

    //#ifdef JAVA2

    /*

        pProperties.store(out,"hsqldb database");

    */

    //#else

        pProperties.save(out,"hsqldb database");

    //#endif

        ...</pre></div><p>For detailed information on the command line options run
    <tt class="classname">java org.hsqldb.util.CodeSwitcher</tt>. Usage examples
    can be found in the switchtojdk1*.bat files in the
    <tt class="filename">/build</tt> directory.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N127B6"></a>Building documentation</h2></div></div><div></div></div><p>To build the User Guide in HTML format, you must have the Docbook
    stylesheets installed locally. The Docbook stylesheets are available on
    the Internet. On Linux, just install the
    <tt class="literal">docbook-xsl-stylesheets</tt> rpm. Then add an entry to
    <tt class="filename">build.properties</tt> in your build directory with
    contents like <div class="informalexample"><pre class="screen">docbook.xsl.home: /usr/share/sgml/docbook/docbook-xsl-stylesheets</pre></div> Where you specify your local path to the base
    directory of your Docbook stylesheet installation. Build like <div class="example"><a name="N127C8"></a><p class="title"><b>Example&nbsp;A.5.&nbsp;Building HTML User Guides</b></p><pre class="screen">ant docbooks-html
ant docbooks-chunk</pre></div></p><p>To build the User Guide in PDF format, you must also have the Java
    FOP system installed locally. FOP is available for free download on the
    Internet. Add an entry to <tt class="filename">build.properties</tt> in your
    build directory with contents like <div class="informalexample"><pre class="screen">fop.home /usr/local/fop-0.20.5</pre></div> Where you specify your local path to the base
    directory of your FOP installation. <div class="example"><a name="N127D9"></a><p class="title"><b>Example&nbsp;A.6.&nbsp;Building User Guides in all formats</b></p><pre class="screen">ant docbook</pre></div> Don't pay too much attention to error messages by FOP,
    because they are really warnings, but do check the output. If there are
    problems with the PDF output, try using a newer version of FOP.</p><div class="important" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Important</h3><p>By default, your docs will fail to build if you do not have
      Internet connectivity. This is because our primary Docbook source file
      references the Docbook DTDs via Internet URL. You can build without
      Internet connectivity by installing the Docbook DTDs and editing our
      primary Docbook source file. Docbook is available on the Internet. On
      Linux, just install the <tt class="literal">docbook-dtds</tt> or
      <tt class="literal">docbook</tt> rpm. Then make one edit to the file
      <tt class="filename">docsrc/guide/guide.xml</tt> in your HSQLDB distribution.
      Change the line containing <pre class="screen">"http://www.oasis-open.org/docbook/xml/4.2CR1/docbookx.dtd" [</pre>
      to <pre class="screen">"file:///usr/share/xml/docbook/schema/dtd/4.2/docbookx.dtd" [</pre>
      where the second filepath is the path to the
      <tt class="filename">docbookx.dtd</tt> file within your Docbook
      installation.</p></div></div></div><div class="appendix" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="firstclient-appendix"></a>Appendix&nbsp;B.&nbsp;First JDBC Client Example</h2></div></div><div></div></div><p>
            There is a copy of <tt class="filename">Testdb.java</tt> in the
            directory <tt class="filename">src/org/hsqldb/sample</tt> of your
            HSQLDB distribution.
        </p><div class="example"><a name="N1280A"></a><p class="title"><b>Example&nbsp;B.1.&nbsp;JDBC Client source code example</b></p><pre class="programlisting">/* Copyright (c) 2001-2005, The HSQL Development Group
 * All rights reserved.
 *
 * Redistribution and use in source and binary forms, with or without
 * modification, are permitted provided that the following conditions are met:
 *
 * Redistributions of source code must retain the above copyright notice, this
 * list of conditions and the following disclaimer.
 *
 * Redistributions in binary form must reproduce the above copyright notice,
 * this list of conditions and the following disclaimer in the documentation
 * and/or other materials provided with the distribution.
 *
 * Neither the name of the HSQL Development Group nor the names of its
 * contributors may be used to endorse or promote products derived from this
 * software without specific prior written permission.
 *
 * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS"
 * AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE
 * IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE
 * ARE DISCLAIMED. IN NO EVENT SHALL HSQL DEVELOPMENT GROUP, HSQLDB.ORG,
 * OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL,
 * EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT LIMITED TO,
 * PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES;
 * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND
 * ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT
 * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS
 * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
 */


package org.hsqldb.sample;

import java.sql.Connection;
import java.sql.DriverManager;
import java.sql.ResultSet;
import java.sql.ResultSetMetaData;
import java.sql.SQLException;
import java.sql.Statement;

/**
 * Title:        Testdb
 * Description:  simple hello world db example of a
 *               standalone persistent db application
 *
 *               every time it runs it adds four more rows to sample_table
 *               it does a query and prints the results to standard out
 *
 * Author: Karl Meissner karl@meissnersd.com
 */
public class Testdb {

    Connection conn;                                                //our connnection to the db - presist for life of program

    // we dont want this garbage collected until we are done
    public Testdb(String db_file_name_prefix) throws Exception {    // note more general exception

        // Load the HSQL Database Engine JDBC driver
        // hsqldb.jar should be in the class path or made part of the current jar
        Class.forName("org.hsqldb.jdbcDriver");

        // connect to the database.   This will load the db files and start the
        // database if it is not alread running.
        // db_file_name_prefix is used to open or create files that hold the state
        // of the db.
        // It can contain directory names relative to the
        // current working directory
        conn = DriverManager.getConnection("jdbc:hsqldb:"
                                           + db_file_name_prefix,    // filenames
                                           "sa",                     // username
                                           "");                      // password
    }

    public void shutdown() throws SQLException {

        Statement st = conn.createStatement();

        // db writes out to files and performs clean shuts down
        // otherwise there will be an unclean shutdown
        // when program ends
        st.execute("SHUTDOWN");
        conn.close();    // if there are no other open connection
    }

//use for SQL command SELECT
    public synchronized void query(String expression) throws SQLException {

        Statement st = null;
        ResultSet rs = null;

        st = conn.createStatement();         // statement objects can be reused with

        // repeated calls to execute but we
        // choose to make a new one each time
        rs = st.executeQuery(expression);    // run the query

        // do something with the result set.
        dump(rs);
        st.close();    // NOTE!! if you close a statement the associated ResultSet is

        // closed too
        // so you should copy the contents to some other object.
        // the result set is invalidated also  if you recycle an Statement
        // and try to execute some other query before the result set has been
        // completely examined.
    }

//use for SQL commands CREATE, DROP, INSERT and UPDATE
    public synchronized void update(String expression) throws SQLException {

        Statement st = null;

        st = conn.createStatement();    // statements

        int i = st.executeUpdate(expression);    // run the query

        if (i == -1) {
            System.out.println("db error : " + expression);
        }

        st.close();
    }    // void update()

    public static void dump(ResultSet rs) throws SQLException {

        // the order of the rows in a cursor
        // are implementation dependent unless you use the SQL ORDER statement
        ResultSetMetaData meta   = rs.getMetaData();
        int               colmax = meta.getColumnCount();
        int               i;
        Object            o = null;

        // the result set is a cursor into the data.  You can only
        // point to one row at a time
        // assume we are pointing to BEFORE the first row
        // rs.next() points to next row and returns true
        // or false if there is no next row, which breaks the loop
        for (; rs.next(); ) {
            for (i = 0; i &lt; colmax; ++i) {
                o = rs.getObject(i + 1);    // Is SQL the first column is indexed

                // with 1 not 0
                System.out.print(o.toString() + " ");
            }

            System.out.println(" ");
        }
    }                                       //void dump( ResultSet rs )

    public static void main(String[] args) {

        Testdb db = null;

        try {
            db = new Testdb("db_file");
        } catch (Exception ex1) {
            ex1.printStackTrace();    // could not start db

            return;                   // bye bye
        }

        try {

            //make an empty table
            //
            // by declaring the id column IDENTITY, the db will automatically
            // generate unique values for new rows- useful for row keys
            db.update(
                "CREATE TABLE sample_table ( id INTEGER IDENTITY, str_col VARCHAR(256), num_col INTEGER)");
        } catch (SQLException ex2) {

            //ignore
            //ex2.printStackTrace();  // second time we run program
            //  should throw execption since table
            // already there
            //
            // this will have no effect on the db
        }

        try {

            // add some rows - will create duplicates if run more then once
            // the id column is automatically generated
            db.update(
                "INSERT INTO sample_table(str_col,num_col) VALUES('Ford', 100)");
            db.update(
                "INSERT INTO sample_table(str_col,num_col) VALUES('Toyota', 200)");
            db.update(
                "INSERT INTO sample_table(str_col,num_col) VALUES('Honda', 300)");
            db.update(
                "INSERT INTO sample_table(str_col,num_col) VALUES('GM', 400)");

            // do a query
            db.query("SELECT * FROM sample_table WHERE num_col &lt; 250");

            // at end of program
            db.shutdown();
        } catch (SQLException ex3) {
            ex3.printStackTrace();
        }
    }    // main()
}    // class Testdb

</pre></div></div><div class="appendix" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="N12811"></a>Appendix&nbsp;C.&nbsp;Hsqldb Database Files and Recovery</h2></div><div><div class="legalnotice"><p>
        This text is based on HypersonicSQL documentation, updated to reflect 
        the latest version 1.8.0 of HSQLDB.
    </p></div></div><div><p class="pubdate">$Date: 2005/07/01 17:06:32 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N12828"></a></span></dt><dt><span class="section"><a href="#N12858">States</a></span></dt><dd><dl><dt><span class="section"><a href="#N1285B"></a></span></dt><dt><span class="section"><a href="#N1288A"></a></span></dt><dt><span class="section"><a href="#N128B9"></a></span></dt></dl></dd><dt><span class="section"><a href="#N128EB">Procedures</a></span></dt><dd><dl><dt><span class="section"><a href="#N128F0">Clean Shutdown</a></span></dt><dt><span class="section"><a href="#N1294A">Startup</a></span></dt><dt><span class="section"><a href="#N1299C">Repair</a></span></dt></dl></dd></dl></div><div class="section" lang="en"><div class="titlepage"><div></div><div></div></div><p>
        The Standalone and Client/Server modes will in most cases use files to 
        store all data to disk in a persistent and safe way.
        This document describes the meaning of the files, the states and the 
        procedures followed by the engine to recover the data.
    </p><p>
        A database named 'test' is used in this description.
        The database files will be as follows.
    </p></div><div class="variablelist"><p class="title"><b>Database Files</b></p><dl><dt><span class="term">test.properties</span></dt><dd><p>
        Contains the entry 'modified'.
        If the entry 'modified' is set to 'yes' then the database is either 
        running or was not closed correctly (because the close algorithm sets 
        'modified' to 'no' at the end).
        </p></dd><dt><span class="term">test.script</span></dt><dd><p>
        This file contains the SQL statements that makes up the database up to 
        the last checkpoint - it is in synch with
        <tt class="filename">test.backup</tt>.
        </p></dd><dt><span class="term">test.data</span></dt><dd><p>
        This file contains the (binary) data records for CACHED tables only.
        </p></dd><dt><span class="term">test.backup</span></dt><dd><p>
        This is compressed file that contains the complete backup of the old 
        <tt class="filename">test.data</tt> file at the time of last checkpoint.
        </p></dd><dt><span class="term">test.log</span></dt><dd><p>
        This file contains the extra SQL statements that have modified the 
        database since the last checkpoint (something like the 'Redo-log' or 
        'Transaction-log', but just text).
        </p><p>
        In the above list, a checkpoint results from both a CHECKPOINT command 
        and a SHUTDOWN command.
        </p></dd></dl></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12858"></a>States</h2></div></div><div></div></div><div class="section" lang="en"><div class="titlepage"><div></div><div></div></div>Database is closed correctly</div><div class="itemizedlist"><p class="title"><b>State after using the command <tt class="literal">SHUTDOWN</tt></b></p><ul type="disc"><li><p>
            The <tt class="filename">test.data</tt> file is fully updated.
        </p></li><li><p>
            The <tt class="filename">test.backup</tt> contains the compressed 
            <tt class="filename">test.data</tt> file.
        </p></li><li><p>
            The  <tt class="filename">test.script</tt> contains the information in 
            the database, excluding data for CACHED and TEXT tables. 
        </p></li><li><p>
            The <tt class="filename">test.properties</tt> contains the entry 
            'modified'  set to 'no'.
        </p></li><li><p>
            There is no <tt class="filename">test.log</tt> file.
        </p></li></ul></div><div class="section" lang="en"><div class="titlepage"><div></div><div></div></div>Database is closed correctly with SHUTDOWN SCRIPT</div><div class="itemizedlist"><p class="title"><b>State after using the command <tt class="literal">SHUTDOWN SCRIPT</tt></b></p><ul type="disc"><li><p>
            The <tt class="filename">test.data</tt> file does not exist; all CACHED 
            table data is in the <tt class="filename">test.script</tt> file
        </p></li><li><p>
            The <tt class="filename">test.backup</tt> does not exist.
        </p></li><li><p>
            The  <tt class="filename">test.script</tt> contains the information in 
            the database, including data for CACHED and TEXT tables.
        </p></li><li><p>
            The <tt class="filename">test.properties</tt> contains the entry 
            'modified'  set to 'no'.
        </p></li><li><p>
            There is no <tt class="filename">test.log</tt> file.
        </p></li></ul></div><div class="section" lang="en"><div class="titlepage"><div></div><div></div></div>Database is aborted</div><p>
        This may happen by sudden power off, Ctrl+C in Windows, but may be 
        simulated using the command SHUTDOWN IMMEDIATELY.
    </p><div class="itemizedlist"><p class="title"><b>Aborted Database state</b></p><ul type="disc"><li><p>
            The <tt class="filename">test.properties</tt> still containes 
            'modified=yes'.
        </p></li><li><p>
            The <tt class="filename">test.script</tt> contains a snapshot of the 
            database at the last checkpoint and is OK.
        </p></li><li><p>
            The <tt class="filename">test.data</tt> file may be corrupt because the 
            cache in memory was not written out completely.
        </p></li><li><p>
            The <tt class="filename">test.backup</tt> file contains a snapshot of 
            <tt class="filename">test.data</tt> that corresponds to 
            <tt class="filename">test.script</tt>.
        </p></li><li><p>
            The  <tt class="filename">test.log</tt> file contain all information to 
            re-do all changes since the snanapshot.
            As a result of abnormal termination, this file may be partially 
            corrupt.
        </p></li></ul></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N128EB"></a>Procedures</h2></div></div><div></div></div><p>
        The database engine performs the following procedures internally in 
        different circumstances. 
    </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N128F0"></a>Clean Shutdown</h3></div></div><div></div></div><div class="procedure"><p class="title"><b>Procedure&nbsp;C.1.&nbsp;Clean Hsqldb database shutdown</b></p><ol type="1"><li><p>
                The <tt class="filename">test.data</tt> file is written completely 
                (all the modified cached table rows are witten out) and closed.
            </p></li><li><p>
                The <tt class="filename">test.backup.new</tt> is created (containing 
                the compressed <tt class="filename">test.data</tt> file)
            </p></li><li><p>
                The file <tt class="filename">test.script.new</tt> is created using 
                the information in the database (and thus shrinks because no 
                UPDATE and DELETE statements; only INSERT).
            </p></li><li><p>
                The entry 'modified' in the properties file is set to 
                'yes-new-files'
            </p></li><li><p>
                The file <tt class="filename">test.script</tt> is deleted
            </p></li><li><p>
                The file <tt class="filename">test.script.new</tt> is renamed to 
                <tt class="filename">test.script</tt>
            </p></li><li><p>
                The file <tt class="filename">test.backup</tt> is deleted
            </p></li><li><p>
                The file <tt class="filename">test.backup.new</tt> is renamed to 
                <tt class="filename">test.backup</tt>
            </p></li><li><p>
                The entry 'modified' in the properties file is set to 'no' 
            </p></li><li><p>
                The file <tt class="filename">test.log</tt> is deleted
            </p></li></ol></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1294A"></a>Startup</h3></div></div><div></div></div><div class="procedure"><p class="title"><b>Procedure&nbsp;C.2.&nbsp;Database is opened</b></p><ol type="1"><li><p>
                Check if the database files are in use (by checking a special 
                <tt class="filename">test.lck</tt> file).
            </p></li><li><p>
                See if the <tt class="filename">test.properties</tt> file exists,
                otherwise create it.
            </p></li><li><p>
                If the <tt class="filename">test.properties</tt> did not exist, then 
                this is a new database.
                Create the empty <tt class="filename">test.log</tt> to append new 
                commands.
            </p></li><li><p>
                If it is an existing database, check in the
                <tt class="filename">test.properties</tt> file if 'modified=yes'.
                This would mean last time it was not closed correctly, and thus 
                the <tt class="filename">test.data</tt> file may be corrupted or 
                incomplete.
                In this case the 'REPAIR' algorithm is executed (see below), 
                before the database is opened normally.
            </p></li><li><p>
                Otherwise, if in the <tt class="filename">test.properties</tt> file
                'modified=yes-new-files', then the (old) 
                <tt class="filename">test.backup</tt> and 
                <tt class="filename">test.script</tt> files are deleted and the new 
                <tt class="filename">test.script.new</tt> file is renamed to 
                <tt class="filename">test.script</tt>.
                </p></li><li><p>
                Open the <tt class="filename">test.script</tt> file and execute the 
                commands.
            </p></li><li><p>
                Create the empty test.log to append new commands.
            </p></li></ol></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N1299C"></a>Repair</h3></div></div><div></div></div><p>
            The current <tt class="filename">test.data</tt> file is corrupt, but 
            with the old <tt class="filename">test.data</tt> (from the 
            <tt class="filename">test.backup</tt> file and 
            <tt class="filename">test.script</tt>) and the current 
            <tt class="filename">test.log</tt>, the database is made up-to-date.
            The database engine takes these steps:
        </p><div class="procedure"><p class="title"><b>Procedure&nbsp;C.3.&nbsp;Database Repair</b></p><ol type="1"><li><p>
                    Restore the old <tt class="filename">test.data</tt> file from 
                    the backup (uncompress the <tt class="filename">test.backup</tt>
                    and overwrite <tt class="filename">test.data</tt>).
            </p></li><li><p>
                Execute all commands in the <tt class="filename">test.script</tt> 
                file.
            </p></li><li><p>
                Execute all commands in the <tt class="filename">test.log</tt> file.
                If due to corruption, an exception is thrown, the rest of the 
                lines of command in the <tt class="filename">test.log</tt> file are 
                ignored.
            </p></li><li><p>
                Close the database correctly (including a backup).
            </p></li></ol></div></div></div></div><div class="appendix" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="N129E2"></a>Appendix&nbsp;D.&nbsp;Running Hsqldb with OpenOffice.org 1.1.x</h2></div><div><div class="author"><h3 class="author"><span class="firstname">Hermann</span> <span class="surname">Kienlein</span></h3><div class="affiliation"><span class="orgname">EDV - Systeme Kienlein<br></span></div><tt class="email">&lt;<a href="mailto:hermann@kienlein.com">hermann@kienlein.com</a>&gt;</tt></div></div><div><div class="legalnotice"><p>
            Copyright 2003-2004 Hermann Kienlein.
            Permission is granted to distribute this document without any 
            alteration under the terms of the HSQLDB license.
            Additional permission is granted to the HSQLDB Development Group to 
            distribute this document with or without alterations under the 
            terms of the HSQLDB license.
        </p></div></div><div><p class="pubdate">$Date: 2005/06/08 16:02:34 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N12A02">Introduction</a></span></dt><dt><span class="section"><a href="#N12A0B">Installing</a></span></dt><dt><span class="section"><a href="#N12A10">Setting up OpenOffice.org</a></span></dt><dd><dl><dt><span class="section"><a href="#N12A22">On Windows</a></span></dt><dt><span class="section"><a href="#N12A35">On Linux</a></span></dt></dl></dd></dl></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12A02"></a>Introduction</h2></div></div><div></div></div><p>
            HSQLDB can now act as a Database with OpenOffice.org.
            This document is written to help you connecting and running HSQLDB 
            out of OpenOffice.org in a simple way.
            Without user-managment and only for your single-system.
        </p><p>
            If you have problems read the other available documents, because I 
            will not write them here again.
            If you need a real DB-System with user-management and different 
            rights for different users, read the other documents.
        </p><p>
            HSQLDB is included with OpenOffice.org 2.0 and is used by default.
            Please refer to standard OpenOffice.org 2.0 documentation on how 
            to use HSQLDB with this version.
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12A0B"></a>Installing</h2></div></div><div></div></div><p>
            I assume you have a running OpenOffice.org (OOo) and a
            JavaRuntimeEnvironment.
            So place the hsqldb_*.zip file where you want on your disk 
            and unpack it (I assume you have done this already).
        </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12A10"></a>Setting up OpenOffice.org</h2></div></div><div></div></div><p>
            Start OOo with a text document and go to the Database-Explorer
            (simply by pressing F4).
            In the left frame you see a tree-view with all known databases in
            OOo.
        </p><p>
            A right mouse-click opens a menu where you can manage your
            databases.
            So click on <tt class="literal">New Database</tt> and choose a name that 
            you want to have inside OOo.
            I chose HSQLDB as name.
        </p><p>
            As connection-type choose JDBC and then switch to the JDBC-tab.
        </p><p>
            As Driver-Class insert <tt class="classname">org.hsqldb.jdbcDriver</tt> 
            and as URL choose the following:
        </p><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N12A22"></a>On Windows</h3></div></div><div></div></div><p>
                You can specify a directory where HSQLDB should store the info 
                and data. Something like 
                <tt class="literal">jdbc:hsqldb:file:c:\javasrc\hsqldb-dev\databasename</tt>
                (where jdbc: is written by OOo).
                The string 
                <tt class="filename">c:\javasrc\hsqldb-dev\databasename</tt>
                works only on windows, but you can write this down as 
                linux-path like
                <tt class="filename">/javasrc/hsqldb-dev/databasename</tt> too.
                Then HSQLDB takes the c:\ drive as root.
                This means this works only on c:\ for you.
            </p><p>
                The first is the directory-path and the databasename is the 
                identifier for the database.
            </p></div><div class="section" lang="en"><div class="titlepage"><div><div><h3 class="title"><a name="N12A35"></a>On Linux</h3></div></div><div></div></div><p>
                Choose a path as said for windows like /opt/db/data
            </p><p>
                As username take sa, this is the standard-administrator for 
                HSQLDB.
            </p><p>
                Now click the OK-Button
            </p></div><p>
            Now OOo has to find your <tt class="filename">hsqldb.jar</tt> file.
            So go to options =&gt; security and insert the path to the .jar 
            file.
            If you have problems, search the Online-help for JDBC.
            You then get help in your own language (this is generally quite 
            better than my English, I think ;-)
        </p><p>
            If you cannot write to your Tables, OOo thinks that you don't 
            have permission to write to HSQLDB.
            Then we tell OOo to ignore the DriverPrivileges because on our
            single-user-system we do not need them.
        </p><p>
            Because OOo is working on this, the next Step is only needed for 
            systems without write - permission.
        </p><p>
            So we go to http://dba.openoffice.org and look at the
            <tt class="filename">IgnoreDriverPrivileges.html</tt> file in the 
            HowTo-section.
            You find here a macro-code.
        </p><p>
            Open tools =&gt; macro in OOo to get the Basic-IDE.
            Here simple copy and paste the code and run the macro.
            You see a input-box where you only have to insert the name of your 
            DB, in my example I have to insert HSQLDB, because I took this as 
            name in OOo.
        </p><p>
            Note that if you change your OOo-DB name, you have to run this 
            macro again!
        </p><p>
            Now we only have to stop and restart OOo.
            Be sure that you exit Quickstarter and all running processes too.
            On next OOo-Start you should have a running Database in 
            OpenOffice.org.
        </p></div></div><div class="appendix" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="N12A55"></a>Appendix&nbsp;E.&nbsp;Hsqldb Test Utility</h2></div><div><p class="pubdate">$Date: 2005/05/27 12:41:50 $</p></div></div><div></div></div><p>The <tt class="literal">org.hsqldb.test</tt> package contains a number of
  tests for various functions of the database engine. Among these, the
  <tt class="classname">TestSelf</tt> class performs the tests that are based on
  scripts. To run the tests, you should compile the
  <tt class="filename">hsqldbtest.jar</tt> target with Ant.</p><p>For <tt class="classname">TestSelf</tt>, a batch file is provided in the
  testrun/hsqldb directory, together with a set of TestSelf*.txt files. To
  start the application in Windows, change to the directory and type:</p><pre class="screen">
    runtest TestSelf</pre><p>In Unix / Linux, type:</p><pre class="screen">
    ./runTest.sh TestSelf</pre><p>The new version of <tt class="classname">TestSelf</tt> runs multiple SQL
  test files to test different SQL operations of the database. All files in
  the working directory with names matching TestSelf*.txt are processed in
  alphabetical order.</p><p>You can add your own scripts to test different series of SQL queries.
  The format of the TestSelf*.txt file is simple text, with some indentation
  and prefixes in the form of Java-style comments. The prefixes indicate what
  the expected result should be.</p><div class="itemizedlist"><ul type="disc"><li><p>Comment lines must start with -- and are ignored</p></li><li><p>Lines starting with spaces are the continuation of the previous
      line</p></li><li><p>SQL statements with no prefix are simply executed.</p></li><li><p>
        <span class="emphasis"><em>The remaining items in this list exemplify use of the
        available command line-prefixes.</em></span>
      </p></li><li><div class="informalexample"><p>The /*s*/ option stands for silent. It is used for executing
        quries regardless of results. Used for preparation of tests, not for
        actual tests.</p><pre class="programlisting">
/*s*/ Any SQL statement - errors are ignored</pre></div></li><li><div class="informalexample"><p>The /*c&lt;rows&gt;*/ option is for SELECT queries and
        asserts the number of rows in the result matches the given
        count.</p><pre class="programlisting">
/*c&lt;rows&gt;*/ SQL statement returning count of &lt;rows&gt;</pre></div></li><li><div class="informalexample"><p>The /*u*/ option is for queries that return an update count,
        such as DELETE and UPDATE. It asserts the update count
        matches.</p><pre class="programlisting">
/*u&lt;count&gt;*/ SQL statement returning an update count equal to &lt;count&gt;</pre></div></li><li><div class="informalexample"><p>The /*e*/ option asserts that the given query results in an
        erros. It is mainly used for testing the error detection capabilities
        of the engine. It can also be used with syntactically valid queries to
        assert a certain state in the database. For example a CREATE TABLE can
        be used to assert the table of the same name already exists.</p><pre class="programlisting">
/*e*/ SQL statement that should produce an error when executing</pre></div></li><li><div class="informalexample"><p>The /*r....*/ option asserts the SELECT query returns a
        single row containing the given set of field values.</p><pre class="programlisting">
/*r&lt;string1&gt;,&lt;string2&gt;*/ SQL statement returning a single row ResultSet equal to the specified value</pre></div></li><li><div class="informalexample"><p>The extended /*r...*/ option asserts the SELECT query returns
        the given rows containing the given set of field values.</p><pre class="programlisting">
/*r
    &lt;string1&gt;,&lt;string2&gt;
    &lt;string1&gt;,&lt;string2&gt;
    &lt;string1&gt;,&lt;string2&gt;
*/ SQL statement returning a multiple row ResultSet equal to the specified values</pre></div><p>(note that the result set lines are indented).</p></li><li><p>All the options are lowercase letters. During development, an
      uppercase can be used for a given test to exclude a test from the test
      run. The utility will just report the test blocks that have been
      excluded without running them. Once the code has been developed, the
      option can be turned into lowercase to perform the actual test. </p></li></ul></div><p>See the TestSelf*.txt files in the /testrun/hsqldb/ directory for
  actual examples.</p></div><div class="appendix" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="N12ACB"></a>Appendix&nbsp;F.&nbsp;Database Manager</h2></div><div><div class="authorgroup"><div class="author"><h3 class="author"><span class="firstname">Fred</span> <span class="surname">Toussi</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:ft@cluedup.com">ft@cluedup.com</a>&gt;</tt></div><div class="author"><h3 class="author"><span class="firstname">Blaine</span> <span class="surname">Simpson</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:ft@cluedup.com">ft@cluedup.com</a>&gt;</tt></div></div></div><div><p class="pubdate">$Date: 2005/07/25 23:21:10 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N12AF4">Brief Introduction</a></span></dt><dt><span class="section"><a href="#N12B1E">Auto tree-update</a></span></dt><dt><span class="section"><a href="#N12B35">Automatic Connection</a></span></dt><dt><span class="section"><a href="#N12B43">RC File</a></span></dt><dt><span class="section"><a href="#N12B68">Using the current DatabaseManagers with an older HSQLDB
    distribution.</a></span></dt><dt><span class="section"><a href="#N12B9A">DatabaseManagerSwing as an Applet</a></span></dt></dl></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12AF4"></a>Brief Introduction</h2></div></div><div></div></div><p>The Database Manager tool is a simple GUI database query tool with a
    tree display of the tables. Both AWT and SWING versions of the tool are
    available and work almost identically. The AWT version class name is
    org.hsqldb.util.DatabaseManager; the SWING version,
    org.hsqldb.util.DatabaseManagerSwing.</p><p>The AWT version of the database manager can be deployed as an applet
    in a browser. A demo HTML file with an embedded Database Manager is
    included in the /demo directory.</p><p>When the Database Manager is started, a dialogue allows you to enter
    the JDBC driver, URL, user and password for the new connection. A
    drop-down box, Type, offers preset values for JDBC driver and URL for most
    popular database engines, including HSQLDB. Once you have selected an item
    from this drop-down box, you should edit the URL to specify the details of
    the database or any additional properties to pass. You should also enter
    the username and password before clicking on the OK button.</p><p>The connection dialogue allows you to save the settings for the
    connection you are about to make. You can then access the connection in
    future sessions. To save a connection setting, enter a name in the Setting
    Name box before clicking on the OK button. Next time the connection
    dialogue is displayed, the drop-down box labeled Recent will include the
    name for all the saved connection settings. When you select a name, the
    individual settings are displayed in the appropriate boxes.</p><p>The small Clr button next to the drop-down box allows you to clear
    all the saved settings. If you want to modify an existing setting, first
    select it from the drop-down box then modify any of the text boxes before
    making the connection. The modified values will be saved.</p><p>Most menu items have context-sensitive tool tip help text which
    will appear if you hold the mouse cursor still over the desired menu item.
    (Assuming that you don't turn Tooltips off under the
    <span class="guimenu">Help</span> menu.</p><p>The DatabaseManagers do work with HSQLDB servers serving
    TLS-encrypted JDBC data. See the <a href="#tls-chapter" title="Chapter&nbsp;7.&nbsp;TLS">TLS</a> chapter and the <a href="#auth-section" title="RC File Authentication Setup">RC File Authentication Setup</a> section of this Guide.</p><div class="tip" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Tip</h3>
        If you are using DatabaseManagerSwing with Oracle, you will want
        to make sure that <span class="guimenuitem">Show row counts</span>
        and <span class="guimenuitem">Show row counts</span> are both off
        <span class="emphasis"><em>before connecting to the database</em></span>.
        You may also want to turn off Auto tree-update, as described in
        the next section.
    </div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12B1E"></a>Auto tree-update</h2></div></div><div></div></div><p>By default, the object tree in the left panel is refreshed when
    you execute DDL which may update those objects. If you are on a slow
    network or performance-challenged PC, use the <span class="guimenu">view</span> /
    <span class="guimenuitem">Auto-refresh tree</span> menu item to turn it off. You
    will then need to use the <span class="guimenu">view</span><span class="guimenuitem">Refresh
    tree</span> menu item every time that you want to refresh the
    tree.</p><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Note</h3><p>Auto-refresh tree does not automatically show all updates to
      database objects, it only refreshes when you submit DDL which may update
      database objects. (This behavior is a compromise between utility and
      performance).</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12B35"></a>Automatic Connection</h2></div></div><div></div></div><p>You can use command-line switches to supply connection information.
    If you use these switch(es), then the connection dialog window will be
    skipped and a JDBC connection will be established immediately. Assuming
    that the hsqldb.jar (or an alternative jar) are in your CLASSPATH, this
    command will list the available command-line options. <div class="informalexample"><pre class="screen">
    java org.hsqldb.util.DatabaseManagerSwing --help</pre></div></p><p>It's convenient to skip the connection dialog window if you
    always work with the same database account.</p><div class="warning" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Warning</h3><p>Use of the --password switch is not secure. Everything typed on
      command-lines is generally available to other users on the computer. The
      problem is compounded if you use a network connection to obtain your
      command line. The RC File section explains how you can set up automatic
      connections without supplying a password on the command line.</p></div></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12B43"></a>RC File</h2></div></div><div></div></div><p>You can skip the connection dialog window securely by putting the
    connection information into an RC file and then using the
    <tt class="literal">--urlid</tt> switch to DatabaseManager or
    DatabaseManagerSwing. This strategy is great for adding launch menu items
    and/or launch icons to your desktop. You can set up one icon for each of
    the database accounts which you regularly use.</p><p>The default location for the RC file is
    <tt class="filename">dbmanager.rc</tt> in your home directory. The <a href="#auth-section" title="RC File Authentication Setup">RC File Authentication Setup</a> section explains how to put
    the connection information into this text file. If you also run <a href="#sqltool-chapter" title="Chapter&nbsp;8.&nbsp;SqlTool">SqlTool</a>, then you can share
    the RC file with SqlTool by using a sym-link (if your operating system
    supports sym links), or by using the <tt class="literal">--rcfile</tt> switch
    for either SqlTool or DatabaseManagerSwing.</p><div class="warning" style="margin-left: 0.5in; margin-right: 0.5in;"><h3 class="title">Warning</h3><p>Use your operating system facilities to prevent others from
      reading your RC file, since it contains passwords.</p></div><p>To set up launch items/icons, first experiment on your command line
    to find exactly what command works. For example, <div class="informalexample"><pre class="screen">
    java -cp /path/to/hsqldb.jar org.hsqldb.util.DatabaseManagerSwing --urlid mem</pre></div> Then, use your window manager to add an item that
    runs this command.</p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12B68"></a>Using the current DatabaseManagers with an older HSQLDB
    distribution.</h2></div></div><div></div></div><p>This procedure will allow users of a legacy version of HSQLDB to
    use all of the new features of the DatabaseManagers. You will also get the
    new version of the SqlTool! This procedure works for distros going back to
    1.7.3.3 at least, probably much farther.</p><p>These instructions assume that you are capable of running an Ant
    build. See the <a href="#building-appendix" title="Appendix&nbsp;A.&nbsp;Building HSQLDB">Building HSQLDB</a> chapter.</p><div class="procedure"><ol type="1"><li><p>Download and extract a current HSQLDB distribution. If you
        don't want to use the source code, documentation, etc., you can use a
        temporary directory and remove it afterwards.</p></li><li><p>Cd to the build directory under the root directory where you
        extracted the distribution to.</p></li><li><p>Run <tt class="literal">ant hsqldbutil</tt>.</p></li><li><p>If you're going to wipe out the build directory, copy
        <tt class="filename">hsqldbutil.jar</tt> to a safe location
        first.</p></li><li><p>For now on, whenver you are going to run DatabaseManager*,
        make sure that you have this <tt class="filename">hsqldbutil.jar</tt> as
        the first item in your CLASSPATH.</p></li></ol></div><p>Here's a UNIX example where somebody wants to use the new
    DatabaseManagerSwing with their older HSQLDB database, as well as with
    Postgresql and a local application. <div class="informalexample"><pre class="screen">
CLASSPATH=/path/to/hsqldbutil.jar:/home/bob/myapp/classes:/usr/local/lib/pg.jdbc3.jar
export CLASSPATH
java org.hsqldb.util.DatabaseManagerSwing --urlid urlid</pre></div></p></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12B9A"></a>DatabaseManagerSwing as an Applet</h2></div></div><div></div></div><p>
          DatabaseManagerSwing is also an applet.
          You can use it in HTML, JSPs, etc.
          Be aware that in Applet mode, actions to load or save local files
          will be disabled, and attempts to access any server other than 
          the HTML-serving-host will be fail.
      </p><p>
          Since the Applet can not store or load locally saved preferences,
          the only way to have persistent preference settings is by using
          Applet parameters.
          <div class="variablelist"><p class="title"><b>DatabaseManagerSwing Applet Parameters</b></p><dl><dt><span class="term">jdbcUrl</span></dt><dd>
                  URL of a data source to auto-connect to.  String value.
              </dd><dt><span class="term">jdbcDriver</span></dt><dd>
                  URL of a data source to auto-connect to.  String value.
                  Defaults to <tt class="literal">org.hsqldb.jdbcDriver</tt>.
              </dd><dt><span class="term">jdbcUser</span></dt><dd>
                  User name for data source to auto-connect to.  String value.
              </dd><dt><span class="term">jdbcPassword</span></dt><dd>
                  Password for data source to auto-connect to.  String value.
                  Defaults to zero-length string.
              </dd><dt><span class="term">schemaFilter</span></dt><dd>
                  Display only object from this schema in the object navigator.
                  String value.
              </dd><dt><span class="term">laf</span></dt><dd>
                  Look-and-feel.  String value.
              </dd><dt><span class="term">loadSampleData</span></dt><dd>
                  Auto-load sample data.  Boolean value.
                  Defaults to false.
              </dd><dt><span class="term">autoRefresh</span></dt><dd>
                  Auto-refresh the object navigator when DDL modifications
                  detected in user SQL commands.  Boolean value.
                  Defaults to true.
              </dd><dt><span class="term">showRowCounts</span></dt><dd>
                  Show number of rows in each table in the object navigator.
                  Boolean value.  Defaults to false.
              </dd><dt><span class="term">showSysTables</span></dt><dd>
                  Show system tables in the object navigator.  Boolean value.
                  Defaults to false.
              </dd><dt><span class="term">showSchemas</span></dt><dd>
                  Show object names like schema.name in object navigator.
                  Boolean value.  Defaults to true.
              </dd><dt><span class="term">resultGrid</span></dt><dd>
                  Show query results in Gui grid (as opposed to in plain text).
                  Boolean value.  Defaults to true.
              </dd><dt><span class="term">showToolTips</span></dt><dd>
                  Show help hover-text.  Boolean value.  Defaults to true.
              </dd></dl></div>
      </p></div></div><div class="appendix" lang="en"><div class="titlepage"><div><div><h2 class="title"><a name="N12BF8"></a>Appendix&nbsp;G.&nbsp;Transfer Tool</h2></div><div><div class="authorgroup"><div class="author"><h3 class="author"><span class="firstname">Fred</span> <span class="surname">Toussi</span></h3><div class="affiliation"><span class="orgname">HSQLDB Development Group<br></span></div><tt class="email">&lt;<a href="mailto:ft@cluedup.com">ft@cluedup.com</a>&gt;</tt></div></div></div><div><p class="pubdate">$Date: 2005/06/29 23:15:13 $</p></div></div><div></div></div><div class="toc"><p><b>Table of Contents</b></p><dl><dt><span class="section"><a href="#N12C15">Brief Introduction</a></span></dt></dl></div><div class="section" lang="en"><div class="titlepage"><div><div><h2 class="title" style="clear: both"><a name="N12C15"></a>Brief Introduction</h2></div></div><div></div></div><p>Transfer Tool is a GUI program for transferring SQL schema and data
    from one JDBC source to another. Source and destination can be different
    database engines or different databases on the same server.</p><p>Transfer Tool works in two different modes. Direct transfer
    maintains a connection to both source and destination and performs the
    transfer. Dump and Restore mode is invoked once to transfer the data from
    the source to a text file (Dump), then again to transfer the data from the
    text file to the destination (Restore). With Dump and Restore, it is
    possible to make any changes to database object definitions and data prior
    to restoring it to the target.</p><p>Dump and Restore modes can be set via the command line with -d
    (--dump) or -r (--restore) options. Alternatively the Transfer Tool can be
    started with any of the three modes from the Database Manager's Tools
    menu.</p><p>The connection dialogue allows you to save the settings for the
    connection you are about to make. You can then access the connection in
    future sessions. These settings are shared with those from the Database
    Manager tool. See the appendix on Database Manager for details of the
    connection dialogue box.</p><p>In version 1.8.0 Transfer Tool is no longer part of the hsqldb.jar.
    You can build the hsqldbutil.jar using the Ant command of the same name,
    to build a jar that includes Transfer Tool and the Database
    Manager.</p><p>When collecting meta-data, Transfer Tool performs SELECT * FROM
    &lt;table&gt; queries on all the tables in the source database. This may
    take a long time with some database engines. When the source database is
    HSQLDB, this means memory should be available for the result sets returned
    from the queries. Therefore, the memory allocation of the java process in
    which Transfer Tool is executed may have to be high.</p></div></div></div></body></html>