File: sqlreference.xml

package info (click to toggle)
virtuoso-opensource 6.1.4%2Bdfsg1-7
  • links: PTS, VCS
  • area: main
  • in suites: wheezy
  • size: 245,116 kB
  • sloc: ansic: 639,631; sql: 439,225; xml: 287,085; java: 61,048; sh: 38,723; cpp: 36,889; cs: 25,240; php: 12,562; yacc: 9,036; lex: 7,149; makefile: 6,093; jsp: 4,447; awk: 1,643; perl: 1,017; ruby: 1,003; python: 329
file content (5310 lines) | stat: -rw-r--r-- 207,757 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
<?xml version="1.0" encoding="ISO-8859-1"?>
<!--
 -  
 -  This file is part of the OpenLink Software Virtuoso Open-Source (VOS)
 -  project.
 -  
 -  Copyright (C) 1998-2006 OpenLink Software
 -  
 -  This project is free software; you can redistribute it and/or modify it
 -  under the terms of the GNU General Public License as published by the
 -  Free Software Foundation; only version 2 of the License, dated June 1991.
 -  
 -  This program is distributed in the hope that it will be useful, but
 -  WITHOUT ANY WARRANTY; without even the implied warranty of
 -  MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
 -  General Public License for more details.
 -  
 -  You should have received a copy of the GNU General Public License along
 -  with this program; if not, write to the Free Software Foundation, Inc.,
 -  51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA
 -  
 -  
-->
<chapter label="sqlreference.xml" id="sqlreference">
	<title>SQL Reference</title>
	<bridgehead>SQL Reference</bridgehead>
	<abstract>
<para>SQL Reference.</para>
</abstract>
<chapterinfo>
  <keywordset>
    <keyword>SQL</keyword>
    <keyword>SQL Reference</keyword>
    <keyword>Select</keyword>
    <keyword>Update</keyword>
    <keyword>delete</keyword>
    <keyword>Select Statement</keyword>
    <keyword>SQL Syntax</keyword>
    <keyword>Syntax</keyword>
  </keywordset>
</chapterinfo>

	<!-- ======================================== -->
	<sect1 id="sqlrefDATATYPES">
		<title>Datatypes</title>
		<variablelist>
			<varlistentry>
				<term>CHARACTER</term>
				<listitem>
					<para>CHARACTER</para>
				</listitem>
				<listitem>
					<para>VARCHAR</para>
				</listitem>
				<listitem>
					<para>VARCHAR&apos;(&apos;INTNUM&apos;)&apos;</para>
				</listitem>
				<listitem>
					<para>NVARCHAR</para>
				</listitem>
				<listitem>
					<para>NVARCHAR&apos;(&apos;INTNUM&apos;)&apos;</para>
				</listitem>
				<listitem>
					<para>CHAR&apos;(&apos;INTNUM&apos;)&apos;</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>NUMERIC</term>
				<listitem>
					<para>NUMERIC</para>
				</listitem>
				<listitem>
					<para>NUMERIC&apos;(&apos;INTNUM&apos;)&apos;</para>
				</listitem>
				<listitem>
					<para>NUMERIC&apos;(&apos;INTNUM&apos;,&apos;INTNUM&apos;)&apos;</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>DECIMAL</term>
				<listitem>
					<para>DECIMAL</para>
				</listitem>
				<listitem>
					<para>DECIMAL&apos;(&apos;INTNUM&apos;)&apos;</para>
				</listitem>
				<listitem>
					<para>DECIMAL&apos;(&apos;INTNUM&apos;,&apos;INTNUM&apos;)&apos;</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>INTEGER</term>
				<listitem>
					<para>INT</para>
				</listitem>
				<listitem>
					<para>INTEGER</para>
				</listitem>
				<listitem>
					<para>SMALLINT</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>FLOAT</term>
				<listitem>
					<para>FLOAT</para>
				</listitem>
				<listitem>
					<para>FLOAT&apos;(&apos;INTNUM&apos;)&apos;</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>REAL</term>
				<listitem>
					<para>REAL</para>
				</listitem>
				<listitem>
					<para>DOUBLE PRECISION</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>LONG VARCHAR</term>
				<listitem>
					<para>BLOB data</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>VARBINARY [( precision )]</term>
				<listitem>
					<para>Binary data</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>LONG VARBINARY</term>
				<listitem>
					<para>Binary BLOB data</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>TIMESTAMP</term>
				<listitem>
					<para>TIMESTAMP</para>
				</listitem>
				<listitem>
					<para>DATETIME</para>
				</listitem>
				<listitem>
					<para>TIME</para>
				</listitem>
				<listitem>
					<para>DATE</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>&lt;UDT&gt;</term>
				<listitem>
					<para>User Defined Type with varbinary-like size properties.</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>LONG &lt;UDT&gt;</term>
				<listitem>
					<para>User Defined Type with LONG varbinary-like size properties.</para>
				</listitem>
			</varlistentry>
			<varlistentry>
				<term>LONG XML</term>
				<listitem>
					<para>LONG XML BLOB-like data type.</para>
				</listitem>
			</varlistentry>
		</variablelist>

		<note><title>Note:</title>
		  <para>User Defined Types can be created from native or external types,
		composites or classes from any hosted language such as Java or .Net.  Any
		User Defined Type can be used to define a column in a
		CREATE TABLE statement.</para></note>

 		<sect2 id="dt_dateliterals">
 			<title>Date Literals</title>
 			<para>
 			Virtuoso does not support date literals or the
 			DATE reserved keyword.  Literal dates should be
 			enclosed in a conversion function such as
 			<function>stringdate()</function>, as in this example:
 			</para>
 			<programlisting>
select * from demo.demo.orders o
  where o.orderdate between stringdate('1994-01-01') And stringdate('1997-12-31')
</programlisting>
      <para>Alternatively type casts can be used to explicitly instruct Virtuoso
      to assume a string as a date, see below.</para>
 		</sect2>
		<sect2 id="dtcasting">
			<title>Casting</title>
			<para>
Blob types can be cast to varchars.  This will produce a string of
up to 16 MB in length and an error for longer blobs.
	</para>
			<para>
Nothing can be cast to a blob type.  Blobs only come from selecting
blob columns and are created by assigning
values to such columns.
	</para>
			<para>
Converting non-integer values to integers rounds towards 0.
	</para>
			<para>
Any data type can be converted to binary with the VARBINARY target data
type.  The result may or may not be meaningful.  Specifically datetime can be
converted to binary and back.
	</para>
			<programlisting>
cast_expression :
		CAST &apos;(&apos; scalar_exp AS data_type [COLLATE collation_name ] &apos;)&apos;

collation_name :
	identifier
	| owner &apos;.&apos; identifier
	| qualifier &apos;.&apos; owner &apos;.&apos; identifier
</programlisting>
			<para>
The CAST expression converts the type of the scalar_exp into the data_type,
if possible.  If the conversion is not meaningful, as from a float to a date,
an error is signalled.
	</para>
			<para>
CAST is the recommended way of converting between data types,
including any conversion between strings, different number types and datetime types.
	</para>
			<example>
				<title>Examples:</title>
				<programlisting>
select cast (&apos;2000-1-3&apos; as date);

select cast (cast (&apos;2000-1-3&apos; as date) as varchar);
	= 2000-01-03 00-00-00 000000
</programlisting>
			</example>
		</sect2>
    <sect2 id="sqldatemanus"><title>Time &amp; Date Manipulation</title>
    <para>The SQL92 standard functions for time and date queries are available.
    These are mapped to Virtuoso internal functions as follows:</para>
    <simplelist>
      <member><emphasis>CURRENT_DATE</emphasis> - <link linkend="fn_curdate"><function>curdate()</function></link></member>
      <member><emphasis>CURRENT_TIME</emphasis> - <link linkend="fn_curdate"><function>curtime()</function></link></member>
      <member><emphasis>CURRENT_TIMESTAMP</emphasis> - <link linkend="fn_curdate"><function>curdatetime()</function></link></member>
    </simplelist>
    <para>The results of the above functions can also be obtained using the
    <link linkend="fn_now"><function>now()</function></link> function and
    casting to the appropriate target type.</para>
    <para>Dates and times should be input or compared as literals in a standard
    format.  The following table describes the proper methods available:</para>

      <table><title>Time &amp; date syntax</title>
        <tgroup cols="2">
	      <thead><row>
          <entry>Datatype</entry>
          <entry>ODBC Syntax</entry>
          <entry>SQL92 Casting</entry>
        </row></thead>
	      <tbody>
          <row>
            <entry>Date</entry>
            <entry>{d 'yyyy-mm-dd'}</entry>
            <entry>cast('yyyy-mm-dd' as date)</entry>
          </row>
          <row>
            <entry>Time</entry>
            <entry>{t 'hh:mm:ss'}</entry>
            <entry>cast('hh:mm:ss' as time)</entry>
          </row>
          <row>
            <entry>Datetime/timestamp</entry>
            <entry>{ts 'yyyy-mm-dd hh:mm:ss[.f...]'}</entry>
            <entry>cast('yyyy-mm-dd hh:mm:ss[.f...]' as datetime)</entry>
          </row>
        </tbody>
        </tgroup></table>

    <example id="ex_comparingdates"><title>Example: comparing dates</title>
    <programlisting>
select datecol from table
  where datecol &gt; cast('1900-01-01' as date)
    and datecol &lt; cast(now() as date);
</programlisting>
    <para>now() is cast for explicit compatibility although not required.</para>
    </example>
    </sect2>
		<sect2 id="deccolexp">
			<title>Declaring Collations of Expressions</title>
			<para>
A collation can be declared with CAST for string expressions.  Suppose
insensitive_ascii were a collation name specifying case insensitive comparison
of ASCII strings, the predicate:
	</para>
			<programlisting>
CAST &apos;foo&apos; as varchar collate insensitive_ascii) = CAST &apos;FOO as varchar collate insensitive_ascii)
</programlisting>
			<para>
would be true.
	</para>
			<para>
This will alter the semantic of string comparison and can be used
to define a collation where the collation would otherwise be default,
for instance when comparing results of expressions or constants.  This can
also alter the default collation implied by the collation declaration in
column options in CREATE TABLE.
	</para>
		</sect2>
	</sect1>

  &udt;

<sect1 id="sqlrefxmldatatype"><title>XML Column Type</title>

  <para>Virtuoso allows for native XML storage in a database table column using
  the <computeroutput>LONG XML</computeroutput> type.  This data type is
  a variation of <computeroutput>LONG VARCHAR</computeroutput> that can have
  plain text or XML entities, persistent or non-persistent values, but will always
  return an XML entity when selected.  </para>

  <para>Since ODBC does not support an XML entity type this column will appear
  as a LONG VARCHAR when selected from ODBC based clients.</para>

  <example id="ex_xmlcolumntype"><title>Using LONG XML Columns</title>

  <programlisting><![CDATA[
CREATE TABLE xml_col_test (
  id INTEGER,
  txt VARCHAR,
  xmltxt LONG XML
  )
  ;

  INSERT INTO xml_col_test (id, txt, xmltxt)
    VALUES (1, 'test', '<xml><test>test</test><test>test2</test></xml>');

  INSERT INTO xml_col_test (id, txt, xmltxt)
    VALUES (2, 'test', xml_tree_doc('<xml><test>test</test><test>test2</test></xml>'));

  select * from xml_col_test;
id          txt               xmltxt
INTEGER     VARCHAR           LONG VARCHAR
____________________________________________________________________________

1           test              <xml><test>test</test><test>test2</test></xml>
2           test              <xml><test>test</test><test>test2</test></xml>
]]></programlisting>
</example>

  <tip><title>See Also:</title>
    <para>The <link linkend="fn_xml_tree_doc"><function>xml_tree_doc()</function></link>
	also returns an XML entity and describes other functions that work with it.</para></tip>

</sect1>

	<!-- ======================================== -->
<sect1 id="catidentifiers"><title>Identifier Case &amp; Quoting</title>

  <para>Virtuoso can operate with different identifier case conventions.
The CaseMode setting in the virtuoso.ini file controls this, see the
<link linkend="VIRTINI">virtuoso.ini configuration</link> section of
the documentation.</para>
  <para>The default files supplied with Virtuoso specify a CaseMode of 2,
which is a case insensitive mode that preserves the declaration case of identifiers.
</para>
			<para>
A CaseMode of 1 specifies the upper case mode, which is most
commonly used in SQL databases, e.g. Oracle.
In the upper case mode, all unquoted identifiers are converted to upper
case by the SQL parser. If identifiers are not quoted, the case in which
they are entered is irrelevant.
</para>
			<para>
The identifier quote character is the double quote (&quot;).  Quoted
identifiers are processed in the case they are written in and are thus
case sensitive.
</para>
			<para>
SQL reserved words are case insensitive in all case modes.
</para>
			<para>
If CaseMode is 0 or absent, identifiers will be treated as case sensitive
in all situations, whether quoted or not.
</para>
			<para>
If an identifier&apos;s name is equal to a SQL reserved word, e.g. TABLE,
it must be quoted (&quot;TABLE&quot;) in order to be used as an identifier.
</para>
			<para>
If an identifier contains non-alphanumeric characters, e.g. space, &apos;-&apos; etc. it
must be quoted regardless of CaseMode.
</para>
			<para>
Although CaseMode can be changed at any time it should only be set at database
creation.  Changing the CaseMode may result in view or procedure code becoming invalid
if it relies on specific case conventions.
</para>
		</sect1>

<sect1 id="wideidentifiers"><title>Wide Character Identifiers</title>

<para>All Virtuoso schema columns are confined to 8-bit character fields.  This will
remain for backwards compatibility and performance reasons, however, there
are two options available for support of non-ASCII identifier names as follows:</para>

<itemizedlist>
  <listitem><para>Maintain an 8-bit system.  Pass all 8-bit codes that enter the
  system and read them back according to the current database character set.
  This has the convenience of a 1-to-1 correspondence between the character
  lengths of an identifier and their representation, so it's a subject to
  like single character wildcards etc.</para>
  <para>This works well only for languages that do have single bit encodings
  (like western-european languages and cyrillic).  But this does not work at
  all for the far-east languages.  It also depends on the database character
  set and does not allow identifiers to be composed from multiple character
  sets.</para></listitem>

  <listitem><para>Store all identifiers as UTF-8 encoded unicode strings.  This
  would allow seamless storage and retrieval of ANY character within the unicode
  character space.  This, however, has the disadvantage of the varying character
  length representation which should be taken into account when comparing identifier
  names with LIKE.</para></listitem>
</itemizedlist>

<para>Virtuoso supports the above cases which are switchable through the
"SQL_UTF8_EXECS" = 1/0 flag in the [Client] section of the Virtuoso INI file.
Setting SQL_UTF8_EXECS = 1 enables UTF-8 identifier storage and retrieval,
whereas setting SQL_UTF8_EXECS = 0 disables it.  The default setting is 0: disabled
for backwards compatible option.</para>

<note><title>Note:</title>
<para>Once a non-ASCII identifier gets stored using a particular setting for
the "SQL_UTF8_EXECS" flag and the flag is subsequently changed this will
make the stored identifiers unreadable by normal means (but can be read
by special means).</para></note>

<para>When an SQL statement comes into the driver(s) it is expanded into unicode (using
either the current database character set if it is a narrow string like in
SQLExecDirect, or taking it verbatim as in SQLExecDirectW).  The unicode
string is then encoded into UTF-8 passed to the SQL parser.  The SQL parser knows
that it will receive UTF-8 so it takes that into account when parsing the
national character literals (N'&lt;literal&gt;') and the "normal" literals ('&lt;literal&gt;').
It will however return identifier names in UTF-8, these will then get stored into
the DBMS system tables or compared against them depending on the type of statement.</para>

<para>All returned identifiers will be translated from UTF-8 to Unicode when
returned to the client, so the client should never actually see the
UTF-8 encoding of the identifiers.</para>

<para>Representing a string in UTF-8 will not change the identifier parsing rules
or the SQL applications logic since the SQL special characters - like dot,
quote, space etc - are ASCII symbols and they will get represented as a
single byte sequence in UTF-8.</para>

<para>The upper/lower functions should be used with care when applied to identifiers:
they will get narrow strings in UTF-8, so applying an upper/lower to them may
cause damage to the UTF-8 encoding.  That is why the identifiers should be
converted explicitly to wide strings using the charset_recode function,
changed to upper or lower case and then translated back to UTF-8 using the
charset_recode function again.</para>

<para>Using single character LIKE
patterns against identifiers stored as narrow strings in system tables will generally not work, as a single character
may be represented with up to 6 bytes in UTF-8.  An exception to that is when
using single character pattern to match an ASCII character.</para>

<sect2 id="utf8notes4odbc"><title>UTF-8 Implementation Notes For ODBC</title>

<para>All wide functions which do return an identifier, like SQLDescribeColW and
friends, will return the correct wide literal.  For their narrow counterparts,
such as SQLDescribeCol, the UTF-8 string will first be converted to a wide
string and then to a narrow string using the current database character set.
However, an extension to the ODBC standard has been implemented instructing
all result set returning meta-data functions, such as SQLTables and SQLTablesW,
to return SQL_NVARCHAR instead of SQL_VARCHAR columns.  This is not a problem
for most applications since all they do is to map the result to
SQL_C_CHAR on retrieval which will convert the wide string to the appropriate
narrow string inside the driver using the current database character set.
This will cause problems with narrow applications like MS Query, trying to get
identifiers not representable in the current narrow character set, because
all they will get is the "untranslatable char" mark (currently a question mark).</para>
</sect2>

<sect2 id="utf8notes4jdbc"><title>UTF-8 Implementation Notes In JDBC</title>

<para>Since JAVA is all unicode there are no unavoidable deviations from the JDBC
standard.  However when printing the Java strings to the screen or a file
or getting their byte representation, the usual JAVA conversion rules apply.
The types of the meta data result set columns in JDBC are somewhat debatable,
but since they are usually retrieved with Resultset.getString() the Virtuoso
JDBC driver will return the raw wide string instead of trying to make it
VARCHAR before returning it to the application.</para>
</sect2>
</sect1>

	<!-- ======================================== -->
	<sect1 id="QUALIFIEDNAMES">
		<title>Qualified Names</title>
		<sect2 id="qual_owners">
			<title>Qualifiers and Owners</title>
			<para>
Virtuoso supports multiple namespaces for tables and procedures.  A table
or procedure is uniquely identified by a three part name consisting of
qualifier, owner and name separated by dots.
</para>
			<para>
Each connection has a current qualifier which is used as the default
qualifier for if a name does not specify a qualifier.  The owner can
be omitted from a name if the qualifier and name uniquely identify the
object, e.g.  DB..SYS_KEYS.
</para>
			<para>
Initially, all system objects have the qualifier DB and owner DBA.
</para>
			<para>
The default current qualifier of all connections is DB unless otherwise
specified using db.dba.user_set_qualifier.
</para>
			<para>
A user can be assigned a default qualifier set as current qualifier upon
login.  This is done with the stored procedure db.dba.user_set_qualifier.
</para>
			<screen>
user_set_qualifier  (in user varchar, in qualifier varchar)
</screen>
		</sect2>
		<sect2 id="defaultqualifiers">
			<title>Default Qualifiers</title>
			<para>
The default qualifier of the user is set to be the qualifier.  The names
are strings and thus case sensitive.
</para>
			<para>Example:</para>
			<programlisting>
db..user_set_qualifier (&apos;U1&apos;, &apos;U1DATA&apos;);
</programlisting>
		</sect2>
		<sect2 id="userstmtid">
			<title>USE Statement, USE identifier</title>
			<para>
This sets the default qualifier for the connection in question.  The
identifier cannot be an expression. The identifier
is subject to whatever case conversions may be in effect.
</para>
			<tip>
				<title>See Also:</title>
				<para><link linkend="catidentifiers">CaseMode Configuration parameter</link>.</para>
			</tip>
			<para>
A quoted identifier will always pass in the
case it is entered. An unquoted identifier will be converted to upper
case if CaseMode so specifies.
</para>
		</sect2>
	</sect1>

		<sect1 id="litsbraceescs">
			<title>Literals, Brace Escapes</title>
			<sect2 id="strings">
				<title>Strings</title>
				<para>
String literals are delimited with single quotes.  A double single
quote is an escape notation for a single quote character inside a
string literal.  Additionally, standard C language escapes are supported.
Support of C escapes can be turned off for compatibility with other SQL databases
by using the SQL_NO_CHAR_C_ESCAPE option in the configuration file or as an
ODBC connection option.
</para>
				<screen>
Literal			meaning
&apos;&apos;			&lt;empty&gt;
&apos;&apos;&apos;&apos;			&apos;
&apos;&apos;&apos;&apos;&apos;&apos;			&apos;&apos;
&apos;\t\r\n\\&apos;		tab, carriage return, newline, backslash
&apos;\012&apos;			Character 012 octal, i.e. newline
</screen>
			</sect2>
			<sect2 id="numbers">
				<title>Numbers</title>
				<para>
An integer constant consist of an optional minus sign followed by
decimal digits.  Integer literals are of the C type long, 32 bit.
</para>
				<para>
Numeric literals with a decimal point literal are internally of the DECIMAL SQL type, a variable
length decimal floating point type.
The Following are examples of decimal literals:
</para>
				<screen>
123.456
-16.0
</screen>
				<para>
Numeric literals which specify an exponent, e.g. 1.2e11 or
2e-3 are read as C doubles, (64 bit IEEE binary floating point). This
is potentially less precise than the DECIMAL SQL type.
</para>
				<para>
Integer literals outside of the 32-bit range are interpreted as DECIMAL.
</para>
			</sect2>
			<sect2 id="odbcbraceesc">
				<title>ODBC Brace Escapes</title>
				<para>
The Virtuoso SQL parser supports the following ODBC brace escape notations:
</para>
				<screen>
{fn function (argument, ..) }		fm (arguments .)
call procedure a1, ... }

{d &apos;yyyy.mm.dd&apos;}

{t &apos;hh:mm.ss&apos; }

{ts &apos;yyyy.mm.dd hh:mm.s fraction&apos; }

{oj  }		-- outer join
</screen>
			</sect2>

  <sect2 id="sqlrefhexliterals"><title>Hexadecimal Literals</title>

   <para>Hexadecimal values can be specified literally in two ways, prefixing the
   plain value with '0x' or enclosed with single quotes prefixed with 'X'.  The
   case is not important.  Hex characters should always be pairs, representing
   a single byte, and should be at least on pair.  Here are some examples:</para>

<programlisting>
X'beef'   - valid
0xbeef    - valid

X'abeef'  - not valid
X'0abeef' - valid
X''   - not valid
</programlisting>

<para><computeroutput>X'&lt;value&gt;'</computeroutput> is equivalent
to <computeroutput>0x&lt;value&gt;</computeroutput></para>

  </sect2>

  <sect2 id="sqlrefbinliterals"><title>Binary Literals</title>

  <para>Binary strings can be specified as literals prefixed with 'B' and
  enclosed with single quotes.  The string should not be empty and should
  contain only 1's or 0's.  Binary strings are read from the end to beginning
  forming bytes on each 8-th bit:</para>

<programlisting>
B'1'    = 0x01
B'1111'   = 0x0F
B'111111111'  = 0x01FF
B'100000001'  = 0x0101
B'', X'' and 0x return binary literals.
</programlisting>

  </sect2>

    </sect1>


	<sect1 id="CREATETABLE">
		<title>CREATE TABLE Statement</title>
		<sect2 id="syntax">
			<title>Syntax</title>
<programlisting><![CDATA[
    base_table_def: CREATE TABLE new_table_name '(' base_table_element_commalist ')'
                  | CREATE TABLE new_table_name as query_exp opt_with_data

base_table_element_commalist: base_table_element
                           | base_table_element_commalist ',' base_table_element

base_table_element: column_def
                  | table_constraint_def

column_def: column column_data_type column_def_opt_list

opt_referential_triggered_action: /* empty */
                                | referential_rule
                                | referential_rule referential_rule

referential_rule: ON UPDATE referential_action
                | delete_referential_rule

delete_referential_rule: ON DELETE_L referential_action

opt_on_delete_referential_rule: /* empty */
                              | delete_referential_rule

referential_action: CASCADE
                  | SET NULLX
                  | SET DEFAULT

references: REFERENCES q_table_name opt_column_commalist opt_referential_triggered_action

column_def_opt_list: /* empty */
                   | column_def_opt_list column_def_opt

identity_opt: START_L WITH signed_literal
            | INCREMENT_L BY INTNUM

identity_opt_list: identity_opt
                 | identity_opt_list ',' identity_opt

column_def_opt: NOT NULLX
              | NULLX
              | IDENTITY
              | IDENTITY '(' identity_opt_list ')'
              | PRIMARY KEY
              | DEFAULT signed_literal
              | COLLATE q_table_name
              | references
              | IDENTIFIED BY column
              | CHECK '(' search_condition ')'
	      | WITH SCHEMA column_xml_schema_def
              | UNIQUE

table_constraint_def: UNDER q_table_name
                    | opt_constraint_name PRIMARY KEY '(' index_column_commalist ')' opt_index_option_list
                    | opt_constraint_name FOREIGN KEY '(' column_commalist ')' references
                    | opt_constraint_name CHECK '(' search_condition ')'
                    | opt_constraint_name UNIQUE '(' column_commalist ')'

opt_constraint_name: /* empty */
                   | CONSTRAINT identifier

column_commalist: column
                | column_commalist ',' column

index_column_commalist: column opt_asc_desc
                      | index_column_commalist ',' column opt_asc_desc

index_option: CLUSTERED
            | UNIQUE
            | OBJECT_ID

index_option_list: index_option
                 | index_option_list index_option

opt_index_option_list: /* empty */
                     | index_option_list

column_xml_schema_def
	: '(' STRING ',' STRING ')'
	| '(' STRING ',' STRING ',' STRING ')'

opt_with_data
: /* empty */
| WITH DATA
| WITHOUT DATA

]]></programlisting>

<para>The CREATE TABLE statement creates a new table.  The table is identified by a
new_table_name, which consists of an optional qualifier, an optional owner and
the name.  If the qualifier is not supplied then it defaults to the current qualifier,
and likewise if the table owner is not specified then this will default to the login
name of the user issuing the statement.</para>
			<para>
Following the new_table_name is a list of table elements that are either column
definitions or table constraints.  A column must have a unique name within the table
and possible super tables.  The only necessary attribute of a column is a data type.
</para>
<para>The UNDER q_table_name constraint specifies an optional supertable. The
table being created will inherit all columns, indices, constraints from the
supertable, specifically including the primary key. Hence the under and primary
key constraints cannot be specified together.  If the table being created will be
owned by a non-dba user, the supertable must be owned by the same user.</para>

<para>The AS query_exp opt_with_data causes the table to be created based on the
    compile time types of columns of the SELECT expression query_exp. If WITH DATA
    is specified then the resultset returned by the query_exp is fed into the new
    table. Otherwise (if WITHOUT DATA or not specified) only the table is created.</para>
</sect2>

  <sect2 id="consnotnull"><title>NOT NULL</title>
  <para>Optionally a column can be declared NOT NULL.  Any attempts to
  insert NULL into column declared NOT NULL will result in an error and the
  insert rejected.</para>
	</sect2>
	<sect2 id="identity"><title>IDENTITY (Auto Increment)</title>
	<para>The IDENTITY keyword causes the columns to be automatically incremental,
  meaning that each successive insert into the table will automatically assign
  a value greater than any previous row of the table.  These columns are
  often referred to as "autoincrement columns".  The assigned values
  are normally consecutive integers.  There may be gaps in the sequence if some
  transactions that reserve a number fail to commit.  </para>
  <para>An autoincrement column may or may not be part of the primary key or
  of any index.</para>
  <para>The <link linkend="fn_identity_value"><function>identity_value()</function></link>
  function returns the identity column value most recently assigned on the current connection.  This can be used inside procedures or from clients.  See also the ODBC statement option SQL_GETLASTSERIAL.</para>
  <para>The <link linkend="fn_set_identity_column"><function>set_identity_column()</function></link>
  function allows you to change the identity column sequence value.</para>
  <para>The IDENTITY keyword supports the SQL 3 optional clause that allows
      you to specify a starting value and/or step value in the table creation statement.  The syntax is:</para>

  <programlisting><![CDATA[
      IDENTITY (START WITH <N>, INCREMENT BY <Y>)
]]></programlisting>

<example id="ex_identity"><title>Using the IDENTITY declaration</title>
<programlisting>
CREATE TABLE DB.DBA.AI (
	AI INTEGER IDENTITY,
	XX VARCHAR,
	PRIMARY KEY (AI)
  )
;</programlisting>
  <para>Creates a table with an autoincrement primary key column AI.</para>
<programlisting>
set_identity_column("DB"."DBA"."AI", "AI", 11);</programlisting>
  <para>will cause the next row to be inserted into AI to have the AI column
  equal to 11.</para>
</example>

<example id="ex_identity"><title>Using the IDENTITY (START WITH) declaration</title>
<programlisting>
CREATE TABLE DB.DBA.AI (
	AI INTEGER IDENTITY (START WITH 100),
	XX VARCHAR,
	PRIMARY KEY (AI)
  )
;</programlisting>
  <para>Creates a table with an autoincrement primary key column AI, whose
  first value will be 100 and will auto-increment from there upwards.</para>
</example>

<tip><title>See Also</title>
<para><link linkend="sequenceobjects">Sequence Objects</link></para>
</tip>

  </sect2>
			<sect2 id="default">
				<title>DEFAULT</title>
				<para>
This option specifies a constant default value given to the column by an INSERT
that does not specify a value for the column.  The constant must be compatible
with the column&apos;s data type.  An IDENTITY or TIMESTAMP column cannot have
a default value.
</para>
			</sect2>
		<sect2 id="pkeycons"><title>PRIMARY KEY Constraint</title>
    <para>This declares a column combination that will uniquely identify each
    row in the table.  This automatically defines an index on these columns
    and clusters the physical rows of the table together with the index entry
    for this primary key index.  Always specify a primary key if there is a
    uniquely identifying column combination on the table. This is the case for
    any normalized database.  Hence virtually all tables should have the primary
    key constraint.  This is substantially more efficient than defining the
    primary key as a unique index with CREATE INDEX.   The primary key constraint
    exists for the purpose of guaranteeing uniqueness of a row and hence should
    be respected.  A unique index is not a primary key and should never
    substitute one.</para>

<example id="ex_pkeyfullconstraint"><title>Primary Key using Constraint</title>
  <para>This example shows how to create a table with a primary key defined in
  full as a named primary key table constraint</para>
  <programlisting>
CREATE TABLE demo_table (
  id INTEGER NOT NULL,
  txtdata VARCHAR(20),
  CONSTRAINT demo_table_pk PRIMARY KEY (id)
  )
;</programlisting>
</example>

    <para>PRIMARY KEY is a shorthand for the PRIMARY KEY (column)
    table constraint which is specified in the column definition.  SQL-89 required
    that you specify NOT NULL PRIMARY KEY but SQL-92 does not because primary
    keys columns do not permit NULL values.  This means that no members of a
    combination of columns that constitute a primary key can have a NULL value.</para>

<example id="ex_pkeyshort"><title>Primary Key shorthand</title>
  <para>This example shows how to create a table with a primary key defined
  using shorthand:</para>
  <programlisting>
CREATE TABLE demo_table (
  id INTEGER NOT NULL PRIMARY KEY,
  txtdata VARCHAR(20),
  )
;</programlisting>
  <para>Or shorter still:</para>
  <programlisting>
CREATE TABLE demo_table (
  id INTEGER PRIMARY KEY,
  txtdata VARCHAR(20),
  )
;</programlisting>
</example>

    <para>If a table definition has no PRIMARY KEY clause, Virtuoso will generate
    a default primary key column called "_IDN".  <important>Always declare a primary key using
    the primary key table constraint.  This is always more efficient than the
    default primary key.</important>  You could allow Virtuoso to generate the
    primary key if you simply want an IDENTITY primary key column, however this
    is considered lazy and, of course, not portable.  If you already have a
    column or combination of columns that could be a candidate for a primary
    key, taking the default primary key from Virtuoso will reduce the overall
    efficiency because an extra column will be used per row that would be
    redundant to the data itself.</para>

<example id="ex_pkeydefault"><title>Default Virtuoso Primary Key</title>
  <para>In the absence of a PRIMARY KEY definition:</para>
  <programlisting>
CREATE TABLE SAMPLE (
  THING VARCHAR
  )
;</programlisting>
  <para>will be expanded into:</para>
  <programlisting>
CREATE TABLE SAMPLE (
  THING VARCHAR,
  _IDN INTEGER IDENTITY,
	PRIMARY KEY (_IDN)
  )
;</programlisting>
</example>

  <para>Tables with generated default primary keys will appear as if they have
  no primary key defined.  The default primary key (_IDN) column will not appear
  in the ODBC catalog calls <function>SQLColumns()</function>,
  <function>SQLStatistics()</function>, <function>SQLPrimaryKeys()</function>,
  <function>SQLColumnPrivileges()</function>.  The column can be explicitly
  referenced in SQL statements just as any other.  The SQL "SELECT * ..."
  statement will omit the _IDN column.  The "INSERT INTO TABLE VALUES (.)"
  statement does not expect a value for the _IDN column.
  <function>SQLSpecialColumns()</function> with the <parameter>SQL_BEST_ROWID</parameter>
  option is the only catalog call that will return the _IDN column.</para>

  <para>The PRIMARY KEY option may not coexist with UNDER in a CREATE TABLE
  statement because a subtable always inherits the supertable&apos;s primary key.</para>

  <tip><title>See Also:</title>
  <para><link linkend="CREATEINDEX">CREATE INDEX</link> for the index options.</para></tip>

</sect2>

  <sect2 id="under"><title>UNDER</title>
  <para>This allows the user to create a table as a sub-table of an existing table.
  A sub-table will inherit all columns and constraints of its super-table, most
  importantly the primary key.  Primary keys shall be unique in the set of rows
  belonging to any direct or indirect sub-table of one super-table.  A select
  from a super-table will see all rows, including those of any sub-tables, but
  not vice versa.  Rows inserted directly into the super-table will not be
  visible to sub-tables.</para>
  <para>
The primary key option may not coexist with UNDER, since a subtable always
inherits the supertable&apos;s primary key.
</para>

<example id="ex_under"><title>Creating sub-tables using UNDER</title>
  <para>Here a subtable will be created for the demo_table defined earlier.
  Both definitions are listed for convenience.  Notice that the select over
  the sub-table (demo_sub_table) lists all columns whereas the select from
  super-table does not, however rows inserted into the super-table,
  demo_table, will not be seen in a select from the sub-table, but rows
  inserted into the sub-table will be shown in a select from the super-table.</para>
  <programlisting>
CREATE TABLE demo_table (
  id INTEGER PRIMARY KEY,
  txtdata VARCHAR(20),
  )
;

CREATE TABLE demo_sub_table (
  new_col VARCHAR(10),
  UNDER demo_table
  )
;

SQL> select * from demo_table;
id                txtdata
INTEGER NOT NULL  VARCHAR
____________________________________________________________________


0 Rows. -- 20 msec.

SQL> select * from demo_sub_table;
id                txtdata               new_col
INTEGER NOT NULL  VARCHAR               VARCHAR
____________________________________________________________________


0 Rows. -- 10 msec.
</programlisting>
</example>
</sect2>
	<sect2 id="fkeys"><title>FOREIGN KEY Constraint</title>
			<para>A FOREIGN KEY is a column of combination of columns used to retrieve a related
      row from a related table.  These reference constraints are automatically enforced,
      unless explicitly disabled.  This declaration can be accessed by client
      applications using the <function>SQLForeignKeys()</function> ODBC
      function.  This is used by some tools to display dependencies between
      tables.  Foreign keys are there to maintain referential integrity within
      the database.  This constraint will ensure that rows in one table will
      have corresponding rows in another table, so that your orders are not
      made for products that do not exist, for example.</para>
			<para>Forward references are not permitted in FOREIGN KEY.  Also a table
      referenced in a foreign key constraint of another table cannot be dropped.
      It is usual to list the columns in the referenced table corresponding
      to the columns in the referencing table, however, this list can be omitted,
      in which case the set of primary key columns of the referenced table is
      used automatically by default.  The referenced and referencing column
      lists must be of equal length.  To declare two mutually referencing tables,
      ALTER TABLE must be used after both tables are defined. </para>
      <para>Foreign key constraints are enforced by default.  It is sometimes
      practical to disable constraint checks for performance or for convenience
      when importing data or making bulk updates.  To disable or enable checking
      for foreign key constraints you can use the
      <link linkend="fn_fk_check_input_values"><function>fk_check_input_values()</function></link>
      function.  This function changes the foreign key checking behavior globally
      across the database so it is very important to remember to enable foreign key
      constraint checking again afterwards.</para>
      <para>Columns can be defined as having foreign keys and a default value,
      however, the default value must not violate the constraint at the time of
      insert or update as this will be rejected in the normal way.</para>

<example id="ex_fkeysinuse"><title>Creating tables with foreign key constraints</title>
	<para>First the Primary key table must be defined before it can be referenced:</para>
	<programlisting>
CREATE TABLE T1 (
  Id INTEGER NOT NULL PRIMARY KEY,
  Dt VARCHAR
  )
;</programlisting>
	<para>Now the foreign key table can be created referencing the table above:</para>
	<programlisting>
CREATE TABLE T2 (
  Act INTEGER NOT NULL,  -- will refer to Id in T1
  Retr DATETIME,
  Description VARCHAR,
  CONSTRAINT FK1 FOREIGN KEY (Act) REFERENCES T1 (Id) -- the fk constraint
  )
;</programlisting>
  <para>The statement above creates the foreign key constraint in separate line
  of the create table statement.  This can be also be written in short form
  with the column definition it applies to:</para>
  <programlisting>
CREATE TABLE T2 (
  Act INTEGER NOT NULL REFERENCES T1 (Id),  -- refer to Id in T1
  Retr DATETIME,
  Description VARCHAR
  )
;</programlisting>
</example>

<example id="ex_nwdemofk"><title>Assumed Foreign Key Columns</title>
  <para>This CREATE TABLE statement was used for creating part of Demo database.
  This statement does not describe the columns to be used as foreign keys on
  the referred tables.  Since the referred tables in each case have a single
  Primary Key (Orders.OrderID and Products.ProductID) they need not be
  mentioned and will be assumed when this statement is processed.</para>
  <programlisting>
CREATE TABLE Order_Details(
  OrderID INTEGER,
  ProductID INTEGER,
  UnitPrice DOUBLE PRECISION,
  Quantity SMALLINT,
  Discount REAL,
  PRIMARY KEY (OrderID, ProductID),
  FOREIGN KEY (OrderID) REFERENCES Orders,
  FOREIGN KEY (ProductID) REFERENCES Products
  )
;</programlisting>
</example>

    <sect3 id="fkeyactions"><title>Foreign Key Constraint Actions</title>
    <para>Foreign key constraint actions allow the user to define what action
    data should take when the data they are related to by way of a foreign key
    is updated or deleted.  The two activities that can be programmed are:</para>
    <simplelist>
      <member>ON DELETE</member>
      <member>ON UPDATE</member>
    </simplelist>
    <para>The actions available for both types of activity are:</para>
    <simplelist>
      <member>CASCADE - automatically perform the same action on the referenced data.</member>
      <member>SET NULL - set the referenced data to NULL.</member>
      <member>SET DEFAULT - sets the referenced data to whatever was defined as its default value.</member>
      <member>NO ACTION - to not perform any action at all.</member>
    </simplelist>

<example id="fkeyactions"><title>Foreign Key Constraint Actions</title>
  <para>Now, the foreign key table defined again, but this time with referential
  rules which control how data is managed when rows are updated or deleted in
  the primary key table:</para>
  <programlisting>
CREATE TABLE T3 (
  Act INTEGER NOT NULL DEFAULT 99,  -- will refer to Id in T1
  Retr DATETIME,
  Description VARCHAR,
  CONSTRAINT Fk1 FOREIGN KEY (Act) REFERENCES T1 (Id)
    ON UPDATE CASCADE ON DELETE SET DEFAULT
  )
;</programlisting>
</example>

    </sect3>
  </sect2>
  <sect2 id="sqlrefcreattablecheck"><title>The CHECK Constraint</title>
  <para>The CHECK constraint allows you specify and wide range of rules that
  will dictate whether an insert of update will be permitted.  The syntax is as follows:</para>

<programlisting><![CDATA[
CHECK (search-condition)
]]></programlisting>

  <para>The search condition can be simple and comparative, or quite complicated
  involving regular expressions.</para>

<example id="ex_sqlrefcreatecheck"><title>Creating a table with the CHECK constraint</title>
<para>Here a simple table will be created with two CHECK constraints.  One the
check constraints is a simple comparison ensuring participants are over 18, the
other complicated constraint verifies that the email address is correct using a
regular expression.  Samples SQL statements follow that will demonstrate the
effectiveness of the check constraints.</para>
<programlisting><![CDATA[
CREATE TABLE test_check (
  name VARCHAR,
  age INTEGER
    CHECK (age > 18),
  email VARCHAR
    CHECK (regexp_like(email, '^([a-zA-Z0-9_.-])+@(([a-zA-Z0-9-])+.)+([a-zA-Z0-9]{2,4})+\$'))
  )
  ;

INSERT INTO test_check (name, age, email) VALUES ('Jack', 18, 'jack@foo.bar');
  -- will cause: *** Error 22023: ... SR363: CHECK constraint violated

INSERT INTO test_check (name, age, email) VALUES ('Jill', 19, 'up@thehill.com');
  -- will be insert correctly.

INSERT INTO test_check (name, age, email) VALUES ('Jack and Jill', 37, 'ouch/!^^!!@@');
  -- will cause: *** Error 22023: ... SR363: CHECK constraint violated, also.
]]></programlisting>
</example>

<tip><title>See Also:</title>
  <para><link linkend="fn_regexp_like"><function>regexp_like()</function></link></para></tip>
  </sect2>
  <sect2 id="sqlrefcreattablewithschema"><title>The WITH SCHEMA Constraint</title>
  <para>The WITH SCHEMA constraint allows you force values of an XML column to match a
particular schema. The syntax is as follows:</para>
<programlisting><![CDATA[
WITH SCHEMA (namespace-uri, top-element-name [, optional-dtd-configuration])
]]></programlisting>
  <para>To use this feature, you should make load an XMLSchema to the server by a
<link linkend="CREATEXMLSCHEMA">CREATE XML SCHEMA</link> statement.
As soon as schema is loaded, its target namespace URI can be used in WITH SCHEMA
constraint to validate every new value of the column against this schema.
In addition, the constraint ensures that the document is a well-formed XML document
(not a well-formed generic XML entity) and checks if the name of the top level element
of the document is equal to one specified in the constraint.
</para>
<para>Depending on document size
and the complexity of the schema, schema validation may be a time- and memory- consuming
operation. An application can win a lot if every stored value is validated only once
and avoid repeating validations on every read of the stored data, but it also may loose
if the  validation is actually redundant (e.g. if the data  always comes from sources which produce valid content).
</para>
<para>
The parameter &quot;optional-dtd-configuration&quot; lets an application to specify
how strict the validation should be. In real life, documents may match the schema in general,
but not in minor details that are not important for a particular application.
If specified, the parameter must be a string in the format described in
<link linkend="dtd_config">Configuration Options of the DTD Validator</link>.
The default value is suitable for most of applications and forces the validator to
check well-formedness of the document, nesting of elements, presence of
all &quot;required&quot; attributes, syntax of values of typed elements and attributes;
it also will check referential integrity of ID and IDREF attributes.
</para>

<example id="ex_sqlrefcreattablewithschema"><title>Creating a table with the WITH SCHEMA constraint</title>
<para>Here a simple table will be created with a WITH SCHEMA constraint.
Sample SQL statements follow that will demonstrate the
effectiveness of the check constraints.</para>
<programlisting><![CDATA[
CREATE XML SCHEMA '<?xml version="1.0" encoding="utf-8" ?>
<xs:schema targetNamespace="http://www.example.com/parts"
  xmlns:xs="http://www.w3.org/2001/XMLSchema"
  xmlns:p="http://www.example.com/parts">
   <xs:element name="Part">
      <xs:complexType>
         <xs:choice minOccurs="0" maxOccurs="unbounded">
	   <xs:element ref="p:Part"/>
	 </xs:choice>
         <xs:attribute name="ID" type="xs:string" use="required" />
         <xs:attribute name="Count" type="xs:int" use="optional" />
         <xs:attribute name="Type" type="xs:string" use="optional" />
      </xs:complexType>
   </xs:element>
</xs:schema>';

create table SPARE_PARTS (
  PACK_ID integer primary key,
  CONTENT XMLType with schema ('http://www.example.com/parts', 'Part')
  );

insert into SPARE_PARTS values (1, '
<p:Part xmlns:p="http://www.example.com/parts" ID="keyboard">
  <p:Part Count="101"/>
  <p:Part ID="body"/>
</p:Part>')

*** Error 42000: [Virtuoso Driver][Virtuoso Server]XML parser detected an error:
	ERROR  : Only 0 out of 1 required attributes are defined for element <p:Part>, e.g. the element has no attribute 'ID'
at line 3 column 25 of '(value to be placed in column DB.DBA.SPARE_PARTS of CONTENT)'
  <p:Part Count="101"/>
-----------------------^

insert into SPARE_PARTS values (2, '
<p:Part xmlns:p="http://www.example.com/parts" ID="keyboard">
  <p:Part ID="key" Count="101"/>
  <p:Part ID="body"/>
</p:Part>')

select * from SPARE_PARTS
PACK_ID           CONTENT
INTEGER NOT NULL  LONG VARCHAR
_______________________________________________________________________________

2
<n0:Part xmlns:n0="http://www.example.com/parts" ID="keyboard">
  <n0:Part ID="key" Count="101" />
  <n0:Part ID="body" />
</n0:Part>

1 Rows. -- 00000 msec.
]]></programlisting>
</example>

<para>ALTER TABLE ... MODIFY COLUMN statement does not support changes of WITH SCHEMA constraint.
Double check your XMLSchema and carefully test it on real data used by an application before
using this constraint. If you can't test your schema this way then calling of
<link linkend="fn_xml_validate_schema"><function>xml_validate_schema()</function></link>
in triggers may be safer than using the constraint: such triggers will be slower than
the constraint but you can drop triggers without re-creating the table.
</para>

<tip><title>See Also:</title>
  <para><link linkend="CREATEXMLSCHEMA">CREATE XML SCHEMA Statement</link></para>
  <para><link linkend="fn_xml_validate_schema"><function>xml_validate_schema()</function></link></para>
</tip>
  </sect2>
	</sect1>

  <sect1 id="DROPTABLE">
		<title>DROP TABLE Statement</title>
		<programlisting>
drop_table
	: DROP TABLE q_table_name
	;
</programlisting>
		<para>
This statement drops a table. This requires dba privileges or ownership of the
table.  Any subtables are automatically dropped.  Supertables are not affected.
</para>
	</sect1>
	<sect1 id="CREATEINDEX"><title>CREATE INDEX Statement</title>

	<programlisting>
index_column_commalist
	: column opt_asc_desc
	| index_column_commalist ',' column opt_asc_desc
	;

index_option
	: CLUSTERED
	| UNIQUE
	;

index_option_list
	: index_option
	| index_option_list index_option
	;

opt_index_option_list
	: /* empty */
	| index_option_list
	;

create_index_def
	: CREATE opt_index_option_list INDEX index
		ON new_table_name '(' index_column_commalist ')'
	;
</programlisting>

	<para>This creates an index on a table.  Index names must be unique across a
  qualifier.  The ascending / descending column attributes are recognized for
  compatibility but do not have any effect.  The index is defined and populated
  at the execution of the statement.  Pre-existing stored procedures and
  prepared statements will make use of the new index when appropriate.</para>
	<para>The UNIQUE attribute enforces uniqueness of the specified columns
  across the table and subtables where the index is visible.</para>
	<para>The CLUSTERED attribute is not recommended.  It will cause keys to be
  unprefixed by key id, thus causing the key entries to be intermixed with
  entries of other CLUSTERED indices with adjacent values of key parts.</para>

<tip><title>See:</title>
<para>See the <link linkend="freetext">Free Text</link> section on creating free text indices.</para>
</tip>
</sect1>

	<sect1 id="DROPINDEX">
		<title>DROP INDEX Statement</title>

		<programlisting>
drop_index
	: DROP INDEX NAME opt_table
	;

opt_table
	: /* empty */
	| q_table_name
	;
</programlisting>
  <para>This will drop an index, dba privileges or table ownership are required.
  A table&apos;s primary key which has the same name as the table can not be dropped.</para>
  <para>Optionally, a table name can be given if the index name is not unique.
  The table name may be qualified.</para>
</sect1>
	<sect1 id="ALTERTABLE"><title>ALTER TABLE Statement</title>

		<programlisting><![CDATA[
add_column:
            ALTER TABLE q_table_name ADD opt_col_add_column add_col_column_def_list
          | ALTER TABLE q_table_name DROP opt_col_add_column add_col_column_list
          | ALTER TABLE q_table_name MODIFY opt_col_add_column column_def

add_col_column_def_list: column_def
                       | add_col_column_def_list &apos;,&apos; column_def

add_col_column_list: column
                   | add_col_column_list &apos;,&apos; column

table_rename:
            ALTER TABLE q_table_name RENAME new_table_name

alter_constraint:
            ALTER TABLE q_table_name constraint_op opt_table_constraint_def

constraint_op: ADD
             | DROP
             | MODIFY

opt_drop_behavior: /* empty */
                 | CASCADE
                 | RESTRICT

opt_table_constraint_def: CONSTRAINT identifier opt_drop_behavior
                        | table_constraint_def

view_query_spec: query_exp
               | query_no_from_spec

alter_table
	: ALTER TABLE q_table_name ADD opt_col_add_column add_col_column_def_list

	| ALTER TABLE q_table_name DROP opt_col_add_column add_col_column_list

	| ALTER TABLE q_table_name MODIFY opt_col_add_column column_def

	| ALTER TABLE q_table_name RENAME new_table_name

	| ALTER TABLE <table> ADD | DROP | MODIFY <constraint> [<constraint-name>]

<constraint> ::=
	: PRIMARY KEY '(' <column list> ')'
	| FOREIGN KEY '(' <column list> ')' <references>
	| CHECK ( search-condition )

<references> ::=
   REFERENCES <table> ['(' <column list> ')' ] <OPTIONS>

<OPTIONS>  ::=
   [ON UPDATE OPT_ACTION] [ON DELETE OPT_ACTION]
]]></programlisting>
  <para>The ALTER TABLE statement adds or drops columns and renames tables.</para>
  <para>Adding or dropping a column of a table will create a new version of the
  table&apos;s schema entry.  The rows of the altered table will be changed to
  conform to the new definition when next updated.  All newly inserted rows
  will be in the new row layout.  This means that ALTER TABLE itself executes in
  fixed time without locking the table.  The time to update the actual data
  will be spread over subsequent updates.</para>
  <para>An added column will have a NULL value on those rows where the
  new column has not been set.  A possible default will only apply to newly
  inserted rows.</para>
  <para>When dropping a column one can execute a statement of the form UPDATE
  &lt;table&gt; SET &lt;key&gt; = &lt;key&gt; to force the physical change,
  causing space associated with the dropped column to be freed.</para>
  <para>The column_def in the ADD clause may specify any column options, except
  PRIMARY KEY.</para>
  <para>If the table name is not fully qualified it is completed as in any table
  reference.  The new name in the RENAME clause is defaulted to the current
  qualifier and user account, as in a CREATE TABLE.</para>
  <para>A primary key may only be modified, never dropped or added.  Tables
  always have exactly one primary key.</para>
  <para>The first unique index of an empty table becomes the primary key. This
  may thereafter not be dropped.</para>
  <para>The primary key of an attached table may not be changed.</para>
  <para>Foreign keys can be added.  Dropping a foreign key will drop all
  foreign keys between the foreign key and primary key tables.</para>
  <para>ALTER TABLE cannot be applied to an attached table.</para>
		<example id="ex_altertable"><title>ALTER TABLE Examples</title>
			<programlisting>
ALTER TABLE DISTRICT
    add D_SALES_MGR integer not null references EMPLOYEES (E_ID);

ALTER TABLE idt MODIFY PRIMARY KEY (K1, K2);

ALTER TABLE idt ADD FOREIGN KEY (d) REFERENCES idt (d);

ALTER TABLE idt ADD FOREIGN KEY (k2, k1) REFERENCES idt;

ALTER TABLE idt DROP FOREIGN KEY (d) REFERENCES idt (d);
</programlisting>
		</example>

  <sect2 id="sqlrefalttabcheck"><title>Adding a CHECK Constraint</title>

  <para>A CHECK constraint can be added to a table after it has been created
  and populated providing that none of the tables contents would violate the constraint.</para>

  <example id="ex_alttabcheck"><title>Adding a CHECK constraint to an existing table.</title>
<programlisting><![CDATA[
CREATE TABLE test_add_check (
  name VARCHAR,
  age INTEGER
  )
;

ALTER TABLE test_add_check ADD CONSTRAINT chkage CHECK (age > 18);
]]></programlisting>
  </example>

<tip><title>See Also:</title>
  <para><link linkend="sqlrefcreattablecheck">The CHECK constraint</link></para></tip>
  </sect2>
	</sect1>

  <sect1 id="CREATEVIEW"><title>CREATE VIEW Statement</title>
		<programlisting>
&lt;view definition&gt; ::=
    CREATE VIEW &lt;table name&gt; [ &lt;left paren&gt; &lt;view column list&gt;
                                  &lt;right paren&gt; ]
      AS &lt;query expression&gt;
</programlisting>
	</sect1>
  <sect1 id="CREATEXMLSCHEMA"><title>CREATE XML SCHEMA Statement</title>
		<programlisting>
&lt;xml schema definition&gt; ::=
    CREATE XML SCHEMA &lt;text of schema&gt;
</programlisting>
<para>
Virtuoso supports registering XML Schemas for use in
<link linkend="sqlrefcreattablewithschema">WITH SCHEMA</link>
constraint for column values. The statement contains the whole text of the schema as a
string constant, i.e. enclosed in single quotes. This is not the best possible syntax,
because single quotes inside the text of schema should be carefully quoted, but this is
de-facto standard. If the schema contains number of single quotes (e.g. attributes are
in single quotes instead of typically used double quotes), try a system stored procedure
<programlisting>
DB.DBA.SYS_CREATE_XML_SCHEMA (text_of_schema);
</programlisting>
that will have the same effect, but is not portable.
</para>
<para>
In principle, you can register any valid XMLSchema, but some features can cause prohibitive loss of performance.
It is strongly advised to compose the schema as a "standalone" document that has no references to
external DTDs or external generic entities. It is also strongly advised to avoid xs:include and
xs:import directives. The only sort of external references that does not affect performance is
xs:include or xs:import of a registered "sibling" schema. They say that a schema X is a "sibling" of schema Y
if their target namespace URIs have identical protocol names and host names and differs only in local path,
and schema X imports Y using relative (not absolute!) URI that contain only relative path,
(no protocol and no host).
</para>
<example id="ex_CREATEXMLSCHEMA"><title>Registering Sibling Schemas</title>
<para>Two sibling schemas are registered here.
First statement registers an XMLSchema for &quot;http://www.example.com/parts&quot; target namespace.
Second statement registers an XMLSchema for &quot;http://www.example.com/jobs&quot; target namespace
that imports the first schema using relative URI.
The rest of statements demonstrate a single WITH SCHEMA constraint that
inspect elements of these two target namespaces.</para>
<programlisting><![CDATA[
CREATE XML SCHEMA '<?xml version="1.0" encoding="utf-8" ?>
<xs:schema targetNamespace="http://www.example.com/parts"
  xmlns:xs="http://www.w3.org/2001/XMLSchema"
  xmlns:p="http://www.example.com/parts">
   <xs:element name="Part">
      <xs:complexType>
         <xs:choice minOccurs="0" maxOccurs="unbounded">
	   <xs:element ref="p:Part"/>
	 </xs:choice>
         <xs:attribute name="ID" type="xs:string" use="required" />
         <xs:attribute name="Count" type="xs:int" use="optional" />
         <xs:attribute name="Type" type="xs:string" use="optional" />
      </xs:complexType>
   </xs:element>
</xs:schema>'

CREATE XML SCHEMA '<?xml version="1.0" encoding="utf-8" ?>
<xs:schema targetNamespace="http://www.example.com/jobs"
  xmlns:xs="http://www.w3.org/2001/XMLSchema"
  xmlns:p="http://www.example.com/parts"
  xmlns:j="http://www.example.com/jobs">
   <xs:import schemaLocation="parts" />
   <xs:element name="Job">
      <xs:complexType>
         <xs:sequence>
	   <xs:element ref="p:Part"/>
	 </xs:sequence>
         <xs:attribute name="JobID" type="xs:string" use="required" />
      </xs:complexType>
   </xs:element>
</xs:schema>'

create table JOBS (
  PACK_ID integer primary key,
  CONTENT XMLType with schema ('http://www.example.com/jobs', 'Job')
  )

insert into JOBS values (1, '
<j:Job xmlns:j="http://www.example.com/jobs" xmlns:p="http://www.example.com/parts" JobID="asmkeyboard">
  <p:Part xmlns:p="http://www.example.com/parts" ID="keyboard">
    <p:Part Count="101"/>
    <p:Part ID="body"/>
  </p:Part>
</j:Job>')

*** Error 42000: [Virtuoso Driver][Virtuoso Server]XML parser detected an error:
	ERROR  : Only 0 out of 1 required attributes are defined for element <p:Part>, e.g. the element has no attribute 'ID'
at line 4 column 27 of '(value to be placed in column DB.DBA.JOBS of CONTENT)'
    <p:Part Count="101"/>
-------------------------^

insert into JOBS values (2, '
<j:Job xmlns:j="http://www.example.com/jobs" xmlns:p="http://www.example.com/parts" JobID="asmkeyboard">
  <p:Part xmlns:p="http://www.example.com/parts" ID="keyboard">
    <p:Part ID="key" Count="101"/>
    <p:Part ID="body"/>
  </p:Part>
</j:Job>');
]]>
</programlisting>
</example>
<note><title>Note:</title>
<para>
There is no way to change a registered schema if it is used in some WITH SCHEMA constraint.
Double-check any schema before using it, because it may be hard to fix the error
later.
</para>
</note>
	</sect1>
  <sect1 id="DROPXMLSCHEMA"><title>DROP XML SCHEMA Statement</title>
		<programlisting>
&lt;xml schema removal&gt; ::=
    DROP XML SCHEMA &lt;target URI&gt;
</programlisting>
<para>
This reverts the effect of <link linkend="CREATEXMLSCHEMA">CREATE XML SCHEMA</link>.
</para>
<para>The &lt;target URI&gt; should be a string constant that is equal to the value of
"targetNamespace" attribute of "xs:schema" element of a previously declared XML schema.
</para>
<para>The statement signals an error if the XMLSchema to be dropped is used in some WITH SCHEMA constraint.</para>
</sect1>
	<!-- ======================================== -->
  <sect1 id="sequenceobjects"><title>Sequence Objects</title>
  <para>
Virtuoso supports sequence objects. These can be used to generate sequential
numbers which can be used as unique identifiers.  A sequence object is
guaranteed never to give the same number twice.  Each sequence has a
name and a state. The state of a sequence is stored in the database at
checkpoint time. Between checkpoints sequence states are logged so that
a possible roll forward recovery will not lose information.
</para>
			<para>
The SQL functions <function>sequence_next</function>() and <function>sequence_set</function>() are used to access
and set the state of sequences.  These take the name of the sequence as
argument.  This is a server/wide unique string. There are no restrictions
on the length or character set of the sequence
</para>
			<para>
Sequences do not have to be separately created.  A sequence object
will automatically be generated when first referenced by <function>sequence_next</function>()
or sequence_set.
</para>
			<programlisting>sequence_next (in name varchar) returns integer
</programlisting>
			<programlisting>sequence_set (in name varchar, in state integer, in mode integer)
		returns integer
</programlisting>

			<para>
Function <function>sequence_next</function>() returns the current state of the specified sequence and
atomically increments it by one.  The next call will thus return a
number one greater than the previous. The sequence is shared between
all connections and all transactions.  Using a sequence never involves
locking.
</para>
			<para>
Function <function>sequence_set</function>() sets and returns the state of a sequence object.  The next
call to <function>sequence_next</function>() will return this same number.  If mode equals 0,
the state is set regardless of the previous state. If mode is non-zero,
the state is set only if the new state is greater then the previous
state.  Calling sequence_set (&apos;sequence&apos;&apos; , 0, 1) will always return
the sequence&apos;s state without changing it.
</para>
  <para>
      Each autoincrement column corresponds to an internal sequence object.
  The name of the sequence object is&apos;DB.DBA.&apos; plus the concatenation
  of the table's qualifier, owner, table name and column name,
  e.g. &apos;DB.DBA.db.dba.my_table.ai_column&apos;.  The user does not
  normally need to know about the sequence associated with an autoincrement
  column unless he or she wishes to change the sequence values using the
  <function>sequence_set()</function> function and the sequence objects name.</para>
<para>
See the section on identity columns under create table and the function identity_value and the related ODBC statement option SQL_GETLASTSERIAL for more. 
</para>
	</sect1>
	<sect1 id="insertSTMT">
		<title>INSERT Statement</title>

<programlisting>
    insert_statement
	    : INSERT insert_mode table priv_opt_column_commalist values_or_query_spec
	    ;

    insert_mode
	    : INTO
	    | REPLACING
	    | SOFT

    priv_opt_column_commalist
	    : /* empty */
	    | &apos;(&apos; column_commalist &apos;)&apos;&#10;
	    ;

    values_or_query_spec
	    : VALUES &apos;(&apos; insert_atom_commalist &apos;)&apos;
	    | query_spec
	    ;

    insert_atom_commalist
	    : insert_atom
	    | insert_atom_commalist &apos;,&apos; insert_atom
	    ;

    insert_atom
	    : scalar_exp
	    ;

    column_commalist
	    : column
	    | column_commalist &apos;,&apos; column
	    ;

    query_spec
	    : SELECT opt_all_distinct selection table_exp
	    ; ... See the SELECT statement next.
</programlisting>

<para>
New rows (or records) are entered into a database using the INSERT statement.
</para><para>
If you have to enter a NULL you can simply use the keyword NULL, as you would a normal value.  Since
NULL is a special keyword you do not need to enclose it in single quotes.
</para><para>
You can specify the columns that you are inserting values into in the insert statement.  One
should always specify the columns that you are inserting into, in case the order of columns in
the database are not as expected, or you are not inserting values into every column.
</para><para>
If a value is not specified for a column on insert, then the default value will be used for that column.
If no default value has been specified either by a CREATE or MODIFY TABLE statement then NULL will be used.
</para>

<sect2 id="insertsoft"><title>INSERT SOFT</title>
<para>
<emphasis>INSERT SOFT</emphasis> can be used in place of <emphasis>INSERT INTO</emphasis>
if you are unsure whether the value to be inserted into a primary key column will
violate that constraint.  If the row with this primary key already exists, then the
new row is not inserted.
</para>
<programlisting>
SQL> create table insert_test(id integer primary key, txt varchar);
Done. -- 90 msec.
SQL> insert into insert_test(id, txt) values(1, 'test');
Done. -- 0 msec.
SQL> insert into insert_test(id, txt) values(1, 'test');

*** Error 23000: [Virtuoso ODBC Driver][Virtuoso Server]SR197:
  Non unique primary key on DB.DBA.insert_test. at line 4 (4) of Top-Level:
  insert into insert_test(id, txt) values(1, 'test')

SQL> insert soft insert_test(id, txt) values(1, 'testsoft');

Done. -- 0 msec.
SQL> select * from insert_test;
id                txt
INTEGER NOT NULL  VARCHAR
_______________________________________________________________________________

1                 test

1 Rows. -- 60 msec.
</programlisting>
</sect2>

<sect2 id="insertreplacing"><title>INSERT REPLACING</title>
<para>
<emphasis>INSERT REPLACING</emphasis> can be used in place of <emphasis>INSERT INTO</emphasis>
if you are unsure whether the value to be inserted into a primary key column will
violate that constraint.  If the row with this primary key already exists, then the
new row will be inserted replacing the old values.
</para>
<programlisting>
SQL> create table insert_test(id integer primary key, txt varchar);
Done. -- 90 msec.
SQL> insert into insert_test(id, txt) values(1, 'test');
Done. -- 0 msec.
SQL> insert into insert_test(id, txt) values(1, 'test');

*** Error 23000: [Virtuoso ODBC Driver][Virtuoso Server]SR197:
  Non unique primary key on DB.DBA.insert_test. at line 4 (4) of Top-Level:
  insert into insert_test(id, txt) values(1, 'test')

SQL> insert replacing insert_test(id, txt) values(1, 'testreplacing');

Done. -- 0 msec.
SQL> select * from insert_test;
id                txt
INTEGER NOT NULL  VARCHAR
_______________________________________________________________________________

1                 testreplacing

1 Rows. -- 0 msec.
</programlisting>
</sect2>
</sect1>

<sect1 id="updatestmt">
	<title>UPDATE Statement</title>
	
	<para>Existing rows (or records) are changed in the database using the UPDATE statement.</para>
	
	<para>NULL values can be utilized using the <computeroutput>NULL</computeroutput> keyword without 
		any quotes.  Since NULL is a special keyword you do not need to enclose it in single quotes, doing so 
		will cause it be read as a string-literal.</para>
	
	<para>The update statement is made up by selecting the table to update, the search condition that 
		identifies which rows you want to update, and the <computeroutput>column=value</computeroutput>  
		of each column you wish to change.  </para>
		
	<example id="ex_updatestatement"><title>Basic Update Statement</title>
		<para>A table can be updated using:</para>
		<screen><![CDATA[
update demo.dba.employees e
  set username = 'thing'
  where email_address = 'thing@thingdom.com'
  ;
]]></screen>
	</example>
	
	
	<example id="ex_updatestatementfrom"><title>Update from Select</title>
		<para>It is possible to update one table based on a select from another 
		table.  Ensure that the selection is properly conditioned to update.</para>
	<screen><![CDATA[
update demo.dba.employees e
	set username = (select U_NAME from DB.DBA.SYS_USERS u where u.U_EMAIL = e.email_address)
	;
]]></screen>	
	</example>
</sect1>

	<sect1 id="SELECTSTMT">
		<title>SELECT Statement</title>
		<sect2 id="selectsyntax">
			<title>Syntax</title>
			<para/>
			<programlisting>
&lt; select statement: single row &gt; ::= SELECT [ &lt; set quantifier &gt; ] &lt; select list &gt;&#10;
      INTO &lt; select target list &gt;&#10;
      &lt; table expression &gt;&#10;

&#10;&lt; select target list &gt; ::=
      &lt; target specification &gt; [ { &lt; comma &gt; &lt; target specification &gt; }... ]

&#10;&lt; query expression &gt; ::=
      &lt; non-join query expression &gt;&#10;
    | &lt; joined table &gt;&#10;

&#10;&lt; non-join query expression &gt; ::=
      &lt; non-join query term &gt;&#10;
    | &lt; query expression &gt; UNION  [ ALL ]
          [ &lt; corresponding spec &gt; ] &lt; query term &gt;&#10;
    | &lt; query expression &gt; EXCEPT [ ALL ]
          [ &lt; corresponding spec &gt; ] &lt; query term &gt;&#10;

&#10;&lt; non-join query term &gt; ::=
      &lt; non-join query primary &gt;&#10;
    | &lt; query term &gt; INTERSECT [ ALL ]
          [ &lt; corresponding spec &gt; ] &lt; query primary &gt;&#10;

&#10;&lt; non-join query primary &gt; ::=
      &lt; simple table &gt;&#10;
    | &lt; left parent &gt; &lt; non-join query expression &gt; &lt; right parent &gt;&#10;

&#10;&lt; simple table &gt; ::=
      &lt; query specification &gt;
    | &lt; table value constructor &gt;
    | &lt; explicit table &gt;

&#10;&lt; query specification &gt; ::=
    SELECT [ &lt; set quantifier &gt; ] &lt; select list &gt; &lt; table expression &gt;

&#10;&lt; select list &gt; ::=
      &lt; asterisk &gt;
    | &lt; select sublist &gt; [ { &lt; comma &gt; &lt; select sublist &gt; }... ]

&#10;&lt; select sublist &gt; ::=
      &lt; derived column &gt;
    | &lt; qualifier &gt; &lt; period &gt; &lt; asterisk &gt;

&#10;&lt; derived column &gt; ::= &lt; value expression &gt; [ &lt; as clause &gt; ]

&#10;&lt; as clause &gt; ::= [ AS ] &lt; column name &gt;

&#10;&lt; table expression &gt; ::=
    &lt; from clause &gt;
    [ &lt; where clause &gt; ]
    [ &lt; group by clause &gt; ]
    [ &lt; having clause &gt; ]

&#10;&lt; from clause &gt; ::= FROM &lt; table reference &gt;
    [ { &lt; comma &gt; &lt; table reference &gt; }... ]

&#10;&lt; table reference &gt; ::=
      &lt; table name &gt; [ [ AS ] &lt; correlation name &gt;
          [ &lt; left parent &gt; &lt; derived column list &gt; &lt; right parent &gt; ] ]
    | &lt; derived table &gt; [ AS ] &lt; correlation name &gt;
          [ &lt; left parent &gt; &lt; derived column list &gt; &lt; right parent &gt; ]
    | &lt; joined table &gt;

&#10;&lt; derived column list &gt; ::= &lt; column name list &gt;

&#10;&lt; derived table &gt; ::= &lt; table subquery &gt;

&#10;&lt; table subquery &gt; ::= &lt; subquery &gt;

&#10;&lt; joined table &gt; ::=
      &lt; cross join &gt;
    | &lt; qualified join &gt;
    | &lt; left parent &gt; &lt; joined table &gt; &lt; right parent &gt;

&#10;&lt; cross join &gt; ::=
    &lt; table reference &gt; CROSS JOIN &lt; table reference &gt;

&#10;&lt; qualified join &gt; ::=
    &lt; table reference &gt; [ NATURAL ] [ &lt; join type &gt; ] JOIN
      &lt; table reference &gt; [ &lt; join specification &gt; ]

&#10;&lt; join type &gt; ::=
      INNER
    | &lt; outer join type &gt; [ OUTER ]
    | UNION

&#10;&lt; outer join type &gt; ::=
      LEFT
    | RIGHT
    | FULL

&#10;&lt; join specification &gt; ::=
&#10;      &lt; join condition &gt;
    | &lt; named columns join &gt;

&#10;&lt; join condition &gt; ::= ON &lt; search condition &gt;

&#10;&lt; named columns join &gt; ::=
    USING &lt; left parent &gt; &lt; join column list &gt; &lt; right parent &gt;

&#10;&lt; join column list &gt; ::= &lt; column name list &gt;

&#10;&lt; where clause &gt; ::= WHERE &lt; search condition &gt;

&#10;&lt; group by clause &gt; ::=
    GROUP BY &lt; grouping column reference list &gt;

&#10;&lt; grouping column reference list &gt; ::=
&#10;    &lt; grouping column reference &gt;
        [ { &lt; comma &gt; &lt; grouping column reference &gt; }... ]

&#10;&lt; grouping column reference &gt; ::=
&#10;    &lt; column reference &gt; [ &lt; collate clause &gt; ]
</programlisting>
			<para/>
		</sect2>
		<sect2 id="descrip">
			<title>Description</title>
			<para>
The SELECT statement is the principal means of information retrieval in SQL.
A SELECT can retrieve information from one or more tables with arbitrary search criteria.
SELECT&apos;s can also be nested to have the output of one serve as an input or search condition for another.
Several SELECT&apos;s can be combined into one query with the UNION, INTERSECTION and EXCEPT operators.
</para>
			<para>
The SELECT syntax consists of the following parts:
</para>
			<programlisting>
SELECT [DISTINCT] scalar_exp {, scalar_exp}
	FROM table {, table}
	WHERE &lt; search condition &gt;
	GROUP BY &lt; column list &gt;
	HAVING &lt; search condition &gt;
	ORDER BY &lt; ordering spec list &gt;
	FOR UPDATE
</programlisting>
			<para>
All parts are optional. If one or more of the clauses
appear they must appear in the above order.  All parts do not need to be specified,
e.g. SELECT A FROM T FOR UPDATE is valid but SELECT A FROM T ORDER BY a WHERE &lt; &lt; 10 is not.
</para>
			<note>
				<title>Note:</title>
				<para>A select without a FROM clause is allowed.
</para>
				<para>
This is useful for returning values of expressions to the client. Such a select always returns one row,
with the values listed as columns. Typically only useful from interactive SQL.
</para>
				<para>
Example:
</para>
				<para>
select 1 + 2 as three;
</para>
			</note>
			<para>
A table reference in the FROM clause can either be a simple table name, another SELECT
expression of the form described above or a join expression.
A SELECT inside a FROM is called a derived table. This means that the rows selected by
the derived table expression are treated as if they constituted a table. This is similar to a
VIEW reference and a derived table can be thought of as an unnamed in-line VIEW declaration.
</para>
			<para>
A join expression combines table references, which are either simple, derived or joined tables
themselves into different joins.
</para>
			<para>
A join is an operation that retrieves for each row of one table zero
or more rows from another table. The join condition specifies how the rows are matched.
The result of a join is a set of rows containing selected columns from both joined tables.
Joins are by default so called INNER joins, which means that for a row to be in the result
there must be a row matching the left table in the right table as specified by the join
condition. An OUTER join is a join that will produce a result row even if there is no row
in the right table for the row in the left table. The columns that would have come from the
right table are then just set to NULL&apos;s.
</para>
			<programlisting>
table_ref ::=
	&lt; table name &gt; [&lt; correlation name &gt;]
  |	/ query expression ) &lt; correlation name &gt;
  |	&lt; table ref &gt; &lt; [NATURAL] join &gt; &lt; table ref &gt; &lt; join condition &gt;

join ::=
  	&lt; empty &gt;
  |	CROSS
  |	INNER
  | 	LEFT [OUTER]
  | 	RIGHT [OUTER]

join condition ::=
	&lt; empty &gt;
  |	ON &lt; search condition &gt;
  |	USING &apos;(&apos; &lt; column &gt; {, column} &apos;)&apos;
</programlisting>
			<para>
The &lt; correlation name &gt; is an identifier that is used to identify the table in a column
reference if the same table appears many times in the query expression, e.g. is joined
with itself.
</para>
			<para>
The CROSS join has no join condition. This means that for each row in the left table all
rows in the right table are included in the result.
</para>
</sect2>
<!-- ======================================== -->
	<sect2 id="ASDEC">
		<title>Column Aliasing - AS Declaration</title>
		<para>
Virtuoso supports the AS operator in the selection list of a SELECT
statement. This notation allows declaring a name and optionally a type
and precision for a statement&apos;s output column.
</para>
		<para>
The syntax is:
</para>
		<screen>
as_exp:
Scalar_exp AS NAME opt_data_type
</screen>
		<para>
For instance, one can write:
</para>
		<programlisting>
SELECT COUNT (*) AS NUMBEROFROWS FROM XX;
SELECT COUNT (*) AS NUMBEROFROWS INTEGER (2) FROM XX;
SELECT CONCATENATE (COL1, COL2) AS RESULTSTRING VARCHAR (50) FROM XX;
</programlisting>
		<para>
The AS expression tells the client to return specified values in the
SQLDescribeCol, SQLColAttribute or equivalent calls. The semantics of
statements is not otherwise affected.   An AS expression can appear
anywhere a scalar expression can but the only place where it has an
effect is the selection list of a SELECT statement.
</para>
		<para>
If a data type is given and contains a precision, that precision is
returned to the client as the precision of the column in question.
</para>
		</sect2>
		<sect2 id="joinexamples">
			<title>Join examples</title>
			<para>
The following three statements produce an identical result.
</para>
			<programlisting>
select Orders.OrderID, ProductID
    from Orders natural join Order_Details using (OrderID)
select Orders.OrderID, ProductID
    from Orders join Order_Details on Orders.OrderID = Order_Details.OrderID
select Orders.OrderID, ProductID
    from Orders,  Order_Details where Orders.OrderID = Order_Details.OrderID
</programlisting>
			<note>
				<title>Note:</title>
				<para>In all these cases if there exists no Order_Details row matching the Orders row there
will no no result row corresponding to the Orders row.  An outer join can can be used to also
retrieve left table records for which there is no matching right table record.
</para>
			</note>
			<programlisting>
select Orders.OrderID, ProductID
    from Orders natural left outer join Order_Details using (OrderID)
</programlisting>
			<para>will produce a result identical to the above sample if for each Orders row there is at least
one Order_Details row. If there is none however, the OrderID column from Orders will appear
together with a NULL ProductID from the non-existent Order_Details.
</para>
			<para>
A right outer join is like a left outer join with the left and right tables reversed.
</para>
		</sect2>
		<sect2 id="ordergrping">
			<title>Ordering and Grouping</title>
			<para>
The result rows of a query can be ordered based on their column values.
The ORDER BY phrase allows specifying an ascending or descending sort order for a
any column. The SQL interpreter will use an index if there is an index whose order
reflects the order in the ORDER BY clause. If there is no appropriate index or if
ascending and descending order is combined for columns of the same table the SQL
interpreter will first evaluate the query and then sort the results before returning
them.
</para>
			<tip>
				<title>See:</title>
				<para>Optimizations below for more information.</para>
			</tip>
			<programlisting>
 select * from Employees order by BirthDate;
</programlisting>
			<para>
will list all employees, oldest first, in ascending order of birth date.
</para>
			<para>
The GROUP BY clause allows computing functions over repeating groups. Without
the GROUP by clause set functions (AVG, MIN, MAX, SUM, COUNT) may not be mixed
with normal columns in a selection list.
If set functions and columns are mixed, all the columns must appear in the GROUP BY section.
Such a query will produce as many rows as there are distinct value combinations of the grouping columns.
The set functions will be computed for each distinct column combination.
</para>
			<programlisting>
select OrderID, sum (UnitPrice * Quantity)
   from Order_Details group by OrderID
   having sum (UnitPrice * Quantity) &gt; 5000  order by 2 desc;
</programlisting>
			<para>
Produces the OrderID and total value of the order in decreasing order of order value.
The HAVING clause specifies that only orders with a value &gt; 5000 will be counted. Note
that the sum expression in having must be written identically to the same expression
in the SELECT left.
</para>
			<para>
The 2 in the order by refers to the second column of the select, which has no name,
it being a function reference.
</para>
		<sect3 id="ordergrping_cube">
		<title>CUBE and ROLLUP</title>
		<para>Virtuoso database offers the tool which increase efficiency of SQL summary queries and
 simplify such operations. The options ROLLUP and CUBE in the GROUP BY allow creating more comprehensive
 summary operations. The result of CUBE and ROLLUP are result sets which could be produced in other
way only with additional coding and queries. </para>
		<para>The ROLLUP and CUBE extends the result set of GROUP BY. The ROLLUP builds consequence
 of subtotal aggregates on every queried level including the grand total. The CUBE is an extension of ROLLUP.
 It builds all possible subtotal aggregates combination for given GROUP BY.</para>
		<para>Here are the examples of ROLLUP and CUBE usage:</para>
		<programlisting>
select j, grouping (j), k, grouping (k), t, grouping (t), sum (i) from TABLE1 group by rollup (j,k,t);
select j, grouping (j), k, grouping (k), t, grouping (t), sum (i) from ROLLUP1 group by cube (j,k,t);
</programlisting>
		<para>the grouping(c1) procedure returns &quot;1&quot; if the column &quot;c1&quot; is
 not in the dynamic GROUP BY set, and returns &quot;0&quot; otherwise.</para>
		<para>The result set of:</para>
		<programlisting>
select j, k, t, sum (i) from TABLE1 group by rollup (j,k,t) ;
</programlisting>
		<para>is equivalent of accumulate result sets of:</para>
		<programlisting>
select j, k, t, sum (i) from TABLE1 group by j,k,t;
select NULL, k, t, sum (i) from TABLE1 group by k,t;
select NULL, NULL, t, sum (i) from TABLE1 group t;
select NULL, NULL, NULL, sum (i) from TABLE1;
</programlisting>
		<para>The result set of:</para>
		<programlisting>
select t,s, sum (i) from TABLE1 group by cube (t,s);
</programlisting>
		<para>is equivalent of accumulate result set of:</para>
		<programlisting>
select t,s, sum (i) from TABLE1 group by t,s;
select t,NULL, sum (i) from TABLE1 group by t;
select s,NULL, sum (i) from TABLE1 group by s;
select NULL,NULL, sum (i) from TABLE1;
</programlisting>
		</sect3>
		</sect2>
		<sect2 id="derivedtables">
			<title>Derived Tables</title>
			<para>
A SELECT expression may be used in the place of a table in a FROM clause.
This provides control over where DISTINCT and ORDER BY operations are evaluated.
</para>
			<programlisting>
select ProductName, UnitsInStock
    from (select distinct ProductID from Order_Details) O,
        Products where Products.ProductID = O.ProductID;
</programlisting>
			<para>
This retrieves the name and quantity of products that have been ordered.
</para>
			<para>
An equivalent phrasing would be
</para>
			<programlisting>
select distinct ProductName, UnitsInStock
   from Order_Details O, Products where Products.ProductID = O.ProductID;
</programlisting>
			<para>
The difference is that the latter retrieves a Products row for each order line whereas
as the first retrieves a products row for each distinct product  in the order lines.
The first is therefore faster to evaluate. Also note that the rows in the DISTINCT buffer
in the first example only consist of the product id whereas they are much longer in the
second example.
</para>
			<para>
Note that a correlation name is required for derived tables since the derived table is as
such anonymous.
</para>
		</sect2>
		<sect2 id="qryexpressions">
			<title>Query Expressions</title>
			<programlisting>
&lt; non-join query expression &gt; ::=
      &lt; non-join query term &gt;
    | &lt; query expression &gt; UNION  [ ALL ]
          [ &lt; corresponding spec &gt; ] &lt; query term &gt;
    | &lt; query expression &gt; EXCEPT [ ALL ]
          [ &lt; corresponding spec &gt; ] &lt; query term &gt;

&lt; corresponding spec &gt; ::=
    CORRESPONDING [ BY &lt; left parent &gt;
        &lt; corresponding column list &gt; &lt; right parent &gt; ]
</programlisting>
			<para>
Queries can be combined by set operators UNION, INTERSECTION and EXCEPT (set difference).
The ALL keyword will allow duplicate rows in the result set. The CORRESPONDING BY clause
allows specifying which columns will be used to determine the equality of rows from the
left and right operands.
</para>
			<programlisting>
 select OrderID from Orders except
    corresponding by (OrderID) select OrderID from Order_Details
</programlisting>
			<para>
will produce the OrderID&apos;s of orders that have no Order_Details. This is equivalent to:
select OrderID from Orders a where not exists (select 1 from Order_Details b where a.OrderID = b.OrderID)
</para>
			<para>
Note that the queries, although to a similar effect are executed quite differently.
There may be significant differences in performance.
</para>
		</sect2>
		<sect2 id="LikePredicate">
<title>LIKE Predicate &amp; Search Patterns</title>
	<para>
The <emphasis>LIKE</emphasis> predicate expects a pattern to be applied to
a varchar or nvarchar column to qualify the results to be returned from a query.
</para>
	<para>
If the pattern does not begin with an at-sign (@) or with two
asterisks (**), then we test the equality of the string and pattern
with ordinary wildcard matching, which behaves
approximately like the filename pattern matching in the Unix shell.
(But not like the regular expression matching in utilities like grep
and sed).
</para>
	<para>
The following characters have special significance in the pattern:
</para>
	<simplelist>
		<member>?    Matches any single character.</member>
		<member>*    Matches zero or more of any characters.</member>
	</simplelist>

	<para>
[ ]  (Called a group-expression here)
Matches any one of the enclosed characters, unless the
first character following the opening [ is ^, then matches
only if the character (in the datum string) is not any one of
those specified after the ^. (i.e. the ^ negates the meaning
of this expression.)
</para>
	<para>
You can use character ranges like 0-9 (shorthand for 0123456789)
inside the brackets, in which case the character in the datum
string must be lexically within the inclusive range of that
pair (of course the character at the left side of hyphen must
be lexically (that is, its ASCII value) less than the
character at the right side).
</para>
	<para>
The hyphen can be included in the character set by putting it
as the first or last character.  The right bracket (]) can
be included by putting it as the first character in the expression,
i.e. immediately after the opening bracket ([) or the caret (^)
following it.
</para>

<example>
<title>Examples:</title>
<programlisting>
[abc]          Matches any of the letters a, b and c.
[^0123456789]  Matches anything, except digits. (same as [^0-9])
[[]            Matches [
[]]            Matches ]
[][]           Matches ] and [
[^]]           Matches anything except ]
[A-Za-z0-9]    Matches all the alphanumeric characters.
[-*+/]         Matches the four basic arithmetic operators.
[-]            Matches to single hyphen.
[]-]           Matches to ] or -
[-[] or [[-]   Matches to - or [
</programlisting>
</example>

	<para>
That is, the hyphen indicates a range between characters, unless
it is the first or the last character in the group expression,
in which case it matches just to itself.
</para>
	<para>
<emphasis>@</emphasis>   Matches the character last matched to ? or group-expression.
For example ?*@ matches to all strings which begin with the same
character they end.  However, if there is neither ? nor [] expression
at the left side of @ in the pattern, then @ matches just to
itself. (e.g. *@* should match to all e-mail addresses).
</para>
	<para>
Any other characters match ONLY to themselves, that is, not even to
the upper- or lowercase variants of the same letter. Use expression
like [Wo][Oo][Rr][Dd] if you want to find any mixed-case variant of
the word "word", or use the substring search explained below.
</para>
	<para>
However, if the pattern begins with an at-sign (@) then we compare
the rest of pattern to string with the fuzzy matching,
allowing differences of few characters in quality and
quantity (length).  If there is more than one @ in the beginning of
pattern they are all skipped, and so many
additional liberties are given for the match function.  The more
@-signs there are in the beginning, the more fuzzy (liberal) is the
search.  For example: pattern "@Johnson" will match to string
"Jonsson" and pattern "@@Johnson" will match also to "Jansson".
</para>
	<para>
If the pattern begins with two asterisks, then we do diacritic- and
case insensitive substring search,
trying to find the string given in the rest of pattern from the
datum string.
</para>

<example><title>Example:</title>
<para>"**escort" will match to "Ford Escort vm. 1975".</para>
</example>

	<para>
If there are any ISO8859.1 diacritic letters (e.g. vowels with
accents or umlaut-signs, or letters like the Spanish n with ~ (tilde))
present in the datum string, then the plain unaccented (7-bit ASCII)
variant of the same letter in the pattern string will match to it.
But if there are any diacritic letter specified in the pattern string,
then it will match only to the upper- or lowercase variant of exactly
the same diacritic letter.
</para>
	<para>
The rationale behind this is that the people entering the information
to database can use the exact spelling for the word, for example
writing the word "Citroen" with the umlaut-e (e with two dots above it),
as it is actually written in French, and the people who search for
the Citroens can still find it without need to remember the exact
orthography of the French, by just giving a word "citroen".
And this allows also the people who have just plain 7-bit ASCII
keyboards to search for the words like Ra"a"kkyla" (place in Finland,
a" means umlaut-a, i.e. a with two dots above it), just by entering
the word raakkyla.
</para>
	<para>
So the following holds with the substring searches:
</para>

<simplelist>
	<member>
1) Any non-alphabetic character in the pattern matches just to itself
in the datum string (e.g. ? to ? and 3 to 3).
</member>
	<member>
2) Any 7-bit ASCII letter (A-Z and a-z without any diacritic signs)
in the pattern matches to any diacritic variant of the same letter
(as well as to same 7-bit ASCII letter) in the datum string, either
in the upper- or lowercase.
</member>
	<member>
3) Any diacritic letter (8-bit ISO8859.1 letter) in the pattern matches
only to the same letter (in the upper- or lowercase) in the datum
string.
</member>
</simplelist>

<note><title>Note:</title>
<para>because the internal matching functions use macros
which consider also the characters like:
@, [, \, ], and ^ to be letters, they will match against characters
`, {, |, }, and ~ respectively, which is just all right, because
in some older implementations of European character sets those
characters mark the uppercase and lowercase variants of certain
diacritic letters.
</para>
</note>

	<para>
It is generally better to match
too liberally and so maybe sometimes give something entirely off
the wall to the user, than to miss something important because of
too strict criteria.
</para>
	<para>
Of course, when searching from the data which contains text in
some wide-character format (like certain coding systems for
Japanese and Chinese where one character is coded with two bytes)
neither fuzzy matching function nor nc_strstr function presented here
should be used, as they would often match on entirely spurious cases.
</para>
		</sect2>
<sect2 id="topselectoption">
	<title>The TOP SELECT Option</title>

	<programlisting>
query_term :  SELECT opt_top selection ....

opt_top :  opt_all_distinct [ TOP INTNUM ]
	|  opt_all_distinct [ TOP SKIPINTNUM, INTNUM ]
	|  opt_all_distinct [ TOP (num_scalar_exp) ]
	|  opt_all_distinct [ TOP (skip_num_scalar_exp, num_scalar_exp) ]
opt_all_distinct : [ ALL | DISTINCT ]
</programlisting>

	<para>
The TOP n phrase can follow an optional ALL or DISTINCT keyword in a SELECT,
either at top level or inside a query term of an expression or subquery. The query
with the TOP option will generate at most the indicated number of result rows.
</para>
	<para>
The scope of TOP is the query in question.  For example
</para>
	<programlisting>
select top 3 row_no from t1 best union select top 3 row_no + 1 from t1;
</programlisting>
	<para>
Will always return 4 rows assuming there are at least 3 rows in T1.
</para>

<para>The optional SKIPINTNUM parameter lets you offset the selection
by SKIPINTNUM number of rows.  If you have a ten-row table and
<computeroutput>select top 2 from this_table</computeroutput> you get
the first two rows, <computeroutput>select top 2, 2 from this_table</computeroutput>
will return the third and fourth rows only, instead.</para>

</sect2>

<sect2 id="caseandco"><title>CASE, NULLIF, COALESCE, CAST Value Expressions</title>
  <sect3 id="case"><title>The CASE Expression</title>
  <para>There are many situations where you might find it useful to alter the
  the data returned by a SQL query based on a few rules.  For example, you may
  want to display Customers gender as 'Male' or 'Female' based on whether their
  title is 'Mr' or one of 'Miss', 'Mrs' or 'Ms'.  The CASE expression can
  easily accommodate this.</para>
  <para>The Syntax of CASE is:</para>
  <programlisting><![CDATA[
CASE
  WHEN <search-condition> THEN <output>
  WHEN <search-condition> THEN <output>
  ...
  ELSE <output>
END
]]></programlisting>
  <para>When a &lt;search-condition&gt; is met the corresponding &lt;output&gt;
  is returned.  If no conditions are met then the &lt;output&gt; after is ELSE
  is returned as a default value.</para>

  <example id="ex_caseexp"><title>Using the CASE expression</title>
  <programlisting>
SELECT Title, CustomerName,
  CASE
    WHEN Title = 'Mr' THEN 'Male'
    WHEN Title = 'Mrs' THEN 'Female'
    WHEN Title = 'Miss' THEN Female'
    WHEN Title = 'Ms' THEN 'Female'
    ELSE 'Unknown'
  END as Gender,
  Company
  FROM Customers
</programlisting>
  <para>May return values such as:</para>
  <screen>
Title   Gender  CustomerName        Company
VARCHAR VARCHAR VARCHAR             VARCHAR
___________________________________________________________

Mr      Male    Thomas Hardy        Around the Horn
Miss    Female  Christina Berglund  Berglunds shop
Mrs     Female  Hanna Moos          Blauer See Delikatessen
Mr      Male    Laurence Lebihan    Bon app
</screen>
  </example>

  <para>There is also a short hand notation for the CASE expression as follows:</para>
  <programlisting><![CDATA[
CASE <search-parameter>
  WHEN <search-value> THEN <output>
  WHEN <search-value> THEN <output>
  ...
  ELSE <output>
END
]]></programlisting>

  <para>This short hand is best demonstrated by the rewrite of the above example
  as follows:</para>

  <example id="ex_caseexpshort"><title>Using the CASE short-hand expression</title>
  <programlisting>
SELECT Title, CustomerName,
  CASE Title
    WHEN 'Mr' THEN 'Male'
    WHEN 'Mrs' THEN 'Female'
    WHEN 'Miss' THEN Female'
    WHEN 'Ms' THEN 'Female'
    ELSE 'Unknown'
  END as Gender,
  Company
  FROM Customers
</programlisting>
  </example>

  <para>In both cases the ELSE keyword is optional.  If ELSE is unspecified
  then ELSE NULL is implicit.</para>

  </sect3>

  <sect3 id="casenullif"><title>The NULLIF Expression</title>
  <para>The NULLIF expression is a short hand implementation of a special case
  of the CASE expression for a popular demand.  Consider the following CASE
  expression:</para>

  <programlisting><![CDATA[
CASE col1
  WHEN 'something' THEN NULL
  ELSE col1
END
]]></programlisting>

  <para>This is replaced by the NULLIF expression which achieves the same
  result using the following, much shorter expression:</para>

    <programlisting><![CDATA[
NULLIF (col1, 'something')
]]></programlisting>

  <para>This is often useful in situations where you have a code to denote
  a value as unspecified for whatever reason, but in many applications you
  would rather this was NULL.</para>
  </sect3>

  <sect3 id="casecoalesce"><title>The COALESCE Expression</title>
  <para>The COALESCE expression is another application of the CASE expression
  to suit another frequent requirement.  The syntax of COALESCE is as follows:</para>

    <programlisting><![CDATA[
COALESCE (value-1, value-2, ..., value-n)
]]></programlisting>

  <para>COALESCE returns the first non-NULL parameter.  This is equivalent to</para>

    <programlisting><![CDATA[
CASE
  WHEN value-1 IS NOT NULL THEN value-1
  WHEN value-2 IS NOT NULL THEN value-2
  ...
  ELSE value-n
END
]]></programlisting>
  </sect3>

  <sect3 id="selcastexp"><title>The CAST Expression</title>
  <para>SQL has always been considered a strongly typed language, meaning that
  you cannot have expressions that contain arbitrary data types.  Casting is
  invaluable for comparing values that are obviously compatible but their
  data types are not, such as <computeroutput>1 = '1'</computeroutput>.  This
  attempts compares an integer with a char which would not work unless one of the
  values was cast as follows:</para>

  <programlisting>cast('1' as integer) = 1</programlisting>

  <tip><title>See Also:</title>
  <para>The <link linkend="dtcasting">CASTING</link> section for more
  information.</para></tip>
  </sect3>
  </sect2>
<sect2 id="selbreackup"><title>SELECT BREAKUP</title>
        <para>Virtuoso extends the select statement with a breakup option. This option allows
a single row selected by a derived table to be seen as multiple rows by the enclosing query.
</para>
        <para>This is specially useful when translating relation tables to RDF. Using breakup,
one can do a single pass over a table and generate multiple triples, each presented as a separate result row.
</para>
        <para>The syntax is:
</para>
        <programlisting>
SELECT BREAKUP breakup_term [, ...] FROM ....
breakup_term ::=

scalar_exp [, scalar_exp...] [WHERE search_condition]
</programlisting>

	<para>Each breakup term is a list of comma separated expressions with an optional search condition at
the end. Each list is treated as a select list in a union, i.e. they must be of equal length and the leftmost
list must provide a name for each column. This means that an AS declaration is needed if the expression is not a column.
</para>
	<para>If a breakup tern has the optional WHERE clause, the condition is evaluated in the scope of the
select, i.e. all that is defined by the FROM. If the condition is true, the row represented by the breakup term
is added to the result set of the breakup select, otherwise it is ignored.
</para>
        <para>A breakup select is only allowed in a derived table or a union or other set operator term inside
a derived table. A top level breakup select is not allowed. To have a breakup select as the topmost select, simply write:
</para>
        <programlisting>
select * from (select breakup .... from ...) f;
</programlisting>
	<para>Breakup cannot be mixed with distinct, top, group by or order by. Again, to combine these, use nested derived tables.
</para>
        <para>Breakup operates equally well on local and remote tables. Breakup is never passed on to a remote but the FROM of a
breakup select can consist of tables from any source.
</para>
<example>
<title>Examples:</title>
<programlisting>
select * from (select breakup (a.row_no, b.fi2) (b.row_no, a.fi3 where a.fi3 is not null)
from r1..t1 a, r1..t1 b
where a.row_no &lt; 10 and b.row_no = a.row_no)f;
</programlisting>
</example>
        <para>This produces 2 rows for each result of the join, except if fi3 is null, in which case only the first term of
the breakup is returned in the result set.
</para>
</sect2>


</sect1>
	<!-- ======================================== -->
	<sect1 id="COMMIT_ROLLBACK">
		<title>COMMIT WORK, ROLLBACK WORK Statement</title>
		<para>
These statements reset the current transaction.  COMMIT WORK leaves all the changes made
by the current transaction in effect whereas ROLLBACK work reverses them.
</para>
		<para>
In both cases, the transaction will be in a fresh state, having no locks and
no changes that could be rolled back.  The rollback operation always succeeds, as any
change is always reversible until committed.  COMMIT WORK may fail if the
transaction had been marked to be canceled before the COMMIT WORK operation started.  A failed
commit has the effect of a rollback but it will signal a SQL STATE descriptive of
the error, e.g. 40001 (deadlock).
</para>
		<para>
These operations are typically not needed, since the SQLTransact ODBC call and the ODBC
autocommit mode are used instead for transaction control.  The only use for
these statements is within stored procedures, where it may be practical to break
a long sequence of operations into several transactions to reduce lock contention.
</para>
		<para>
These can also be used together with the WHENEVER declaration to automate
retry upon deadlock inside stored procedures.
</para>
		<para>
Triggers should not normally use these statements.  The exception is the case where
 a trigger detects a state violating application consistency rules and decides to
abort the transaction. This can be done by ROLLBACK WORK, typically followed by a call to
the signal function for notifying the application.
</para>
		<example>
			<title>Examples:</title>
			<programlisting>
create procedure retry (in x integer)
{
  whenever sql state &apos;40001&apos; goto deal;
 again:
  -- action
  return;
 deadl:
   rollback work;
   goto again;
}

create trigger sal_negative on &quot;Employee&quot; after update (&quot;Salary&quot;)
{
  if (&quot;Salary&quot; &lt; 0) {
    rollback work;
    signal (&apos;A0001&apos;, &apos;Salary cannot be negative&apos;);
  }
}
</programlisting>
		</example>
		<tip>
			<title>See Also:</title>
			<para><link linkend="fn_txn_error">txn_error</link>, <link linkend="fn_txn_killall">txn_killall</link>, <link linkend="fn_signal">signal</link></para>
		</tip>
	</sect1>
	<!-- ======================================== -->
	<sect1 id="CHECKPOINT">
		<title>CHECKPOINT, SHUTDOWN Statement</title>
		<programlisting>
admin_statement
	: SHUTDOWN opt_log
	| CHECKPOINT opt_log
	| BACKUP opt_log
	;
</programlisting>
		<para>
The checkpoint is a point in the history of a database where all
the state is written on disk as a single, consistent image that contains all
the state committed so far and no uncommitted state.  A transaction log starts after a checkpoint
and contains the information to allow the recreation of the effect of transactions
committed since the checkpoint.  The checkpoint state and the transaction
log together allow recovering the database up to the last committed transaction.
</para>
		<para>
The CHECKPOINT statement forces a checkpoint to be made. Making the checkpoint
allows starting a new transaction log.
If no new log name is specified the old log is truncated to length 0 and reused
for logging transactions.  If the CheckpointAuditTrail option is enabled in
virtuoso.ini a new log will be started even if no new log is specified in the checkpoint
or shutdown statement.
</para>
		<para>
The SHUTDOWN statement performs a CHECKPOINT, and terminates the server upon
completion.
</para>
		<para>
BACKUP is an alternate notation for backup().
</para>
		<example>
			<title>Examples:</title>
			<programlisting>
checkpoint &apos;new.log&apos;;
backup &apos;bak.log&apos;;
shutdown &apos;new2.log&apos;;
</programlisting>
		</example>
		<para>
The above sequence of commands makes a checkpoint and starts logging subsequent
transactions into new.log.  The backup statement makes bak.log, which represents the state
prior to starting new.log.  The shutdown statement makes a new checkpoint and marks new2.log as the log
file to be used for logging transactions after the database restarts. The database server exits at the completion of the
SHUTDOWN statement.
</para>
		<programlisting>
replay (&apos;bak.log&apos;);
replay (&apos;new.log&apos;);
</programlisting>
		<para>
These statements executed on an empty database will recreate the state in effect after the last transaction
to commit before the SHUTDOWN statement of the previous example.
</para>

<tip><title>See Also</title>
<para>The <link linkend="backup">Backup section</link> for more backup and
recovery information.</para></tip>
                <example>
			<title>Example for control the transaction logging:</title>
			<programlisting><![CDATA[
create procedure log_test ()
{
  -- disable the transaction logging
  log_enable (0);

  -- action code, for ex.:
  delete from TAG_REL_INX;
  insert into TAG_REL_INX (TR_T1, TR_T2, TR_COUNT) select TR_T1, TR_T2, TR_COUNT from TAG_REL;

  exec('checkpoint');

  -- enable the transaction logging
  log_enable (1);
};
]]></programlisting>
		</example>

		<sect2 id="checkpointparams">
			<title>Checkpoint &amp; Page Remapping</title>
			<para>
In concept, making a checkpoint consists of writing the last committed
state of a page on the read-only pre-checkpoint state. This is in case
the page existed before the previous checkpoint.  If the page was
created after the last checkpoint, making the checkpoint consists of
just writing it to disk. Now if the number of pages modified between
checkpoints largely exceeds the amount of RAM, the checkpoint will be a
disk-to-disk copy process which takes a time proportional to the number
of modified pages.   This can take a long time. Virtuoso offers a
mechanism called checkpoint remap. This allows making a committed
state persistent, i.e. safe, without copying all the delta
collected since the last checkpoint over the pre-checkpoint state.
</para>
			<para>
The checkpoint remap mechanism means that a page, say number 12 get
remapped to 15 when updated. Suppose now that the page were written
to disk.  Now we have the pre-checkpoint page on 12 and the committed
post checkpoint state on 15. If a checkpoint now takes place, instead
of copying 15 over 12, which may involve reading the page, we just write
that 12 is actually on 15. This speeds up the checkpoint but causes one
page to take the space of 2. Now suppose 12 were modified again, now we
would see that the pre checkpoint page is 15 and that the original 12
is free. The page now gets mapped to 12.  The next checkpoint now will
mark that 12 is 12, which was the original condition and 15 is free.
</para>
			<para>
The mechanism is actually more complex but this is the basic idea. By
allowing a page to occupy two pages in some situations we dramatically
cut down on atomic checkpoint time and improve availability.
</para>
			<para>
Now we may argue that this destroys locality since pages that were
created contiguous are no longer that after an update.	This is why
there is also a mechanism called unremap. and there is an upper limit
to checkpoint remaps. If every page were updated between checkpoints,
they would alternately be in their original place or in a remote place
from which the next update-checkpoint combination would return them to
the original. Now this is not always the case.	Also there is not always
enough space to keep up to three copies of each page.  Therefore there
is an unremap mechanism and an upper limit to checkpoint remaps.
</para>
			<para>
The <parameter>MaxCheckpointRemap</parameter> parameter in the
<link linkend="VIRTINI">virtuoso.ini</link> file controls how many pages may
be stored on a page other than their logical page.  The
<parameter>UnremapQuota</parameter> parameter in the
<link linkend="VIRTINI">virtuoso.ini</link> file controls how many previously
remapped pages are unremapped each time a checkpoint is made.
</para>
			<para>
Having an unlimited MaxCheckpointRemap and zero UnremapQuota will cause
a checkpoint to consist exclusively of a flush of dirty buffers.
The downside is that a page can take the space of two for an unlimited
period of time and that original locality is not maintained. Setting
the maximum checkpoint remap to zero in such a situation causes the next
checkpoint to unremap all checkpoint remapped pages, restoring physical
sequence and freeing disk space.
</para>
<tip><title>See Also:</title>
<para>The <link linkend="tpcc">TPC C Benchmark</link> chapter for examples
of checkpoint remapping in use on test environments.</para></tip>

		</sect2>
	</sect1>

	<!-- ======================================== -->
	<sect1 id="spasviewsandtables">
		<title>Stored Procedures as Views &amp; Derived Tables</title>
		<para>
Virtuoso allows using a stored procedure result set in place of a table. A view may also be
defined as a stored procedure. This provides smooth integration to external
procedural logic in queries.
</para>
		<para>
When a procedure appears as a table, the procedure is called and its result set is inserted
into a temporary space. Processing continues from that point on as if the data came from a table.
</para>
		<para>
Queries involving procedure views or derived tables are subject to normal join order selection.
For this purpose it is possible to associate a cost to a procedure used in a procedure view or derived table.  
If the option (order) clause is given at the end of the select, joins  are done left to right.  If a procedure is in the leftmost
position in the from it will be called once for the query, if it is in the second position it will
be called once for every row of the leftmost table that passes selection criteria applicable
to it and so on.
</para>
		<para>
Procedures used as tables can get parameters from the query. These parameters are expressed in the containing select's where clause
as column = expression, where column is a parameter name of the procedure table.
</para>
		<para>
A procedure derived table is of the form:
</para>
		<programlisting>
q_table_name '(' column_commalist ')' '(' column_def_commalist ')' alias
</programlisting>
		<para>
The first column commalist is the parameter list. The second column_def_list is a
description of the result set, as in a CREATE TABLE statement.   The correlation name
alias is required if the procedure occurs as a derived table, with no view definition.
</para>
		<para>
A procedure view is declared as follows:
</para>

<programlisting>
CREATE procedure VIEW new_table_name
	AS q_table_name '(' column_commalist ')' '(' column_def_commalist ')'
</programlisting>

		<para>
The columns in the column definition list should correspond to the procedure's result
set columns.  The columns are explicit in the view so as to be able to interpret the view
definition and to be able to compile procedures and queries using the view before the
procedure itself is defined.  Thus the procedure need be defined only at time of execution,
not at time of definition.
</para>
		<para>
The meta-data returned by ODBC catalog calls for a procedure view will show the columns
as they were declared, just like a regular view. Procedure views are never updatable.
</para>

			<sect2 id="proctabparams">
			<title>Procedure Table Parameters</title>
			<para>
If there is a condition that is in the top level set of AND'ed conditions in the table
expression's WHERE clause and if it is an equality condition and if it references a
parameter of a procedure table and if the other side of the equality does not
reference the procedure table or a table to the right of it, then this condition is
considered a parameter.  This means that the condition is not actually evaluated
but rather that the other side of the equality is evaluated before calling the procedure
and that the value returned is passed to the procedure as an input parameter in the
position indicated by the name in the parameter list of the view or derived table.
</para>
			<para>
If the procedure table is referenced in an explicit join, as in outer or inner join syntax,
only equalities in the join condition (ON clause) are eligible to specify a parameter.
Equalities in the enclosing query's WHERE phrase will be considered tests on the results,
not parameters.
</para>
			<para>
The parameter names in the procedure view's or derived table's parameter list do not
have to be names in the output columns, although this will often be the case.  The
number of parameters in the parameter list in the view or derived table must match
that in the procedure definition but the names do not have to be the same.  Only input
parameters are supported.
</para>
			<para>
If a parameter is specified but no applicable predicate is found, a NULL value is passed.
</para>
</sect2>
			<sect2 id="proctabressets">
			<title>Procedure Table Result Sets</title>
			<para>
The result set is declared in the derived table or view. This should match the result_names
in the procedure but the former will take precedence on the latter. If an actual result row is
shorter than the declared set, the missing columns will default to NULL.
</para>
</sect2>
			<sect2 id="proctabsecurity">
			<title>Procedure Tables &amp; Security</title>
			<para>
Accessing a procedure as a table requires execute privileges on the procedure.
Privileges declared on the view are not checked.
</para>
</sect2>

			<sect2 id="proctabcost">
			<title>Procedure Table Cost and Join Order</title>
			<para>

The __cost declaration in a procedure definition can associate a cost
to a procedure.  This declaration is then used for assessing different
join orders.  Note that depending on the join order, some parameters
of a procedure table may or may not be available.  It is of the form
__cost (n1, n2,...), where each n is a literal number.  
The declaration can figure anywhere in the procedure's body as a regular statement. 
At least one
number is required. The first number is the one-time cost of calling
the procedure.  The second number is the number of result rows that
will be produced by the call, defaulting to 1.  The numbers from third
onwards correspond to the parameters of the procedure from left to right.  If a parameter
is NOT given or is NOT known because of join order, then the cost of
the single call and the result count will be multiplied by the number
corresponding to the parameter.  
</para>

<para>
Consider the declaration __cost (10,
3, 5);.  The procedure will take 10 units of time per call and produce
3 rows if the first parameter is known.  Otherwise it will take 50
units and produce 15 rows.  This is a rough way to specify the
selectivity of specifying a parameter versus not specifying it.  One
may liken this to specifying or not specifying conditions of a table's
columns.
</para>


<para>
The unit of cost is an internal abstract unit.  For purposes of scaling, selecting a single row from a table of 1000 on an exact match of an integer key is 3 units. The costs are shown by the explain function with a second argument of -5. 
</para>
</sect2>

			<sect2 id="proctablimits">
			<title>Limitations</title>
			<para>
There is no limitation to the number of rows in a procedure result set.  The temporary
storage takes place in the database similarly to a sorted ORDER BY.  Number of columns is
limited to the maximum number of columns in a real table. Total row size limit for tables and
ORDER BY intermediate results applies.
Blobs are allowed and do not count towards the row length limit.
</para>
</sect2>
			<sect2 id="procexamples">
			<title>Procedure Table Examples</title>

<programlisting>
create procedure n_range (in first integer, in  last integer)
{
  declare n, n2 integer;
  n := first;
  result_names (n, n2);
  while (n &lt; last){
    result (n, 2 * n);
    n := n + 1;
  }
}

select n, n2 from n_range (first, last) (n int, n2 int) n
	where first = 2 and last = 12;
</programlisting>

<para>
This returns a set of numbers from 2 to 11 and from 4 to 22.
</para>

<programlisting>
select a.n, b.n from n_range (first, last) (n int, n2 int) a,
    n_range (f2, l2) (n int, n2 int) b
  where first = 2 and last = 12 and f2 = a.n - 2 and l2 = a.n + 2;
</programlisting>

<para>
Here we join the second call to the procedure to the first, effectively passing
the output of the left call as parameters to the right call.
</para>

<programlisting>
create procedure view n_range as n_range (first, last) (n1 int, n2 decimal);
</programlisting>

<para>
This defines the procedure as a view, so that it can be referenced like a table.
</para>

<programlisting>
select * from n_range a, n_range b where a.first = 1 and a.last = 11
		and b.last = a.n1 + 2 and b.first = a.n1 - 2;
</programlisting>

<para>
This is the previous join but now using the view.
</para>
</sect2>
</sect1>

	<!-- ======================================== -->
	<!-- ======================================== -->
	<sect1 id="GRANT">
		<title>GRANT, REVOKE Statement</title>
		<programlisting>
privilege_def
	: GRANT ALL PRIVILEGES TO grantee
	| GRANT privileges ON table TO grantee_commalist opt_with_grant_option
	| GRANT grantee_commalist TO grantee_commalist opt_with_admin_option
	;

privilege_revoke
	: REVOKE ALL PRIVILEGES FROM grantee_commalist
	| REVOKE privileges ON table FROM grantee_commalist
	| REVOKE grantee_commalist FROM grantee_commalist
	;

opt_with_grant_option
	: /* empty */
	| WITH GRANT OPTION
	;

opt_with_admin_option
	: /* empty */
        | WITH ADMIN OPTION
 	;

privileges
	: ALL PRIVILEGES
	| ALL
	| operation_commalist
	;

operation_commalist
	: operation
	| operation_commalist &apos;,&apos; operation
	;

operation
	: SELECT priv_opt_column_commalist
	| INSERT
	| DELETE
	| UPDATE priv_opt_column_commalist
	| REFERENCES opt_column_commalist
	| EXECUTE
	| REXECUTE
	| role_name
	;

grantee_commalist
	: grantee
	| grantee_commalist &apos;,&apos; grantee

	;

grantee
	: PUBLIC
	| user
	;

user
	: IDENTIFIER

role_name
	: IDENTIFIER

</programlisting>
		<para>
The GRANT and REVOKE statements are used to define privileges on resources to
users and user groups (roles).  A resource is a table, view or stored procedure.  A grantee
can be PUBLIC, meaning any present or future user accounts or a user name.  Granting
a privilege to a user name means that this user AND any users which have this user as their
user group have the privilege.
</para>
		<para>
Only a granted privilege can be revoked. The sequence:
</para>
		<programlisting>
grant select on employee to public;
revoke select (e_review) from joe;
</programlisting>
		<para>
Is invalid because the privilege being revoked was not granted, instead
it was implied by the select on all column to public.
</para>
<para>
Any role name created by the CREATE ROLE statement is a valid grantee and a valid grantable operation.
</para>
		<para>
The term &apos;effective privilege of a user&apos; means the set of privileges
given to a user by virtue of 1. granting them to public 2. granting them to a role which is granted to the user or to a role either directly or indirectly granted to the user or 3. granting them, to the specific user.
The dba user and all users whose group is &apos;dba&apos; have all privileges.
</para>
		<para>
The phrase
</para>
		<programlisting>
GRANT ALL PRIVILEGES TO user;
</programlisting>
		<para>
is synonymous with setting the user&apos;s group to &apos;dba&apos;.
</para>
		<para>
The effective privileges inside a trigger are those of the owner of the
table whose trigger is executing. The privilege of executing a trigger is derived from the
privilege of performing the trigger action, e.g. update of a specific column.
</para>
		<para>
The effective privilege inside a stored procedure is that of the owner of the procedure.
The privilege to execute a given procedure is granted with the
EXECUTE clause.
</para>
		<note>
			<title>Note:</title>
			<para>The grantee names are identifiers. This means that their case
can be converted to upper case unless they are quoted. The identifier case
conversion depends on the global CaseMode setting.
</para>
		</note>
		<para>
A user may grant or revoke privileges on resources of which he/she is the owner.
A user with effective dba privileges may manipulate any privileges.
</para>
		<example>
			<title>Examples:</title>
			<programlisting>
grant update (&quot;Salary&quot;) on &quot;Employees&quot; to &quot;Manager&quot;;

grant execute on &quot;SalesReport&quot; to &quot;Accounting&quot;;
</programlisting>
		</example>
    <para><emphasis>GRANT REFERENCES</emphasis> is a privilege required by a
    user on a table so that this user can create new tables referencing such tables
    in foreign keys where he/she would otherwise be restricted.</para>

  <formalpara><title>Remote SQL Data Sources</title>
  <para>To provide further consistent security to remote data, only the DBA
  group is permitted to use the <function>rexecute()</function>, unless
  explicitly granted.  Caution is required here since any user granted use of
  <function>rexecute()</function> has full control of the remote data source
  set-up by the DBA, however limited to the overall abilities of the remote
  user on the remote data source.</para></formalpara>
  <para>Users can be granted and denied access to
  <function>rexecute()</function> using the following syntax:</para>

<programlisting><![CDATA[
GRANT REXECUTE ON '<attached_dsn_name>' TO <user_name>
REVOKE REXECUTE ON '<attached_dsn_name>' FROM <user_name>
]]></programlisting>


  <formalpara><title>UDTs</title>
  <para>Security of UDTs is maintained through normal SQL GRANT and REVOKE
  statements via a simple extension.  You can define the level of access to both native
  and externally hosted UDTs.  Grants for persistent user defined types
  are persisted into the SYS_GRANTS table.  Grants on temporary user defined
  types are in-memory only and are lost (together with the temporary user defined
  type definition) when the server is restarted.</para></formalpara>

  <para>There are two GRANT/REVOKE types for UDTs as follows:</para>

  <simplelist>
    <member><emphasis>EXECUTE</emphasis> - all methods and members of a class are accessible to the grantee.</member>
    <member><emphasis>UNDER</emphasis> - the grantee can create subclasses of the class.</member>
  </simplelist>

<programlisting><![CDATA[
GRANT/REVOKE EXECUTE on <user_defined_type>
GRANT/REVOKE UNDER on <user_defined_type>
]]></programlisting>

  <note><title>Note:</title>
    <para>SQL modules, user defined types and SQL stored procedures are exposed
	to GRANT/REVOKE in the same namespace, therefore care must be taken avoid
	inadvertently granting to multiple objects at the same time.</para></note>

<tip><title>See Also:</title>
  <para><link linkend="vdbSTOREDPROCS">Virtual Database Procedures &amp; Functions</link></para></tip>

	</sect1>
	<!-- ======================================== -->
	<sect1 id="SETstmt">
		<title>SET Statement</title>
		<sect2 id="isolation">
			<title>ISOLATION</title>
			<para>
This allows setting a transaction isolation in a stored procedure or trigger body.
The values are:</para>
  <simplelist>
    <member>uncommitted</member>
    <member>committed</member>
    <member>repeatable</member>
    <member>serializable</member>
  </simplelist>

<para>These are case insensitive strings.</para>
			<para>
This takes effect dynamically until replaced by another SET ISOLATION setting.
The effect never persists over the return of the containing procedure or trigger. The effect
does extend into procedures or triggers called from after executing the SET ISOLATION
statement.
</para>

<example id="ex_settingisolations"><title>Setting the isolation level</title>
<programlisting>
set isolation='serializable';
</programlisting>
</example>

			<para>
The initial isolation comes from the SQL_TXN_ISOLATION statement option in
the ODBC API (SQLSetConnectOption). The default isolation is repeatable read.
</para>
		</sect2>
		<sect2 id="lockescalation">
			<title>LOCK_ESCALATION_PCT</title>
			<para>
This controls the escalation from row locking to page locking.  A set of
row locks can be converted into one page lock if: (a) All the row locks on the
page belong to the same transaction, or, (b) No other transaction waits for any of these locks.
The value of this parameter is the percentage of rows on a page that must be held by
the transaction before the locking goes to page level. The default is 50, meaning that
for a page of 120 rows the 61st row lock will escalate the lock if all the previous
locks belong to the same transaction and there is no wait pending on any.
A value of -1 means that locking is always at page level if there is more
than one lock on the page.  A value in excess of 100 causes
lock escalation to be turned off. The effect of this setting is global and
persists until the server is restarted. This setting does not affect the semantic of
locking.
</para>
		</sect2>

		<sect2 id="transactiontimeout">
			<title>transaction_timeout</title>
			<para>

This allows setting a timeout for the current transaction.  The value
must be an integer count of milliseconds from the beginning of the
transaction.  The transaction is deemed to begin when the first
client statement executes inside it or, if the transaction starts from
a commit work or rollback work statement in PL, from the time of this statement.  If the transaction does not commit or rollback within so many milliseconds of its beginning, it is liable to get terminated, which is signalled to any code running inside the transaction as a SQL state S1T00.  When this is signalled the transaction is set into an uncommittable state and must be rolled back.  When the timeoutg elapses, all locks and uncommitted state belonging to the transaction are freed.
</para>
<para>
This setting remains in  effect until the transaction terminates.  Any timeout for a next transaction must be set separately.  This feature can be used for enforcing maximum running times on operations.  The timeout will take effect also if the transaction holds no locks.  This setting corresponds to the Virtuoso ODBC extension SQL_TXN_TIMEOUT statement option.o

</para>
		</sect2>

		<sect2 id="parambatch">
			<title>PARAM_BATCH</title>
			<para>
This sets the batch size used by the virtual database
array parameter optimization batch size.  This causes several
consecutive executes of the same statement to be grouped as a single ODBC operation
with array parameters. This optimizes joins of tables on different servers and searched
updates, inserts and deletes on attached tables.  Most ODBC drivers
do not support array parameters.  A value of 1 or 0 disables
the optimization. This should be done if there is a driver which falsely
claims to support array parameters.  If a given driver returns an error when setting
array parameters the VDB will detect this and will not try to use them.
</para>
			<para>
The effect of this setting is global and persists until the server is restarted.
The default value comes from the ArrayParameters configuration parameter.
</para>
		</sect2>
	</sect1>
<sect1 id="anytimequeries">
		<title>Anytime Queries</title>
     <para>Starting with version 6, Virtuoso offers a partial query evaluation feature that guarantees
answers to arbitrary queries within a fixed time. This is intended for use in  publicly available SPARQL
or SQL end points on large databases. This enforces a finite duration to all queries and will strive to
return meaningful partial results. Thus this provides the same security as a transaction timeout but will
be more user friendly since results will generally be returned, also for aggregate queries. Outside of a
public query service, this may also be handy when exploring a large data set with unknown properties.
</para>
<para>The feature is activated with the statement</para>
<programlisting><![CDATA[
set result_timeout == <expression>;
]]></programlisting>
     <para>The expression should be a count of milliseconds. The scope of the setting is the connection,
thus it remains in effect past the return of the calling procedure. Setting the timeout to 0 returns to the
default state of having no limit on query run time and always returning complete results. The initial value
of the timeout is 0. On a web server thread, the timeout is reset to 0 at the start of processing each
new request header.
</para>
<para>After a query or cursor has exceeded the running time, it is reset.
In the event of the reset occurring inside an aggregation, the part
of the query that produces rows for the aggregation is terminated, the
timeout is reset and the query continues by using the aggregated
results that were obtained before the first timeout. If there is
again a timeout, the present aggregation is reset and the query gets
another lease on life for processing the results accumulated so far.
Thus, a query which has a select, a group by and an order by can
consume at most three timeouts. One for producing the aggregated
rows, another for sorting them and finally a third for returning them
to a client or iterating over them in a stored procedure.
</para>
<para>If the timeout occurs outside an aggregation, the result set is simply truncated.</para>
<para>The fact of a query returning partial results is indicated by the
result set ending with a S1TAT SQL state. If the result set is read
to end without this state being signalled, the results are complete
and the query was not interrupted. If the result set is not consumed
to end, the client cannot be sure of its completeness.
</para>
<para>The error message associated with the S1TAT state contains the human
readable version of the output of db_activity () for the query. If
result_timeout is non-zero, the opening of a cursor or execution of a
query on a client connection or with the exec () function will reset
the client resource consumption counters automatically. This is done
so as to have the resource consumption statistics for the error
message scoped to the query. To get the exact counts, the application
may call db_activity (1) in the same procedure. If this is called on
a client server connection with the timeout on, the counts will be
reset before db_activity () is called.
</para>
     <para>The resolution of the timeout is fairly low, timeouts are checked every two seconds with default
settings.</para>
     <para>A query cannot set a timeout from inside itself. Only a stored procedure or a top level statement
on a client connection can do this.</para>
     <para>A request to SPARQL web service endpoint may specify the timeout as an additoional <emphasis>&amp;timeout=&lt;milliseconds&gt;</emphasis> parameter.
The parameter value should be equal to or greater than 1000, otherwise it will be ignored.
If <emphasis>SPARQL</emphasis> Virtuoso configuration file contains
<emphasis>MaxQueryExecutionTime</emphasis> parameter and its value is greater than or equal to 1000
then the actual &quot;anytime&quot; timeout is the minimum of the requested value and the value in the configuration file.
</para>
     <para>The current standard of SPARQL protocol does not provide any support for partial results.
When a SPARQL query ends with S1TAT state, the returned HTTP header contains four additional rows,
<emphasis>X-SQL-State:</emphasis>, <emphasis>X-SQL-Message:</emphasis>, <emphasis>X-Exec-Milliseconds:</emphasis> and
<emphasis>X-Exec-DB-Activity:</emphasis>; the returned document is formatted according to the requested MIME type as if the result is complete.</para>
 	</sect1>
<sect1 id="besteffortunion">
	<title>Best Effort Union</title>
	<para>
Virtuoso offers a SQL extension for an error tolerant UNION operation.
The idea is that when querying multiple remote data sources in a single union
construct some of the participating data sources may be allowed to fail while
still returning a result for the successfully queried data sources.
</para>
	<para>
The construct is introduced by the BEST keyword before UNION or UNION ALL. If a
query expression of multiple unions has a single BEST keyword the entire union chain
is considered as a best effort union.  It is however recommended to have the BEST
keyword in FROM of all the UNION keywords.
</para>
	<para>
When a run time error occurs during the evaluation of a term in a best effort union
the evaluation of the term is interrupted and the union continues with the next term.
The partial result set that may have been generated by the failed term is considered
when making the result.
</para>
	<para>
Aliasing constant columns selected in the terms of the union by the names __SQLSTATE,
__MESSAGE and __SET_NO retrieve individual error messages. If these are present and a union term
encounters an error an extra row is generated for the term with all NULLs and the __SQLSTATE,
__MESSAGE and __SET_NO columns set to the SQL state, SQL message and the union term number
respectively.  If neither of these is specified and a union term fails without producing any
result rows the error will not be visible.
</para>
<note><title>Note</title>
<para>No error encountered during a best effort union will be signalled in the normal fashion.
</para>
</note>

	<para>
If a term of a best effort union meets the criteria for a pass through query on a specific
remote database and a transaction error occurs when evaluating it, the transaction on the
VDB is not aborted as would normally happen as a result of a VDB transaction error.
</para>
	<para>
Thus if a pass through term dies of deadlock on its data source the query continues
normally for other data sources referenced in the best effort union.  The VDB will however
get the transaction error when attempting to commit the transaction where the best effort
union took place since the remote transaction branch will still be deadlocked.
</para>

	<example>
		<title>Examples</title>

		<programlisting>
select 2222, 1 / 0 from sys_users best union all select key_id, 1 / (1000 - key_id)  from sys_keys;
</programlisting>

		<para>
The first term will immediately hit the /0 error and will produce no rows. The second
term will produce a few rows for system tables but will hit /0 when getting to key_id 1001.
</para>

		<para>
To see the errors one can write:
</para>
		<programlisting>
select '00000' as __sqlstate, '' as __message, 2222, 1 / 0 from sys_users best union
all select '00000' as __sqlstate, '', key_id, 1 / (1001 - key_id)  from sys_keys;
</programlisting>
</example>

<note><title>Note</title>
<para>The columns are named by the first term, hence the AS declaration in
the second term is optional.
</para>
</note>

	<para>
The BEST keyword does not affect the ALL or CORRESPONDING BY options of UNION.
</para>
</sect1>

&aggregates;
&sqloptimizer;
&sqlinverse;


	<sect1 id="GRAMMAR">
		<title>SQL Grammar</title>
		<programlisting>
    sql_list
	    : sql &apos;;&apos;&#10;
	    | sql_list sql &apos;;&apos;&#10;
	    ;

    sql
	    : schema_element_list
	    | view_def
	    ;

    schema_element_list
	    : schema_element
	    | schema_element_list schema_element
	    ;

    schema_element
	    : base_table_def
	    | create_index_def
	    | drop_table
	    | drop_index
	    | add_column
	    | table_rename
	    | privilege_def
	    | privilege_revoke
	    | create_user_statement
	    | delete_user_statement
	    | set_pass
	    | set_group_stmt
	    ;

    base_table_def
	    : CREATE TABLE new_table_name &apos;(&apos; base_table_element_commalist &apos;)&apos;&#10;
	    ;

    base_table_element_commalist
	    : base_table_element
	    | base_table_element_commalist &apos;,&apos; base_table_element
	    ;

    base_table_element
	    : column_def
	    | table_constraint_def
	    ;

    column_def
	    : column data_type column_def_opt_list
	    ;

    references
	    : REFERENCES q_table_name opt_column_commalist
	    ;

    column_def_opt_list
	    : /* empty */
	    | column_def_opt_list column_def_opt
	    ;

    column_def_opt
	    : NOT NULLX
	    | IDENTITY
	    | NOT NULLX PRIMARY KEY opt_index_option_list
	    | DEFAULT literal
	    | references
	    ;

    table_constraint_def
	    : UNDER q_table_name
	    | PRIMARY KEY &apos;(&apos; index_column_commalist &apos;)&apos; opt_index_option_list
	    | FOREIGN KEY &apos;(&apos; column_commalist &apos;)&apos; references
	    ;

    column_commalist
	    : column
	    | column_commalist &apos;,&apos; column
	    ;

    index_column_commalist
	    : column opt_asc_desc
	    | index_column_commalist &apos;,&apos; column opt_asc_desc
	    ;

    index_option
	    : CLUSTERED
	    | UNIQUE
	    ;

    index_option_list
	    : index_option
	    | index_option_list index_option
	    ;

    opt_index_option_list
	    : /* empty */
	    | index_option_list
	    ;

    create_index_def
	    : CREATE opt_index_option_list INDEX index
		    ON new_table_name &apos;(&apos; index_column_commalist &apos;)&apos;&#10;
	    ;

    drop_index
	    : DROP INDEX NAME opt_table
	    ;

    opt_table
	    : /* empty */
	    | q_table_name
	    ;

    drop_table
	    : DROP TABLE q_table_name
	    ;

    add_col_column_def_list
	    : column_def
	    | add_col_column_def_list &apos;,&apos; column_def
	    ;

    add_col_column_list
	    : column
	    | add_col_column_list &apos;,&apos; column
	    ;

    add_column
	    : ALTER TABLE q_table_name ADD opt_col_add_column add_col_column_def_list
	    | ALTER TABLE q_table_name DROP opt_col_add_column add_col_column_list
	    | ALTER TABLE q_table_name MODIFY opt_col_add_column column_def
	    ;

    table_rename
	    : ALTER TABLE q_table_name RENAME new_table_name
	    ;

    view_def
	    : CREATE VIEW new_table_name opt_column_commalist
		    AS query_exp opt_with_check_option
	    ;

    opt_with_check_option
	    : /* empty */
	    | WITH CHECK OPTION
	    ;

    opt_column_commalist
	    : /* empty */
	    | &apos;(&apos; column_commalist &apos;)&apos;&#10;
	    ;

    priv_opt_column_commalist
	    : /* empty */
	    | &apos;(&apos; column_commalist &apos;)&apos;&#10;
	    ;

    privilege_def
	    : GRANT ALL PRIVILEGES TO grantee
	    | GRANT privileges ON table TO grantee_commalist opt_with_grant_option
	    | GRANT grantee_commalist TO grantee_commalist opt_with_admin_option
	    ;

    privilege_revoke
	    : REVOKE ALL PRIVILEGES FROM grantee_commalist
	    | REVOKE privileges ON table FROM grantee_commalist
	    | REVOKE grantee_commalist FROM grantee_commalist
	    ;

    opt_with_grant_option
	    : /* empty */
	    | WITH GRANT OPTION
	    ;

    opt_with_admin_option
	    : /* empty */
	    | WITH ADMIN OPTION
	    ;

    privileges
	    : ALL PRIVILEGES
	    | ALL
	    | operation_commalist
	    ;

    operation_commalist
	    : operation
	    | operation_commalist &apos;,&apos; operation
	    ;

    operation
	    : SELECT priv_opt_column_commalist
	    | INSERT
	    | DELETE
	    | UPDATE priv_opt_column_commalist
	    | EXECUTE
	    ;

    grantee_commalist
	    : grantee
	    | grantee_commalist &apos;,&apos; grantee
	    ;

    grantee
	    : PUBLIC
	    | user
	    ;

    set_pass
	    : SET PASSWORD NAME NAME
	    ;

    create_user_statement
	    : CREATE USER user
	    | CREATE ROLE user
	    ;

    delete_user_statement
	    : DELETE USER user [CASCADE]
	    | DROP ROLE user
	    ;

    set_group_stmt
	    : SET USER GROUP user user
	    ;

    cursor_def
	    : DECLARE NAME CURSOR FOR query_spec
	    ;

    opt_order_by_clause
	    : /* empty */
	    | ORDER BY ordering_spec_commalist
	    ;

    ordering_spec_commalist
	    : ordering_spec
	    | ordering_spec_commalist &apos;,&apos; ordering_spec
	    ;

    ordering_spec
	    : INTNUM opt_asc_desc
	    | column_ref opt_asc_desc
	    | function_ref opt_asc_desc
	    ;

    opt_asc_desc
	    : /* empty */
	    | ASC
	    | DESC
	    ;

    sql
	    : manipulative_statement
	    ;

    manipulative_statement
	    : query_exp
	    | update_statement_positioned
	    | update_statement_searched
	    | insert_statement
	    | delete_statement_positioned
	    | delete_statement_searched
	    | call_statement
	    | admin_statement
	    | use_statement
	    ;

    use_statement
	    : USE NAME
	    ;

    close_statement
	    : CLOSE cursor
	    ;

    delete_statement_positioned
	    : DELETE FROM table WHERE CURRENT OF cursor
	    ;

    delete_statement_searched
	    : DELETE FROM table opt_where_clause
	    ;

    fetch_statement
	    : FETCH cursor INTO target_commalist
	    ;

    insert_mode
	    : INTO
	    | REPLACING
	    | SOFT

    insert_statement
	    : INSERT insert_mode table priv_opt_column_commalist values_or_query_spec
	    ;

    values_or_query_spec
	    : VALUES &apos;(&apos; insert_atom_commalist &apos;)&apos;
	    | query_spec
	    ;

    insert_atom_commalist
	    : insert_atom
	    | insert_atom_commalist &apos;,&apos; insert_atom
	    ;

    insert_atom
	    : scalar_exp
	    ;

    cursor_option
	    : EXCLUSIVE
	    | PREFETCH INTNUM
	    ;

    cursor_options_commalist
	    : cursor_option
	    | cursor_options_commalist &apos;,&apos; cursor_option
	    ;

    opt_cursor_options_list
	    : /* empty */
	    | &apos;(&apos; cursor_options_commalist &apos;)&apos;&#10;
	    ;

    open_statement
	    : OPEN cursor opt_cursor_options_list
	    ;

    with_opt_cursor_options_list
	    : /* empty */
	    | WITH opt_cursor_options_list
	    ;

    select_statement
	    : SELECT opt_all_distinct selection table_exp
	    | SELECT opt_all_distinct selection
	    	INTO target_commalist table_exp with_opt_cursor_options_list
	    ;

    opt_all_distinct
	    : /* empty */
	    | ALL
	    | DISTINCT
	    ;

    update_statement_positioned
	    : UPDATE table SET assignment_commalist WHERE CURRENT OF cursor
	    ;

    assignment_commalist
	    : /* empty */
	    | assignment
	    | assignment_commalist &apos;,&apos; assignment
	    ;

    assignment
	    : column COMPARISON scalar_exp
	    ;

    update_statement_searched
	    : UPDATE table SET assignment_commalist opt_where_clause
	    ;

    target_commalist
	    : target
	    | target_commalist &apos;,&apos; target
	    ;

    target
	    : column_ref
	    ;

    opt_where_clause
	    : /* empty */
	    | where_clause
	    ;

    query_exp
	    : query_term
	    | query_exp UNION query_term
	    | query_exp UNION ALL query_term
	    ;

    query_term
	    : query_spec
	    | &apos;(&apos; query_exp &apos;)&apos;&#10;
	    ;

    query_spec
	    : SELECT opt_all_distinct selection table_exp
	    ;

    selection
	    : scalar_exp_commalist
	    ;

    table_exp
	    : from_clause opt_where_clause opt_group_by_clause opt_having_clause
		    opt_order_by_clause opt_lock_mode
	    ;

    from_clause
	    : FROM table_ref_commalist
	    ;

    table_ref_commalist
	    : table_ref
	    | table_ref_commalist &apos;,&apos; table_ref
	    ;

    table_ref
	    : table
	    | &apos;(&apos; query_exp &apos;)&apos; NAME
	    | joined_table
	    ;

    table_ref_nj
	    : table
	    | subquery NAME
	    ;

    opt_outer
	    : /* empty */
	    | OUTER
	    ;

    jtype
	    : LEFT
	    ;

    joined_table
	    : table_ref jtype opt_outer JOIN table_ref_nj ON search_condition
	    | BEGIN_OJ_X table_ref jtype opt_outer JOIN table_ref_nj
	      ON search_condition ENDX
	    ;

    where_clause
	    : WHERE search_condition
	    ;

    opt_group_by_clause
	    : /* empty */
	    | GROUP BY ordering_spec_commalist
	    ;

    opt_having_clause
	    : /* empty */
	    | HAVING search_condition
	    ;

    opt_lock_mode
	    : /* empty */
	    | FOR UPDATE
	    ;

    search_condition
	    : /* empty */
	    | search_condition OR search_condition
	    | search_condition AND search_condition
	    | NOT search_condition
	    | &apos;(&apos; search_condition &apos;)&apos;&#10;
	    | predicate
	    ;

    predicate
	    : comparison_predicate
	    | between_predicate
	    | like_predicate
	    | test_for_null
	    | in_predicate
	    | all_or_any_predicate
	    | existence_test
	    | scalar_exp_predicate
	    ;

    scalar_exp_predicate
	    : scalar_exp
	    ;

    comparison_predicate
	    : scalar_exp COMPARISON scalar_exp
	    | scalar_exp COMPARISON subquery
	    ;

    between_predicate
	    : scalar_exp NOT BETWEEN scalar_exp AND scalar_exp
	    | scalar_exp BETWEEN scalar_exp AND scalar_exp
	    ;

    like_predicate
	    : scalar_exp NOT LIKE scalar_exp opt_escape
	    | scalar_exp LIKE scalar_exp opt_escape
	    ;

    opt_escape
	    : /* empty */
	    | ESCAPE atom
	    | BEGINX ESCAPE atom ENDX
	    ;

    test_for_null
	    : column_ref IS NOT NULLX
	    | column_ref IS NULLX
	    ;

    in_predicate
	    : scalar_exp NOT IN subquery
	    | scalar_exp IN subquery
	    | scalar_exp NOT IN &apos;(&apos; scalar_exp_commalist &apos;)&apos;&#10;
	    | scalar_exp IN &apos;(&apos; scalar_exp_commalist &apos;)&apos;&#10;
	    ;

    all_or_any_predicate
	    : scalar_exp COMPARISON any_all_some subquery
	    ;

    any_all_some
	    : ANY
	    | ALL
	    | SOME
	    ;

    existence_test
	    : EXISTS subquery
	    ;

    subquery
	    : &apos;(&apos; SELECT opt_all_distinct selection table_exp &apos;)&apos;&#10;
	    ;

    scalar_exp
	    : scalar_exp &apos;+&apos; scalar_exp
	    | scalar_exp &apos;-&apos; scalar_exp
	    | scalar_exp &apos;*&apos; scalar_exp
	    | scalar_exp &apos;/&apos; scalar_exp
	    | &apos;+&apos; scalar_exp %prec UMINUS
	    | &apos;-&apos; scalar_exp %prec UMINUS
	    | atom
	    | column_ref
	    | function_ref
	    | &apos;(&apos; scalar_exp &apos;)&apos;&#10;
	    | &apos;(&apos; scalar_exp &apos;,&apos; scalar_exp_commalist &apos;)&apos;&#10;
	    | function_call
	    | as_expression
	    | assignment_statement
	    | cvt_exp
	    ;

    cvt_exp
	    : CONVERT &apos;(&apos; data_type &apos;,&apos; scalar_exp &apos;)&apos;&#10;
	    ;

    as_expression
	    : scalar_exp AS NAME data_type
	    | scalar_exp AS NAME
	    ;

    opt_scalar_exp_commalist
	    : /* empty */
	    | scalar_exp_commalist
	    ;

    function_call
	    : q_table_name &apos;(&apos; opt_scalar_exp_commalist &apos;)&apos;&#10;
	    | BEGIN_FN_X NAME &apos;(&apos; opt_scalar_exp_commalist &apos;)&apos; ENDX
	    | BEGIN_FN_X USER &apos;(&apos; opt_scalar_exp_commalist &apos;)&apos; ENDX
	    | BEGIN_FN_X CHARACTER &apos;(&apos; opt_scalar_exp_commalist &apos;)&apos; ENDX
	    | CALL &apos;(&apos; scalar_exp &apos;)&apos; &apos;(&apos; opt_scalar_exp_commalist &apos;)&apos;&#10;
	    ;

    obe_literal
	    : BEGINX NAME atom ENDX
	    ;

    scalar_exp_commalist
	    : scalar_exp
	    | scalar_exp_commalist &apos;,&apos; scalar_exp
	    ;

    atom
	    : parameter_ref
	    | literal
	    | USER
	    | obe_literal
	    ;

    parameter_ref
	    : parameter
	    | parameter parameter
	    | parameter INDICATOR parameter
	    ;

    function_ref
	    : AMMSC &apos;(&apos; &apos;*&apos; &apos;)&apos;&#10;
	    | AMMSC &apos;(&apos; DISTINCT scalar_exp &apos;)&apos;&#10;
	    | AMMSC &apos;(&apos; ALL scalar_exp &apos;)&apos;&#10;
	    | AMMSC &apos;(&apos; scalar_exp &apos;)&apos;&#10;
	    ;

    literal
	    : STRING
	    | INTNUM
	    | APPROXNUM
	    | NULLX
	    ;

    q_table_name
	    : NAME
	    | NAME &apos;.&apos; NAME
	    | NAME &apos;.&apos; NAME &apos;.&apos; NAME
	    | NAME &apos;.&apos;  &apos;.&apos; NAME
	    ;

    new_table_name
	    : NAME
	    | NAME &apos;.&apos; NAME
	    | NAME &apos;.&apos; NAME &apos;.&apos; NAME
	    | NAME &apos;.&apos;  &apos;.&apos; NAME
	    ;

    table
	    : q_table_name
	    | q_table_name AS NAME
	    | q_table_name NAME
	    ;

    column_ref
	    : NAME
	    | NAME &apos;.&apos; NAME
	    | NAME &apos;.&apos; NAME &apos;.&apos; NAME
	    | NAME &apos;.&apos; NAME &apos;.&apos; NAME &apos;.&apos; NAME
	    | NAME &apos;.&apos; &apos;.&apos; NAME &apos;.&apos; NAME
	    | &apos;*&apos;
	    | NAME &apos;.&apos; &apos;*&apos;
	    | NAME &apos;.&apos; NAME &apos;.&apos; &apos;*&apos;&#10;
	    | NAME &apos;.&apos; NAME &apos;.&apos; NAME &apos;.&apos; &apos;*&apos;&#10;
	    | NAME &apos;.&apos; &apos;.&apos; NAME &apos;.&apos; &apos;*&apos;&#10;
	    ;

    data_type
	    : CHARACTER
	    | VARCHAR
	    | VARCHAR &apos;(&apos; INTNUM &apos;)&apos;&#10;
	    | CHARACTER &apos;(&apos; INTNUM &apos;)&apos;&#10;
	    | NUMERIC
	    | NUMERIC &apos;(&apos; INTNUM &apos;)&apos;&#10;
	    | NUMERIC &apos;(&apos; INTNUM &apos;,&apos; INTNUM &apos;)&apos;&#10;
	    | DECIMAL
	    | DECIMAL &apos;(&apos; INTNUM &apos;)&apos;&#10;
	    | DECIMAL &apos;(&apos; INTNUM &apos;,&apos; INTNUM &apos;)&apos;&#10;
	    | INTEGER
	    | SMALLINT
	    | FLOAT
	    | FLOAT &apos;(&apos; INTNUM &apos;)&apos;&#10;
	    | REAL
	    | DOUBLE PRECISION
	    | LONG VARCHAR
	    | LONG VARBINARY
	    | TIMESTAMP
	    | DATETIME
	    | TIME
	    | DATE
	    | OWNER
	    ;

    column
	    : NAME
	    ;

    index
	    : NAME
	    ;

    cursor
	    : NAME
	    ;

    parameter
	    : PARAMETER
	    ;

    user
	    : NAME
	    ;

    opt_log
	    : /* empty */
	    | scalar_exp
	    ;

    comma_opt_log
	    : /* empty */
	    | &apos;,&apos; scalar_exp
	    ;

    admin_statement
	    : CHECKPOINT opt_log
	    | SHUTDOWN opt_log
	    | SET REPLICATION atom
	    | LOG OFF
	    | LOG ON
	    ;

    sql
	    : routine_declaration
	    | trigger_def
	    | drop_trigger
	    ;

    routine_declaration
	    : CREATE routine_head new_table_name rout_parameter_list
		opt_return compound_statement
	    ;

    routine_head
	    : FUNCTION
	    | PROCEDURE
	    ;

    opt_return
	    : /* empty */
	    | RETURNS data_type
	    ;

    rout_parameter_list
	    : &apos;(&apos; parameter_commalist &apos;)&apos;&#10;
	    ;

    parameter_commalist
	    : rout_parameter
	    | parameter_commalist &apos;,&apos; rout_parameter
	    ;

    rout_parameter
	    : parameter_mode column_ref data_type
	    ;

    parameter_mode
	    : IN
	    | OUT
	    | INOUT
	    ;

    routine_statement
	    : select_statement
	    | update_statement_positioned
	    | update_statement_searched
	    | insert_statement
	    | delete_statement_positioned
	    | delete_statement_searched
	    | close_statement
	    | fetch_statement
	    | open_statement
	    | commit_statement
    */
	    | &apos;;&apos;&#10;
	    ;

    compound_statement
	    : BEGINX statement_list ENDX
	    ;

    statement_list
	    : statement_in_cs
	    | statement_list statement_in_cs
	    ;

    statement_in_cs
	    : local_declaration &apos;;&apos;&#10;
	    | compound_statement
	    | routine_statement &apos;;&apos;&#10;
	    | control_statement
	    | NAME &apos;:&apos; statement
	    ;

    statement
	    : routine_statement &apos;;&apos;&#10;
	    | control_statement
	    | compound_statement
	    ;

    local_declaration
	    : cursor_def
	    | variable_declaration
	    | handler_declaration
	    ;

    variable_declaration
	    : DECLARE variable_list data_type
	    ;

    variable_list
	    : NAME
	    | variable_list &apos;,&apos; NAME
	    ;

    condition
	    : NOT FOUND
	    | SQLSTATE STRING
	    ;

    handler_declaration
	    : WHENEVER condition GOTO NAME
	    | WHENEVER condition GO TO NAME
	    ;

    control_statement
	    : call_statement &apos;;&apos;&#10;
	    | return_statement &apos;;&apos;&#10;
	    | assignment_statement &apos;;&apos;&#10;
	    | if_statement
	    | goto_statement &apos;;&apos;&#10;
	    | while_statement
	    ;

    assignment_statement
	    : lvalue EQUALS scalar_exp
	    ;

    lvalue
	    : column_ref
	    ;

    if_statement
	    : IF &apos;(&apos; search_condition &apos;)&apos; statement opt_else
	    ;

    opt_else
	    : /* empty */
	    | ELSE statement
	    ;

    call_statement
	    : CALL q_table_name &apos;(&apos; opt_scalar_exp_commalist &apos;)&apos;&#10;
	    | function_call
	    ;

    goto_statement
	    : GOTO NAME
	    | GO TO NAME
	    ;

    return_statement
	    : RETURN scalar_exp
	    | RETURN
	    ;

    while_statement
	    : WHILE &apos;(&apos; search_condition &apos;)&apos; statement
	    ;

    trigger_def
	    : CREATE TRIGGER NAME action_time event ON q_table_name
			    opt_old_ref compound_statement
	    ;

    action_time
	    : BEFORE
	    | AFTER
	    ;

    event
	    : INSERT
	    | UPDATE
	    | DELETE
	    ;

    opt_old_ref
	    : /* empty */
	    | REFERENCING old_commalist
	    ;

    old_commalist
	    : old_alias
	    | old_commalist &apos;,&apos; old_alias
	    ;

    old_alias
 	    : OLD AS NAME
 	    | NEW AS NAME
	    ;

    drop_trigger
	    : DROP TRIGGER q_table_name
	    ;
</programlisting>
	</sect1>
        <sect1 id="BITMAPINDICES">
		<title>Bitmap Indices</title>
        <para>
A bitmap index is a special type of index that is tailored for being efficient for key columns with relatively
few distinct values, i.e. low cardinality key columns. A bitmap index is created with the normal create index
statement by putting the bitmap keyword in front of index, as follows:
</para>
<programlisting>
create table customer (c_id int primary key, c_state char (2), c_gender char (1), .... );

create bitmap index c_gender on customer (c_gender);
create bitmap index c_state on customer (c_state);
</programlisting>
        <para>
Bitmap indices offer space savings of up to 1000 x in some cases and specially for large tables the savings in I/O can be very significant.
</para>
        <para>
A bitmap index can only be used on tables with an integer primary key or in other situations where the last effective key part of the
index is an integer. This is understandable since a bitmap index uses a bitmap for representing the values of the last key part,
thus having one bitmap for each distinct combination of leading key parts. In the above example, the customer table has an
integer c_id column as primary key and a character for the customer's gender and a 2 character field for the state where
the customer is located. Thus, to count all the male customers in Massachusetts, one will take the males bitmap and
the MA bitmap and perform a bitwise AND of the two. This will have a 1 bit corresponding to the c_id of each
male customer in Massachusetts.
</para>
        <para>
We also note that in order to do the count, the customer table itself does not even have to be referenced, as the
bitmaps hold all the information. Even if the table did have to be referenced, for example for adding up the
outstanding credit of all male customers in Massachusetts, the bitwise AND could be done first and only the relevant
rows would have to be retrieved from the table itself.
</para>
        <para>
Virtuoso's implementation of bitmap indices is designed to work efficiently even when the leading key parts have
relatively high cardinality, i.e. many distinct values, causing there to be a large number of mostly empty bitmaps.
Of course, if each bitmap has only one bit set, for example if every customer is in a different state, there is no
benefit to bitmap indices. On the other hand, there is also almost no penalty, only 6 bytes more per index entry
than for a regular index. Therefore, for any non-unique key where bitmap indices are applicable, even if there
are only a few repeated values, bitmap indices are a safe choice. If there are at least 2 times more rows than
distinct values of the keys, space savings are certain.
</para>
        <para>
A bitmap index may have any number of key parts of any type, provided that the last effective part is an integer or and IRI id.
The last key parts of an index are those primary key parts that do not occur elsewhere in the key. Thus, if the primary key is
a single integer, bitmap indices are always applicable. However, supposing the primary key were an integer plus a string,
it would be possible to make a bitmap index where the string were first, followed by the integer. This would make sense and
save space if the string were not unique by itself.
As another example, the RDF_QUAD system table, the default location of the Virtuoso RDF triple store, has the columns P, G, O and S,
where all are IRI ID's, except for O which is ANY. Thus, The primary key is the concatenation of all columns, by default in
the order GSPO. There is another key in the order PGOS which can be implemented as a bitmap index because S is an IRI ID,
hence integer-like for purposes of bitmap indices.
</para>
		<sect2 id="bitmapindandtrans">
			<title>Bitmap Indices and Transactions</title>
        <para>
The minimum locking unit is the row. In the case of a bitmap index, one row holds a bitmap which most often refers to many rows.
Locking is therefore less granular than with regular indices. Thus, if multiple threads insert rows with bitmap indices,
more waits may occur than if the index were not bitmapped. A single row of a bitmap index references maximally 8192 other
rows, most often however the count is much less.
</para>
        <para>
In all other respects, locking and transactional behavior are identical with other indices.
</para>
</sect2>
                <sect2 id="bitmapindandperfmimpl">
			<title>Performance Implications</title>
        <para>
The main advantage of a bitmap index is more compact size, reflected in less I/O. Inserting an entry takes on the average
10% longer than for another type of index, likewise for random lookups with exact key values. Sequential access is usually faster.
Space savings and thereby improved working set behavior can produce dramatic gains for large tables.
</para>
</sect2>
                <sect2 id="physicalstroverheads">
			<title>Physical Structure and Overheads</title>
        <para>
Bitmap indices divide the range of signed 64 bit integer values into ranges holding 8192 (8K) values. Each such range where at least
one bit is set is represented by a compression entry (CE). Multiple CE's can be on the same row. CE's having one bit set take 4
bytes, CE's with 512 or less bits set take 4 bytes plus 2 bytes per bit, CE's with over 512 bits set take 1K byte regardless of how
many bits are set.
</para>
        <para>
A bitmap index where the bitmap holds only one bit takes 6 bytes more than the corresponding non-bitmap index entry.
A second value, if it falls in the same 8K range adds 2 bytes, 4 bytes if it does not fall within in the same 8K range.
If more than 512 values fall within the same 8K range, the bits are represented as a 1K byte bitmap and adding subsequent
values takes no extra space.
</para>
        <para>
Virtuoso supports bitmap indices since version 4.5.2919.
</para>
        <para>
Bitmap Indices
</para>
</sect2>
</sect1>
<!-- Uncommented for Virtuoso 6 Release-->
<sect1 id="transitivityinsQL">
		<title>Transitivity in SQL</title>
<para>Virtuoso SQL supports tree and graph data structures represented with SQL relations through the use of transitive subqueries.</para>
<para>A derived table, i..e. a select inside a from clause, can be declared to be transitive. This is done by putting the TRANSITIVE modifier after the SELECT keyword, at the place where a DISTINCT or TOP modifier would go.</para>
<para>The syntax of this is:</para>
<programlisting><![CDATA[
transitive_decl ::= TRANSITIVE <trans_option>[, ...]

trans_opt :: =
        | T_MIN (INTNUM)
        | T_MAX (INTNUM)
        | T_DISTINCT
        | T_EXISTS
| T_NO_CYCLES
| T_CYCLES_ONLY
        | T_NO_ORDER
        | T_SHORTEST_ONLY
        | T_IN <position_list>
| T_OUT ( <position_list )
        | T_END_FLAG  (INTNUM)
        | T_FINAL_AS NAME
        | T_STEP ( <position_or_path_spec> )
        | T_DIRECTION (INTNUM)


position_list ::=  INTNUM [,...]

position_or_path_spec ::= INTNUM | 'step_no' | 'path_id'
]]></programlisting>
<para>A transitive derived table has a selection that may consist of four different types of columns. These are input, output, step data and special columns.
When a transitive derived table occurs in a query, the enclosing query must specify an equality condition for either all input, all output columns or both.
The designation of input and output columns is for convenience only. The order of query execution will be generally decided by the optimizer, unless overridden with the T_DIRECTION option.
</para>
<para>Consider a simplified social network application:</para>
<programlisting><![CDATA[
create table knows (p1 int, p2 int, primary key (p1, p2))
alter index knows on knows partition (p1 int);
create index knows2 on knows (p2, p1) partition (p2 int);

insert into knows values (1, 2);
insert into knows values (1, 3);
insert into knows values (2, 4);

]]></programlisting>
<para>All persons have single integer identifiers. There is a row in the knows table if person p1 claims to know person p2.</para>
<para>The most basic query is to find all the people that a given person knows either directly or indirectly.</para>
<programlisting><![CDATA[
select * from (select transitive t_in (1) t_out (2) t_distinct  p1, p2 from knows) k where k.p1 = 1;
]]></programlisting>
<para>The transitive derived table simply selects from the knows table. The
enclosing top level query gives an initial value for the input column
of the transitive select. This leaves the output column P2 unbound,
so the query will iterate over the possible values of P2. Initially,
the query loops over the people directly known by 1. In the next
stage, it takes the binding of P2 and uses it as a new value of the
input column P1 to look for people the first degree contact knows and
so on, until no new values are found.</para>
<para>The basic meaning of the transitive modifier is that given initial
values for input column(s), the subquery is evaluated to produce
values for the output columns. Then these values are fed back as
values of input columns and so forth, until some termination condition
is reached. If there are equality conditions for columns designated as output
but no conditions for columns designated as input, then the same
process runs from output to input. The terms input and output do not
imply execution order. If there are bindings for both input and
output columns in the enclosing query, then the transitive derived
table looks for ways of connecting the input and output bindings. If
no such way is found, the subquery is empty and causes the whole
enclosing query to also have no result. A transitive derived table
cannot be the right side of an outer join directly but can be wrapped
in a derived table that is. In this way, an outer join usage is also
possible, whether finding a path is optional.</para>
<para>The result set of a transitive subquery can be thought of as a set of
paths. A path consists of one or more consecutive bindings for the
input columns and is ordered. In our example, a path is p1=1, p1=2,
p1=4. This is the path connecting persons 1 and 4. If there are
columns in the select that are neither input or output, they too are
recorded for each step of the path. The result set may include just
the ends of a path, i.e. one row where the input columns have the
beginning and the output columns the end of the path. This means there is one row per distinct path. The result set may also include a row for each step on each path.
</para>
<para>In this example, we bind both ends of the transitive subquery and ask how person 1 and 4 are connected.
Since the columns p1 and p2 have an equality condition, each row of the result set has these at values 1 and 4 respectively.
</para>
<programlisting><![CDATA[
select * from (select transitive t_in (1) t_out (2) t_direction 3 t_distinct t_shortest_only  p1, p2, t_step (1) as via, t_step ('path_id') as path , t_step ('step_no') as step from knows) k where p1 = 1 and p2 = 4;

P1       P2       VIA                                                                               PATH                                                                              STEP

1        4        1                                                                                 0                                                                                 0
1        4        2                                                                                 0                                                                                 1
1        4        4                                                                                 0                                                                                 2
]]></programlisting>
<para>The three rightmost columns allow returning information in the intermediate steps of the transitive evaluation. t_step (1) means the value of the column at position 1 at the intermediate step. The t_step ('step_no) is the sequence number of the step returned. The t_step ('path_id') is a number identifying the connection path, since there may be many paths joining persons 1 and 4.</para>
<para>In this situation, the result set has one row per step, including a
row for the initial and final steps. While the evaluation order may
vary internally, the result set is presented as if the query were
evaluated from input to output, i.e. looking for people known by 1,
finding 2 and 3, then looking for people they know, finding that 2
knows 4, which is a  solution, since p2 = 4 was specified in the outer select.
If the outere query had p1 = 4 and p2 = 1, there would be an empty result set
since there is no path from 4 to 1.
</para>
<para>For example, if tables have multipart keys, there can be many input and output columns but there must be an equal number of both, since the engine internally feeds the output back into the input or vice versa. The transitive derived table may be arbitrarily complex.</para>
<para>We may have an application that returns extra information about a
step. This could for example be a metric of distance. In such a
case, a column which is neither designated as input nor output and is
not a t_step () function call, will simply be returned as is.
</para>
<para>The result set of a transitive subquery will either have one row for each state reached, or it may have one row for each step on the path to each state reached.</para>
<para>The first example returns only the ends of the paths, i.e. directly and indirectly known person id's. It does not return for each returned id how this person is known, through which set of connections.
The second example returns a row for each step on each path.
Steps will be returned if the selection has t_step () calls or columns that are neither input or output.
</para>
<para>The forms of t_step are:</para>
<programlisting><![CDATA[
t_step (<column number>)
]]></programlisting>
<para>This returns the value that the column, one of the columns designated
as input, has at this step. The input or output columns themselves, if
there is a condition on them, look equal to the condition. This
allows seeing intermediate values of input columns on a path.
</para>
<programlisting><![CDATA[
]]></programlisting>
<para>t_step ('step_no')</para>
<para>This returns the ordinal number of the step on the path. Step -0 corresponds to the input variables being at the value seen in the enclosing query. Step 1 is one removed from this. Step numbering is assigned as if evaluating from input to output.</para>
<para>Consider this:</para>
<programlisting><![CDATA[
select * from (select transitive t_in (1) t_out (2) t_min (0) t_distinct   p1, p2, t_step (1) as via, t_step ('path_id') as path , t_step ('step_no') as step from knows) k where p1 = 1 ;
P1       P2       VIA                                                                               PATH                                                                              STEP

1        1        1                                                                                 0                                                                                 0
1        3        1                                                                                 1                                                                                 0
1        3        3                                                                                 1                                                                                 1
1        2        1                                                                                 2                                                                                 0
1        2        2                                                                                 2                                                                                 1
1        4        1                                                                                 3                                                                                 0
1        4        2                                                                                 3                                                                                 1
1        4        4                                                                                 3                                                                                 2

]]></programlisting>
<para>This returns four paths, all starting at 1: the paths. The path from
1 to 1, the path from 1 to 2, the path from 1 to 3 and the path from 1
to 2 to 4. The path_id column has values from 0 to 3, distinguishing
the four different paths returned. The p1 column is the start of the
path, thus always 1 since this is given in the outer query. The p2
column is the end of the path. The via column is the value of p1 at
the intermediate step. The step number where via is equal to p1 is 0.
The next step number is 1. At the highest step number of each path,
p2 and via are the same.</para>
<para>Now, let us do this in reverse:</para>
<programlisting><![CDATA[
select * from (select transitive t_in (1) t_out (2) t_min (0) t_distinct   p1, p2, t_step (1) as via, t_step ('path_id') as path , t_step ('step_no') as step from knows) k where p2 = 4 ;
P1       P2       VIA                                                                               PATH                                                                              STEP


4        4        4                                                                                 0                                                                                 0
2        4        2                                                                                 1                                                                                 0
2        4        4                                                                                 1                                                                                 1
1        4        1                                                                                 2                                                                                 0
1        4        2                                                                                 2                                                                                 1
1        4        4                                                                                 2                                                                                 2

]]></programlisting>
<para>We give an initial value to p2 and leave p1 free. Now we get three
paths, the path from 4 to 4, from 2 to 4 and from 1 to 2 to 4. We
enumerate the steps as if counting from input to output, albeit
internally the evaluation order is the reverse. Again, step number 0
has the via column equal to p1 and the highest numbered step has via
equal to p2.</para>
<para>Now we may look more formally at the meaning of the transitive options:</para>
<itemizedlist>
<listitem>T_MIN (INTNUM) - This means that paths shorter than the number are not returned. In the examples above, we had min at 0, so that a path of zero length was also returned, i.e. where the first output equals the outer conditions for the inputs.</listitem>
<listitem>T_MAX (INTNUM) - This gives a maximum length of path. Paths longer than this many steps are not returned. A value of 1 means that the subquery is evaluated once, i.e. the outputs of the first evalyuation are not fed back into the inputs. Specifying a minimum of 0 and a maximum of one means an optional join. Specifying min and max both to 1 means an ordinary derived table.</listitem>
<listitem>T_DISTINCT - This means that if a binding of input columns is produced more than once, only the first is used. Id est, the same point is not traversed twice even if many paths lead to it.</listitem>
<listitem>T_EXISTS - Only one path is generated and returned.</listitem>
<listitem>T_NO_CYCLES - If a path is found that loops over itself, i.e. a next step has the input values equal to the input values of a previous step on the path, the binding is ignored.</listitem>
<listitem>T_CYCLES_ONLY - Only paths that have a cycle, i.e. input values of a subsequent step equal the input values of a previous step on the same path, are returned.</listitem>
<!-- listitem>T_NO_ORDER</listitem-->
<listitem>T_SHORTEST_ONLY -  If both ends of the path are given, the evaluation stops at the length of path where the first solution is found. If many paths of equal length are found, they are returned but longer paths are not sought.</listitem>
<listitem>T_IN (column_positions) - This specifies which columns are called input.</listitem>
<listitem>T_OUT (column_positions) - This specifies which columns are called output.</listitem>
<!-- listitem>T_END_FLAG</listitem-->
<!-- listitem>T_FINAL_AS</listitem-->
<!-- listitem>T_STEP</listitem-->
<listitem>T_DIRECTION INTNUM - A value of 0 (default) means that the SQL
optimizer decides which way the transitive subquery is evaluated. 1
means from input to output, 2 from output to input, 3 from both ends. Supposing we are looking at how two points are related, it makes sense to start expanding the transitive closure at both ends. in the above example, this would be going from p1 to p2 on one side and from p2 to p1 on the other.
</listitem>

<!-- listitem>neither in nor out. If this column has a non-0 value, this is considered as end of a path. This allows application logic other than column equality to decide when a solution has been reached.</listitem -->

</itemizedlist>
 <tip><title>See Also:</title>
    <link linkend="rdfsparqlimplementatiotransexamples">Collection of Transitivity Option Demo Queries for SPARQL.</link>
  </tip>
</sect1>
<sect1 id="sqlreffastphrasematch"><title>Fast Phrase Match Processor</title>
  <para>An "annotation phrase" is a keyword or key phrase associated with some application specific data
and a uniform "annotation phrase set" may map dictionary words to their descriptions or ICAO codes
to airport names and co-ordinates or geographical names to maps or Wikipedia topics to links to
Wikipedia pages. An application may need to scan a given text and find all occurrences of phrases
from given phrase set, for various purposes, e.g., to improve the resource with additional hyperlinks,
to replace technical codes with user-friendly names, or to suggest appropriate tags and keywords.
Virtuoso has built-in phrase match processor that is fast enough to deal with long documents and big
phrase sets in interactive applications.</para>
  <sect2 id="sqlreffastphrasematchscl"><title>Phrases, Phrase Sets and Phrase Classes</title>
  <para>An annotation phrase is a pair of a key (a string that is supposed to be a word or phrase of some
natural language) and a value (of any type if its serialization is shorter than 2 kilobytes or a
string shorter than 10 megabytes). The key phrase will be divided into words and normalized by
language-specific functions used by free text search; after normalization it should contain from one
to four words. The associated value may be very long in principle, but it will add noticeable
overheads related to memory allocation and copying so it is recommended to keep it short if
performance is somehow important. It is usual to make the value as short as an ID in some external
"detailed" table, not only for speed but to support multiple synonyms for one thing or names of a
thing in different languages.</para>
  <para>Annotation phrases are grouped in "phrase sets" and every "phrase set" belongs to
some "phrase class".</para>
  <para>Phrase classes are enumerated in a DB.DBA.SYS_ANN_PHRASE_CLASS table.</para>
<programlisting><![CDATA[
create table DB.DBA.SYS_ANN_PHRASE_CLASS
(
  APC_ID integer not null primary key,
  APC_NAME varchar(255) unique,		-- unique name for use in API/UI
  APC_OWNER_UID integer,		-- references SYS_USERS (U_ID), NULL if the record writable for any reader
  APC_READER_GID integer,		-- references SYS_USERS (U_ID), NULL if the record is readable for public
  APC_CALLBACK varchar,
  APC_APP_ENV any
  )
;
]]></programlisting>
  <para>Phrase sets and phrase classes may contain confidential information. E.g., a phrase set may be used
to check that a given outgoing document does not mention titles of confidential projects or names of
persons that should act anonymously for public. So any application may specify access restrictions
when a phrase class is created. The application usually sets APC_CALLBACK to name of some of its
functions (but it may be any string) and APC_APP_ENV to value of any type (application may pass it
to the APC_CALLBACK function as one of arguments). Phrase match processor only keeps these data in
memory, unchanged, and returns to the application as a part of text processing report, so they can
be used for any purpose.
</para>
  <para>Phrase class describes an access to some application-specific callback, but it does not mention any
phrases at all. Individual phrases are grouped into phrase sets. Each phrase set belongs to exactly
one phrase class and is restricted to one language handler. It does not necessarily mean that it should
consist of phrases of one natural language, because many language handlers support mix of languages,
but it may apply some restrictions.</para>
  <para>Phrase sets are enumerated in a DB.DBA.SYS_ANN_PHRASE_SET table.</para>
<programlisting><![CDATA[
create table DB.DBA.SYS_ANN_PHRASE_SET
(
  APS_ID integer not null primary key,
  APS_NAME varchar(255) unique,		-- unique name for use in API/UI
  APS_OWNER_UID integer,		-- references SYS_USERS (U_ID), NULL if the record writable for any reader
  APS_READER_GID integer,		-- references SYS_USERS (U_ID), NULL if the record is readable for public
  APS_APC_ID integer not null,		-- references SYS_ANN_PHRASE_CLASS (APC_ID)
  APS_LANG_NAME varchar not null,	-- name of language handler that is used to split texts of phrases
  APS_APP_ENV any,
  APS_SIZE any,				-- approximate number of phrases inserted in the set (actual or estimate for future)
  APS_LOAD_AT_BOOT integer not null	-- flags whether phrases should be loaded at boot time.
  )
;
]]></programlisting>
  <para>APS_APP_ENV can be of any type (application may pass it to the APC_CALLBACK function as one
of arguments). Like APC_APP_ENV, phrase match processor only keeps it in memory and returns in a text
processing report.</para>
  <para>The APS_SIZE tweaks the amount of memory consumed by a phrase set when it's loaded. The average "price"
of placing a phrase to a set is 2 bytes per phrase. Memory amounts are less than a kilobyte while APS_SIZE
is below 256, less than 64 kilobytes while APS_SIZE grow up to 32 thousands of phrases and reaches its
maximum of 64 megabytes when APS_SIZE reaches its practical limit of 32 million phrases. Only rough
similarity to the actual number of inserts is needed, say, same order of magnitude. The exaggerated value
of APS_SIZE will allocate a bit more memory and may slightly improve the speed. It is not practical to
set APS_SIZE much smaller than it should be because it will cause frequent table lookups and disk buffers
in use will overweight any memory savings in the phrase match processor. If there are numerous phrase sets
that are used only occasionally, do not decrease APS_SIZE, instead set APS_LOAD_AT_BOOT to zero for them.</para>
  <para>Note that if phrase set is edited intensively during server run then the number of inserted phrases is
important, an effect of phrase removal is visible only after server restart. E.g. if a phrase set is
frequently cleaned and refilled with new phrases then it is much better to delete an obsolete set and
create a new one.</para>
  <para>Individual annotation phrases are stored in a table DB.DBA.SYS_ANN_PHRASE, that should not be modified
by applications directly by data manipulation statements. The content of the table is used to build
special search structures in memory and SQL operations like INSERT and DELETE can not keep in-memory
structures in sync with the content of the table. DBA may read the table but should not update; in
case of occasional update all phrase sets that contain edited phrases may become unusable until server
restart.</para>
<programlisting><![CDATA[
create table DB.DBA.SYS_ANN_PHRASE
(
  AP_APS_ID integer not null,		-- references SYS_ANN_PHRASE_SET (APS_ID),
  AP_CHKSUM integer,			-- phrase check-sum
  AP_TEXT varchar,			-- original text
  AP_LINK_DATA any,			-- Associated data about links etc.
  AP_LINK_DATA_LONG long varchar,	-- Same as AP_LINK_DATA but for long content, one of two is always NULL
  primary key (AP_APS_ID, AP_CHKSUM, AP_TEXT)
  )
;
]]></programlisting>
  <para>The "almost direct" way of writing to the table is via BIF
<link linkend="fn_ann_phrase_class_add"><function>ap_add_phrases</function></link>.
It gets two arguments, the
integer ID of annotation phrase set and a vector of descriptions of phrases that should be edited in that
phrase set. Every item of vector of descriptions is in turn vector of one or two values; first value is
the text of the phrase, second value is associated application specific data, the absence of second value
indicates that the phrase should be removed. If same text of phrase appears in the vector of description
more than once, and associated data differ then any version of data can be stored for future use; it is
the roll of dice because the vector is reordered for faster processing.</para>
  </sect2>
  <sect2 id="sqlreffastphrasematchapi"><title>Phrase Set Configuration API</title>
<itemizedlist mark="bullet">
  <listitem><link linkend="fn_ann_phrase_class_add"><function>DB.DBA.ANN_PHRASE_CLASS_ADD</function></link></listitem>
  <listitem><link linkend="fn_ann_phrase_class_del"><function>DB.DBA.ANN_PHRASE_CLASS_DEL</function></link></listitem>
  <listitem><link linkend="fn_ap_build_match_list"><function>AP_BUILD_MATCH_LIST</function></link>:
The report R is a vector of 6 elements:
<orderedlist>
  <listitem>R[0] vector of all distinct phrase classes for phrase sets of found phrases; every pair of
items represents one phrase class: first item is an integer APC_ID of a class, second item is a description
of phrase class as vector of APC_NAME, APC_CALLBACK and APC_APP_ENV;</listitem>
  <listitem>R[1] vector of all distinct phrase sets of found phrases; every pair of items represents
one phrase set: first item is an integer APS_ID of a class, second item is a vector of APS_NAME, APS_APC_ID,
index of phrase class description in R[0] and APS_APP_ENV;</listitem>
  <listitem>R[2] vector of all distinct found phrases; every item represents a phrase as a vector of
AP_APS_ID, index of phrase set description in R[1], AP_TEXT and application-specific data from
AP_LINK_DATA or AP_LINK_DATA_LONG;</listitem>
  <listitem>R[3] vector of all composed arrows for the text; every item represents one place in a text, as an "arrow" described below;</listitem>
  <listitem>R[4] vector of indexes of arrows that point to words in the text; every item is an integer that is index in R[3];</listitem>
  <listitem>R[5] vector of descriptions of occurrences of annotation phrases in text; every item
represents one occurrence as vector of index of first word in R[3], index of last word in R[3], index of
found phrase in R[2], index of previous occurrence of same phrase in R[5].</listitem>
<para>Every "arrow" A is vector of length 5 or 6, it is longer when arrow points inside occurrence of some
annotation phrase.
</para>
<orderedlist>
  <listitem>A[0] integer that indicates type of text fragment:
<itemizedlist mark="bullet">
  <listitem>0 is for plain word (only this type occurs in reports for plain text),</listitem>
  <listitem>1 is for text of opening tag,</listitem>
  <listitem>2 is for text of closing tag,</listitem>
  <listitem>3 is something exceptional like unrecoverable HTML syntax error</listitem>
</itemizedlist>
</listitem>
  <listitem>A[1] integer offset of the first byte of a fragment in the text</listitem>
  <listitem>A[2] integer offset of the first byte after the end of a fragment</listitem>
  <listitem>A[3] integer that is a bit-mask of opened but not yet closed tags</listitem>
  <listitem>A[4] integer index of the arrow of the innermost tag that is opened but
not yet closed where the arrow begins</listitem>
  <listitem>A[5] may absent, if presents then it is a vector of indexes in R[2] of all containing phrases.</listitem>
</orderedlist>
<para>Bit mask of opened but not yet closed tags consists of the following bits:
</para>
<programlisting><![CDATA[
0x00000001	PCDATA containers (such as OPTION, TEXTAREA, XBODY, XHEAD)
0x00000002	Inlined highlight tags (such as ABBR, ACRONYM, B, BDO, BIG, CITE, CODE, DFN, EM, FONT, I, KBD, Q, S, SAMP, SMALL, SPAN, STRIKE, STRONG, SUB, SUP, TT, U)
0x00000004	Tag A
0x00000008	Tag LABEL

0x00000010	Inlined content (such as ADDRESS, APPLET, H1-H6, LABEL, LEGEND, P, PRE, and all blocks of content except MAP)
0x00000020	Blocks (such as BLOCKQUOTE, BUTTON, DD, DIV, DL, DT, FIELDSET, FORM, IFRAME, LI, NOFRAMES, NOSCRIPT, OBJECT, TABLE, TBODY, TD, TFOOT, TH, THEAD, TR, XBODY, XHEAD)

0x00000100	Tags of list and ordered list (MENU, OL, UL)
0x00000200	Tag LI
0x00000400	Tag DL
0x00000800	Tags DD and DT

0x00001000	Tag FORM
0x00002000	Tag SELECT
0x00004000	Tag OPTGROUP
0x00008000	Tag BUTTON

0x00010000	Tag TABLE
0x00020000	Tags inside TABLE but outside table rows (such as TBODY, TFOOT, THEAD)
0x00040000	Tag TR
0x00080000	Tags TH and TD

0x00FFFFFF	Tags XBODY and XHEAD

0x01000000	Tag HEAD
0x02000000	Tag FRAMESET
0x04000000	Tag NOFRAMES

0x10000000	Tag HTML
0x20000000	Tag BODY
0x40000000	Tags INS and DEL
0x80000000	Tag XMP
]]></programlisting>
<para>For long document, the report may be too long, esp. vectors R[3] and R[4].
A simple application may not need locations of every tag and every word of the document.
The report_flags argument is a bitmask, and some bits control the size of the report.
If bit 1 is set then closing tags are excluded from report.
If bit 2 is set then only words in found phrase are placed to the report, the rest of phrases is excluded.
</para>
</orderedlist>
</listitem>
</itemizedlist>
  </sect2>
  <sect2 id="sqlreffastphrasematchsadv"><title>Advertisers and Advertisement Rules</title>
  <para>Phrase sets are sufficient for many purposes but advertisement-specific applications need more built-in
functionality for maximum speed. This functionality can be reused by any application that adds hyperlinks
to texts depending on content of the text.</para>
  <para>Consider advertisers that want to show links to their resources near phrases they choose as relevant, and
one phrase can be chosen by many advertisers. To make the processing easier, there exists special support
for phrase sets that store lists of links for phrases.</para>
  <para>An advertiser is some very abstract "source" of annotation phrases.
The exact nature of an advertiser is application-specific, but each advertiser has an identifiable account.
All accounts are in one table:</para>
<programlisting><![CDATA[
create table DB.DBA.SYS_ANN_AD_ACCOUNT (
  AAA_ID integer not null primary key,
  AAA_NAME varchar(255) unique,		-- unique name for use in API/UI
  AAA_OWNER_UID integer,		-- references SYS_USERS (U_ID), NULL if the record writable for any reader
  AAA_READER_GID integer,		-- references SYS_USERS (U_ID), NULL if the record is readable for public
  AAA_DETAILS long xml,			-- any details, e.g., in RDF
  AAA_APP_ENV any
  )
;
]]></programlisting>
  <para>Advertisement links are stored in a separate table:</para>
<programlisting><![CDATA[
create table DB.DBA.SYS_ANN_LINK (
  AL_ID integer primary key,
  AL_OWNER_UID integer,			-- references SYS_USERS (U_ID), NULL if the record writable for any reader; always readable for public
  AL_URI varchar,			-- URI template for A HREF
  AL_TEXT varchar,			-- text template for body of <A>
  AL_NOTE varchar,			-- text after the link (or around it)
  AL_TAGS any,				-- tags to add or remove
  AL_CALLBACK varchar,
  AL_APP_ENV any
  )
;
]]></programlisting>
  <para>Advertisers, links and phrases are linked together by advertisement rules.
Each rule says that if a given phrase is found in some text then a given link should be shown and a
specified advertiser's account should be charged.
</para>
<programlisting><![CDATA[
create table DB.DBA.SYS_ANN_AD_RULE (
  AAR_AAA_ID integer not null,		-- advertiser who pays for the ad
  AAR_APS_ID integer not null,		-- phrase set
  AAR_AP_CHKSUM integer not null,	-- phrase check-sum
  AAR_TEXT varchar not null,		-- original text
  AAR_AL_ID integer not null,		-- references SYS_ANN_LINK (AL_ID)
  AAR_APP_ENV any,
  primary key (AAR_AAA_ID, AAR_APS_ID, AAR_AP_CHKSUM, AAR_TEXT, AAR_AL_ID)
  )
;
]]></programlisting>
  <para>When an annotation phrase is stored in its phrase set via advertisement API, its application-specific data
is always a vector, and vector's length is divisible by three. When a new ad rule is added to the vector, it
gets three new items: value of AL_ID of a link, value of advertiser's AAA_ID and AAR_APP_ENV of the ad rule.
</para>
  <para>Anyone can describe a link but can not edit other's descriptions:</para>
<programlisting><![CDATA[
create function DB.DBA.ANN_LINK_ADD (
  in _owner_uid integer,
  in _uri varchar,		-- value for AL_URI
  in _text varchar,		-- value for AL_TEXT
  in _note varchar,		-- value for AL_NOTE
  in _tags any,			-- value for AL_TAGS
  in _callback varchar,
  in _app_env any) returns integer
]]></programlisting>
  <para>So one user may create links in favor of other user even without permission, but can not edit other's links.
To edit or delete, one should be an owner and pass authentication:</para>
<programlisting><![CDATA[
create function DB.DBA.ANN_LINK_MODIFY (
  in _id integer,
  in _owner_uid integer,
  in _uri varchar,
  in _text varchar,
  in _note varchar,
  in _tags any,
  in _callback varchar,
  in _app_env any,
  in auth_uname varchar,
  in auth_pwd varchar) returns integer

create function DB.DBA.ANN_LINK_DEL (
  in _id integer,
  in auth_uname varchar,
  in auth_pwd varchar) returns integer
]]></programlisting>
  <para>A link can not be dropped even by its owner if it is used by some advertiser.
</para>
<programlisting><![CDATA[
create function DB.DBA.ANN_AD_RULE_ADD (
  in aaa_name varchar,		-- Advertiser's name (or its integer AAA_ID key), to store as AAR_AAA_ID
  in aps_name varchar,		-- Name of a phrase set (or its integer APS_ID key), to store as AAR_APS_ID
  in _text varchar,		-- Text of the phrase, will be stored as AAR_TEXT and duplicated in an AP_TEXT if the phrase is new
  in _al_id integer,		-- ID of a link (AL_ID in DB.DBA.SYS_ANN_LINK), to store as AAR_AL_ID
  in _app_env any,		-- Application-specific data, will be stored in AAR_APP_ENV and become a part of AP_LINK_DATA of the phrase
  in _lang_name varchar,	-- Language name, for verification only; an error will be signalled if the value of argument is not equal to language name of the phrase set
  in auth_uname varchar,
  in auth_pwd varchar) returns integer
]]></programlisting>
  <para>Application-specific data should be short, because for any given phrase, sum of data from all advertisers
should not exceed 2 kilobytes. Fortunately, most of needed data are in DB.DBA.SYS_ANN_LINK row already so
AAR_APP_ENV is frequently a NULL.</para>
<programlisting><![CDATA[
create function DB.DBA.ANN_AD_RULE_DEL (
  in aaa_name varchar,
  in aps_name varchar,
  in _text varchar,
  in _al_id integer,
  in _lang_name varchar,
  in auth_uname varchar,
  in auth_pwd varchar) returns integer
]]></programlisting>
  <para>If a phrase set is edited by DB.DBA.ANN_AD_RULE_ADD / DB.DBA.ANN_AD_RULE_DEL and by ap_add_phrases() then
errors are almost guaranteed (and not detected or recovered automatically in current version). The function
ap_build_match_list() works fine with mix of phrase sets managed by both methods because it is not sensitive
to the format of data in phrases.</para>
  </sect2>
  <sect2 id="sqlreffastphraseexample"><title>Example</title>
<para>The following example demonstrates managing phrases sets and data associated with them:</para>
<programlisting><![CDATA[
SQL>insert replacing DB.DBA.SYS_ANN_PHRASE_CLASS (APC_ID, APC_NAME, APC_OWNER_UID, APC_READER_GID, APC_CALLBACK, APC_APP_ENV)
values (3, 'Debug apc #3', http_dav_uid(), http_admin_gid(), 'DB.DBA.AP_DEBUG_CALLBACK', 'Debug apc #3 env')
;

Done. -- 0 msec.

SQL>insert replacing DB.DBA.SYS_ANN_PHRASE_SET (APS_ID, APS_NAME, APS_OWNER_UID, APS_READER_GID, APS_APC_ID, APS_LANG_NAME, APS_APP_ENV, APS_SIZE, APS_LOAD_AT_BOOT)
values (5, 'Debug aps #5', http_dav_uid(), http_admin_gid(), 3, 'x-any', 'Debug aps #5 env', 10000, 0)
;

Done. -- 0 msec.

SQL>insert replacing DB.DBA.SYS_ANN_PHRASE_SET (APS_ID, APS_NAME, APS_OWNER_UID, APS_READER_GID, APS_APC_ID, APS_LANG_NAME, APS_APP_ENV, APS_SIZE, APS_LOAD_AT_BOOT)
values (7, 'Debug aps #7', http_dav_uid(), http_admin_gid(), 3, 'x-any', 'Debug aps #7 env', 10000, 0)
;

Done. -- 0 msec.

SQL>ap_add_phrases (5,
  vector (
    vector ('Debug5', 'Debug5 env'),
    vector ('Debug5 one', 'Debug5 one env'),
    vector ('Debug5 two', 'Debug5 two env'),
    vector ('Debug5 three', 'Debug5 three env'),
    vector ('Debug5 twenty one', 'Debug5 twenty one env'),
    vector ('Debug5 twenty two', 'Debug5 twenty two env'),
    vector ('Debug5 twenty three', 'Debug5 twenty three env')
    ) )
;
Done. -- 0 msec.

SQL>ap_add_phrases (7,
  vector (
    vector ('Debug7', 'Debug7 env'),
    vector ('Debug7 one', 'Debug7 one env'),
    vector ('Debug7 two', 'Debug7 two env'),
    vector ('Debug7 three', 'Debug7 three env'),
    vector ('Debug7 twenty one', 'Debug7 twenty one env'),
    vector ('Debug7 twenty two', 'Debug7 twenty two env'),
    vector ('Debug7 twenty three', 'Debug7 twenty three env')
    ) )
;

Done. -- 0 msec.

SQL>ap_add_phrases (5,
  vector (
    vector ('Debug5 thirty one', 'Debug5 thirty one BAD env'),
    vector ('Debug5 thirty two', 'Debug5 thirty two BAD env'),
    vector ('Debug5 thirty three', 'Debug5 thirty three BAD env'),
    vector ('Debug5 one hundred', 'Debug5 one hundred BAD env')
    ) )
;

Done. -- 0 msec.

SQL>ap_add_phrases (5,
  vector (
    vector ('Debug5', 'Debug5 UPDATED env'),
    vector ('Debug5 thirty one', 'Debug5 thirty one NEW env'),
    vector ('Debug5 thirty two', 'Debug5 thirty two NEW env'),
    vector ('Debug5 thirty three', 'Debug5 thirty three NEW env'),
    vector ('Debug5 one hundred')
    ) )
;
Done. -- 0 msec.

SQL>create function ptext_1 ()
{
  return '
    vector ''Debug5'', ''Debug5 env'',
    vector ''Debug5 one'', ''Debug5 one env'',
    vector ''Debug5 two'', ''Debug5 two env'',
    vector ''Debug5 three'', ''Debug5 three env'',
    vector ''Debug5 twenty one'', ''Debug5 twenty one env'',
    vector ''Debug5 twenty two'', ''Debug5 twenty two env'',
    vector ''Debug5 twenty three'', ''Debug5 twenty three env''
ap_add_phrases 7,
  vector
    vector ''Debug7'', ''Debug7 env'',
    vector ''Debug7 one'', ''Debug7 one env'',
    vector ''Debug7 two'', ''Debug7 two env'',
    vector ''Debug7 three'', ''Debug7 three env'',
    vector ''Debug7 twenty one'', ''Debug7 twenty one env'',
    vector ''Debug7 twenty two'', ''Debug7 twenty two env'',
    vector ''Debug7 twenty three'', ''Debug7 twenty three env''
ap_add_phrases 5,
  vector
    vector ''Debug5 thirty one'', ''Debug5 thirty one BAD env'',
    vector ''Debug5 thirty two'', ''Debug5 thirty two BAD env'',
    vector ''Debug5 thirty three'', ''Debug5 thirty three BAD env'',
    vector ''Debug5 one hundred'', ''Debug5 one hundred BAD env''
ap_add_phrases 5,
  vector
    vector ''Debug5'', ''Debug5 UPDATED env'',
    vector ''Debug5 thirty one'', ''Debug5 thirty one NEW env'',
    vector ''Debug5 thirty two'', ''Debug5 thirty two NEW env'',
    vector ''Debug5 thirty three'', ''Debug5 thirty three NEW env'',
    vector ''Debug5 one hundred''
    ';
}
;

Done. -- 20 msec.

SQL>create function ptext_2 ()
{
  return '
    vector ''Debug5 twenty one''
    vector ''Debug7 twenty one''
    vector ''Debug5 thirty one''
    vector ''Debug5 thirty one''
    vector ''Debug5 one hundred''
    ';
}
;
Done. -- 10 msec.


SQL>create function test_ptext_1()
{
  declare ses any;
  ses := string_output();
  ap_debug_langhandler (ptext_1 (), 'x-any', vector (5, 7), ses );
  return string_output_string (ses);
}
;
Done. -- 10 msec.


SQL>create procedure dump_match_list (in vect any, in path varchar := null)
{
  declare VDATA varchar;
  if (path is null)
    {
      result_names (VDATA);
      path := '';
    }
  if (vect is null)
    {
      result (path || ' NULL');
      return;
    }
  if (193 <> __tag (vect))
    {
      result (path || ' ' || (cast (vect as varchar)));
      return;
    }
  declare l, ctr integer;
  l := length (vect);
  if (0 = l)
    {
      result (path || ' (empty vector)');
      return;
    }
  if (isinteger (vect [l - 1]))
    {
      declare ses any;
      ses := string_output ();
      for (ctr := 0; ctr < l; ctr := ctr + 1)
        {
	  http (sprintf (' [%d]=%s', ctr, cast (vect[ctr] as varchar)), ses);
	}
      result (path || string_output_string (ses));
      return;
    }
  for (ctr := 0; ctr < l; ctr := ctr + 1)
    {
      dump_match_list (vect[ctr], sprintf ('%s[%d]', path, ctr));
    }
}
;


Done. -- 10 msec.

SQL>select test_ptext_1();
callret
VARCHAR
_______________________________________________________________________________

    (vector) '[[Debug5 UPDATED env]Debug5]]', '[[Debug5 UPDATED env]Debug5]] (env)', (vector) '[[Debug5 UPDATED env ; Debug5 one env]Debug5]] [[Debug5 one env]one]]', '[[Debug5 UPDATED env ; Debug5 one env]Debug5]] [[Debug5 one env ]one]] (env)',
    (vector) '[[Debug5 UPDATED env ; Debug5 two env]Debug5]] [[Debug5 two env]two]]', '[[Debug5 UPDATED env ; Debug5 two env]Debug5]] [[Debug5 two env ]two]] (env)', (vector) '[[Debug5 UPDATED env ; Debug5 three env]Debug5]] [[Debug5 three env]three]]', '[[Debug5 UPDATED env ; Debug5 three env]Debug5]] [[Debug5 three env]three]] (env)',
    (vector) '[[Debug5 UPDATED env ; Debug5 twenty one env]Debug5]] [[Debug5 twenty one env]twenty]] [[Debug5 twenty one env]one]]', '[[Debug5 UPDATED env ; Debug5 twenty one env]Debug5]] [[Debug5 twenty one env]twenty]] [[Debug5 twenty one env]one]] (env)',
    (vector) '[[Debug5 UPDATED env ; Debug5 twenty two env]Debug5]] [[Debug5 twenty two env]twenty]] [[Debug5 twenty two env]two]]', '[[Debug5 UPDATED env ; Debug5 twenty two env]Debug5]] [[Debug5 twenty two env]twenty]] [[Debug5 twenty two env]two]] (env)',
    (vector) '[[Debug5 UPDATED env ; Debug5 twenty three env]Debug5]] [[Debug5 twenty three env]twenty]] [[Debug5 twenty three env]three]]', '[[Debug5 UPDATED env ; Debug5 twenty three env]Debug5]] [[Debug5 twenty three env]twenty]] [[Debug5 twenty three env]three]] (env)' (ap)_(add)_(phrases) (7), (vector)
    (vector) '[[Debug7 env]Debug7]]', '[[Debug7 env]Debug7]] (env)', (vector) '[[Debug7 one env ; Debug7 env]Debug7]] [[Debug7 one env]one]]', '[[Debug7 one env ; Debug7 env]Debug7]] [[Debug7 one env]one]] (env)',
    (vector) '[[Debug7 two env ; Debug7 env]Debug7]] [[Debug7 two env]two]]', '[[Debug7 two env ; Debug7 env]Debug7]] [[Debug7 two env]two]] (env)',
    (vector) '[[Debug7 three env ; Debug7 env]Debug7]] [[Debug7 three env]three]]', '[[Debug7 three env ; Debug7 env]Debug7]] [[Debug7 three env]three ]] (env)',
    (vector) '[[Debug7 twenty one env ; Debug7 env

1 Rows. -- 50 msec.


SQL>dump_match_list (ap_build_match_list (vector (5, 7), ptext_2 (), 'x-any', 0, 0 ) );
VDATA
VARCHAR
_______________________________________________________________________________

[0][0] 3
[0][1][0] Debug apc #3
[0][1][1] DB.DBA.AP_DEBUG_CALLBACK
[0][1][2] Debug apc #3 env
[1][0] 5
[1][1][0] Debug aps #5
[1][1][1] 3
[1][1][2] 1
[1][1][3] Debug aps #5 env
[1][2] 7
.....
139 Rows. -- 231 msec.

SQL>dump_match_list (ap_build_match_list (vector (5, 7), ptext_2 (), 'x-any', 0, 3 ) );
VDATA
VARCHAR
_______________________________________________________________________________

[0][0] 3
[0][1][0] Debug apc #3
[0][1][1] DB.DBA.AP_DEBUG_CALLBACK
[0][1][2] Debug apc #3 env
[1][0] 5
[1][1][0] Debug aps #5
[1][1][1] 3
[1][1][2] 1
.....
133 Rows. -- 231 msec.

SQL>create procedure ap_make_js_menus (
  in ap_set_ids any, in source_UTF8 varchar, in lang_name varchar, in is_html integer)
{
  declare res_out, script_out, match_list any;
  declare m_apc, m_aps, m_app, m_apa, m_apa_w, m_aph any;
  declare apa_w_ctr, apa_w_count integer;
  declare app_ctr, app_count integer;
  declare prev_end integer;

  match_list := ap_build_match_list ( ap_set_ids, source_UTF8, lang_name, is_html, 3); -- 3 is to have less garbage, hence better speed.
  m_apc := aref_set_0 (match_list, 0);
  m_aps := aref_set_0 (match_list, 1);
  m_app := aref_set_0 (match_list, 2);
  m_apa := aref_set_0 (match_list, 3);
  m_apa_w := aref_set_0 (match_list, 4);
  m_aph := aref_set_0 (match_list, 5);
  apa_w_count := length (m_apa_w);
  app_count := length (m_app);
  if (0 = app_count)
    {
      return source_UTF8;
    }
  res_out := string_output ();
  script_out := string_output ();
  http ('<script DEFER language="javescript"><!--', script_out);
  http ('\n  var v_descs = [', script_out);
  for (apa_w_ctr := 0; apa_w_ctr < apa_w_count; apa_w_ctr := apa_w_ctr + 1)
    {
      declare apa_idx integer;
      declare apa any;
      apa_idx := m_apa_w [apa_w_ctr];
      apa := aref_set_0 (m_apa, apa_idx);
      if (5 = length (apa))
        {
          declare apa_beg, apa_end, apa_hpctr, apa_hpcount integer;
          apa_beg := apa [1];
	  apa_end := apa [2];
	  apa_hpcount := length (apa[4]);
	  http (subseq (source_UTF8, prev_end, apa_beg), res_out);
	  http (sprintf ('<span id="apjsm%d">', apa_idx), res_out);
	  http (subseq (source_UTF8, apa_beg, apa_end), res_out);
	  http ('</span>', res_out);
          prev_end := apa_end;
	  if (apa_w_ctr > 0)
	    http(',', script_out);
	  http (sprintf ('\n\t["apjsm%d"\t, [', apa_idx), script_out);
	  for (apa_hpctr := 0; apa_hpctr < apa_hpcount; apa_hpctr := apa_hpctr + 1)
            {
              if (apa_hpctr > 0)
	        http (',', script_out);
	      http (cast (apa[4][apa_hpctr] as varchar), script_out);
            }
	  http (']\t, [', script_out);
	-- todo: list service indexes. Do we need this in such a form?
	  http ('\t]', script_out);
        }
    }
  http (subseq (source_UTF8, prev_end), res_out);
  http (' ];', script_out);
  http ('\n  var v_descs = [', script_out);
  -- todo list services. Do we need this in such a form?
  http (' ];', script_out);
  http ('\n  var v_links = [', script_out);
  for (app_ctr := 0; app_ctr < app_count; app_ctr := app_ctr + 1)
    {
      declare app any;
      app := m_app [app_ctr];
      if (app_ctr > 0)
        http(',', script_out);
      http (sprintf ('\n\t["%s"\t, "%s"\t, "%s"\t, "%s"\t]', app[3][0], app[3][1], app[3][2], app[3][3]), script_out);
    }
  http (' ];', script_out);
  http ('\n--></script><script DEFER language="javascript" src="lookup.js"></script>', script_out);
  return
    replace (
      replace (
        string_output_string (res_out),
        '<body', '<body onload="makePopupDivs (v_descs, v_services, v_links)"' ),
      '</html>', string_output_string (script_out) || '</html>' );
}
;


Done. -- 0 msec.

SQL>create function ptext_3 ()
{
  return '<html>
  <head>
  <link href="gogo.css" rel="stylesheet" type="text/css" />
  </head>
  <body>
  <p>The OpenLink Virtuoso team has developers based in Bulgaria</p>
  </body>
</html>';
}
;

Done. -- 10 msec.

SQL>create function ptext_3 ()
{
  return '<html>
  <head>
  <link href="gogo.css" rel="stylesheet" type="text/css" />
  </head>
  <body>
  <p>The OpenLink <strong>Virtuoso</strong> team has developers based in Bulgaria</p>
  </body>
</html>';
}
;

Done. -- 0 msec.


SQL>insert replacing DB.DBA.SYS_ANN_PHRASE_SET (APS_ID, APS_NAME, APS_OWNER_UID, APS_READER_GID, APS_APC_ID, APS_LANG_NAME, APS_APP_ENV, APS_SIZE, APS_LOAD_AT_BOOT)
values (9, 'Gogo aps', http_dav_uid(), http_admin_gid(), 3, 'x-any', 'Gogo aps env', 10000, 0);

Done. -- 0 msec.

SQL>ap_add_phrases (9,
    vector (
      vector ('OpenLink'		, vector ('OpenLink'		, 'http://www.openlinksw.com'		, 'OpenLink Software'	, ' The industry leading provider of High Performance drivers'	)),
      vector ('OpenLink Virtuoso'	, vector ('OpenLink Virtuoso'	, 'http://www.openlinksw.com/virtuoso'	, 'OpenLink Virtuoso'	, ' OpenLink Universal Integration Middleware'			)),
      vector ('Bulgaria'		, vector ('Bulgaria'		, 'http://www.government.bg/English/'	, 'Bulgaria'		, ' Republic of Bulgaria'					))
    ) )
;

Done. -- 0 msec.

SQL>select ap_make_js_menus (vector (9), ptext_3(), 'x-any', 1);

callret
VARCHAR
_______________________________________________________________________________

<html>
  <head>
  <link href="gogo.css" rel="stylesheet" type="text/css" />
  </head>
  <body onload="makePopupDivs (v_descs, v_services, v_links)">
  <p>The OpenLink <strong>Virtuoso</strong> team has developers based in Bulgaria</p>
  </body>
<script DEFER language="javescript"><!--
  var v_descs = [ ];
  var v_descs = [ ];
  var v_links = [
        ["Bulgaria"     , "http://www.government.bg/English/"   , "Bulgaria"    , " Republic of Bulgaria"       ],
        ["OpenLink Virtuoso"    , "http://www.openlinksw.com/virtuoso"  , "OpenLink Virtuoso"   , " OpenLink Universal Integration Middleware"  ],
        ["OpenLink"     , "http://www.openlinksw.com"   , "OpenLink Software"   , " The industry leading provider of High Performance drivers"  ] ];
--></script><script DEFER language="javascript" src="lookup.js"></script></html>

1 Rows. -- 0 msec.

]]></programlisting>
  </sect2>
</sect1>
	<!-- ======================================== -->
</chapter>