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
|
Postgresql trianing - Laurenz Albe
April. 27, 2020
* Read the docs: www.postgresql.org/docs/11/index.html
* Mailing list: www.postgresql.org/list/
* pgsql-general
* pgsql-hackers : development list
* Wiki: wiki.postgresql.org
Install
* postgresql-debuginfo package.
* it doesn't hurt. doesn't slow things down.
* if you get a crash from pg, then you can create a stack trace for anyone who needs to support you.
* `perf` tool on linux can be used for performance monitoring.
* postgresql11-contrib
* defined in appendix F.
* always install this.
* user: postgres
* dedicated user to run postgres
* create a database cluster
* unfortunate name.
* does not mean mutliple machines.
* it's like an instance
* it's a directory with files and a number of processes running against those files.
```text
cluster
|----------|
| postgres |
|----------| -- (tcp:5432/unix) listen --
| course |
|----------|
```
you cannot join tables between two different databases.
Shared between databases:
* users
* tablespaces
To create a cluster:
```bash
$ initdb -D $DATA_DIR -E UTF8 --locale=en_US.utf8
```
interesting options:
* --encoding=ENCODING (Always use UTF-8)
* --locale=LOCALE
* --lc-collate, --lc-ctype
* determines which character is a space, digit etc.
* collation: determines how string are sorted and ordered. (cannot be changed after db creation)
* indexes are sorted lists. order is determined by collation for string data type
* affects order by clauses based on collation in the database.
* US-english. Or use C or posix locale. C locale is very fast.
* standard data dir: /var/lib/pgsql/11/data
To start:
```bash
$ pg_ctl -D /home/mokha/development/2020-04-pg-training/db/data -l logfile start
```
* 1 server process for each client connection.
* good isolation
* `psql` is a command line client for connecting to the server.
* 4 bits of info needed
* host: -h
* port: -p
* database: -d
* user: -U
```bash
psql -h 127.0.0.1 -p 5432 -U postgres -d postgres
```
How to quit:
* \q
* ^d
* \ -> command for the client
* everything else is sent to SQL interpreter
* version 11 supports `exit`
Defaults:
* -h: unix socket
* -U: logged in user
* environment variables
* PGDATABASE
* PGHOST
* PGPORT
* PGUSER
```sql
CREATE DATABASE course;
```
* creates a copy of an existing database. it uses `template1` database
* you can specify a different template database.
client commands:
* \?
* \watch
* \i FILE
* \ir RELATIVE_FILE
* \h: help about client commands
* \h CREATE DATABASE
* \l: list databases
* \d: describe
# Indexes
We need a table that has a certain size.
We'll create a table with a 1M rows.
```sql
CREATE TABLE test(id bigint GENERATED ALWAYS AS IDENTITY NOT NULL, name text NOT NULL);
```
* id is a autogenerated primary key column, without the primary key constraint.
* always use `bigint` which is an 8 byte integer.
* prevent exhausting possible range of valid integers to choose from for identifier.
* difference between SERIAL column
* `CREATE TABLE test2 (id bigserial PRIMARY KEY);`
* includes a sequence
* default value is next item in sequence.
* IDENTITY Column advantage.
* manually inserting id's can cause collisions with SERIAL.
* standards compliant so it's more portable between databases.
* `text` has a theoretical limit is 1GB
* use `text` when the application doesn't have a limit.
* avoid arbitrary limits like varchar(255).
* why set limit if there is not limit.
* there is not performance impact either.
* nulls make queries difficult, queries are a little more complex which leads to perf issues.
* recommends: use `not null`. Easy to go from `not null` to allow `null. Harder the other way`. Easy to go from `not null` to allow `null`. Harder the other way.
```sql
INSERT INTO test(name) VALUES ('hans'), ('laurenz');
INSERT INTO test(name) SELECT name FROM test;
TABLE test is like SELECT * FROM test;
CREATE INDEX test_id_idx ON test (id);
```
```psql
# SELECT * FROM test WHERE id = 42;
id | name
----+---------
42 | laurenz
(1 row)
Time: 161.688 ms
# CREATE INDEX test_id_idx ON test (id);
CREATE INDEX
Time: 2106.364 ms (00:02.106)
# SELECT * FROM test WHERE id = 42;
id | name
----+---------
42 | laurenz
(1 row)
Time: 1.682 ms
```
You describe how the result should look like.
The db will figure out how to best do that.
* uuid is 16 bytes wide.
* nothing wrong with it and go ahead and use it.
* nice for distributed generation of identifiers.
# query life cycle
1. query is parsed by parser for syntax.
2. query re-writer.
3. query planner or query optimizer. (AI component that tries to enumerate or walk through different possible ways to execute query.)
Prepend `EXPLAIN` to query to see execution plan
```sql
EXPLAIN SELECT * FROM test WHERE id = 42;
```
```sql
# EXPLAIN SELECT * FROM test WHERE id = 42;
QUERY PLAN
-------------------------------------------------------------------------
Index Scan using test_id_idx on test (cost=0.43..8.45 rows=1 width=14)
Index Cond: (id = 42)
(2 rows)
Time: 0.536 ms
```
What do #'s mean?
* cost: no meaning in reality. estimate of cost. from how many rows determines how expensize pg thinks it will be.
* cost=0.43..8.45. initial cost to get first result.. total cost to get all rows.
* rows=1 how many rows it thinks it will return
* width=13 estimated with in bytes.
`\di+ to describe index`
```sql
# \dt+ test
List of relations
Schema | Name | Type | Owner | Size | Description
--------+------+-------+-------+--------+-------------
public | test | table | mokha | 266 MB |
(1 row)
# \di+ test_id_idx
List of relations
Schema | Name | Type | Owner | Table | Size | Description
--------+-------------+-------+-------+-------+--------+-------------
public | test_id_idx | index | mokha | test | 135 MB |
(1 row)
```
It made the query faster but we pay a price for having the index.
divided into blocks
------------------
| table rows | 8K block 0
------------------
| 2 | | 8K block 1
------------------
| 1 | | 8K block 2
------------------
tables are unordered.
updates, deletes will change order.
cannot rely on order of items in the table.
database table is also called a HEAP.
It's unordered.
It's a pile of rows.
Indexes are a different affair. sorted list of index items
Index is kept in order.
-----
| 1 | ---> points to a physical location of row in a datafile.
| 2 |
| 3 |
To maintain the order of an index, deletes, updates of data rows means
having to re-order the index. Insert, update and delete statements will
increase cost to maintain index. Indexes will negatively impact performance
for insert, update and deletes.
Who is responsible for indexes?
* do not believe this: `dba has to figure out performance bottleneck and figure out correct indexes.`
* poor dba doesn't understand the data in the table.
* doesn't know what the data means.
* doesn't know what has to be fast.
* in some cases adding an index afterwards cannot improve a bad query.
* during development make sure to choose good indexes.
What are indexes are useful for?
Library visual
* table is a library of books
* each row is a book
* shelves are blocks
* library catalogue: ordered list of books (index)
* index can be used for a '<' condition.
```sql
# EXPLAIN SELECT * FROM test WHERE id < 42;
QUERY PLAN
--------------------------------------------------------------------------
Index Scan using test_id_idx on test (cost=0.43..9.15 rows=41 width=14)
Index Cond: (id < 42)
(2 rows)
Time: 0.630 ms
```
```sql
# EXPLAIN SELECT * FROM test WHERE id > 4000000000;
QUERY PLAN
-------------------------------------------------------------------------
Index Scan using test_id_idx on test (cost=0.43..4.45 rows=1 width=14)
Index Cond: (id > '4000000000'::bigint)
(2 rows)
Time: 0.571 ms
```
* b-tree indexes can be read in both directions. index wasn't used. why?
* pg can use the index but chooses not to use the index.

Back and forth between index and table. This is fine when a few rows to scan.
When a large amount of rows is large. access pattern between heap and index is
rando I/O. Not as good as sequential I/O. Exceeding a large # of rows means
it's more efficient to just do a sequential scan rather than go back and forth between
index and datafiles.
```sql
# EXPLAIN SELECT min(id) FROM test;
QUERY PLAN
------------------------------------------------------------------------------------------------------
Result (cost=0.47..0.48 rows=1 width=8)
InitPlan 1 (returns $0)
-> Limit (cost=0.43..0.47 rows=1 width=8)
-> Index Only Scan using test_id_idx on test (cost=0.43..213123.91 rows=6291456 width=8)
Index Cond: (id IS NOT NULL)
(5 rows)
Time: 0.766 ms
```
```sql
# EXPLAIN SELECT * FROM test WHERE id < 1000 ORDER BY id;
QUERY PLAN
----------------------------------------------------------------------------
Index Scan using test_id_idx on test (cost=0.43..38.77 rows=991 width=14)
Index Cond: (id < 1000)
(2 rows)
Time: 0.658 ms
```
* If the order of the index matches the order of the query then this is optimal.
Create index on `name` column
```sql
CREATE INDEX ON test(name);
# EXPLAIN SELECT * FROM test where name = 'laurenz';
QUERY PLAN
----------------------------------------------------------------
Seq Scan on test (cost=0.00..112651.20 rows=3146147 width=14)
Filter: (name = 'laurenz'::text)
(2 rows)
Time: 1.250 ms
```
Set parameter to no use a sequential scan if it can
`SET enable_seqscan = off;`
`RESET enable_seqscan;`
## Partial indexes
```sql
DROP INDEX test_name_idx;
CREATE INDEX ON test(name) WHERE name NOT IN ('laurenz', 'hans');
```
* Consequently this index only matches for queries that match the WHERE query.
* smaller index
* indexes only rows where it's useful to have an index.
Constraint: Excludes certain things from the database.
We want to have a primary key.
```sql
ALTER TABLE test ADD PRIMARY KEY(id);
```
An index backing the primary key with a unique constraint.
Soft deletes using `active` true, false.
Apply unique constraint to active rows only.
Add a unique constraint for `active` rows and not on others.
Queries on the `active` rows can be fast.
This way you don't need a large index on all the rows but on only the rows that need them.
```sql
SELECT * FROM test WHERE id = 42 AND name = 'zephanja';
```
`OR` queries makes it harder to use indexes.
```sql
# EXPLAIN SELECT * FROM test WHERE id = 42 OR name = 'zephanja';
QUERY PLAN
----------------------------------------------------------------------------------
Bitmap Heap Scan on test (cost=8.88..12.90 rows=1 width=14)
Recheck Cond: ((id = 42) OR (name = 'zephanja'::text))
-> BitmapOr (cost=8.88..8.88 rows=1 width=0)
-> Bitmap Index Scan on test_pkey (cost=0.00..4.44 rows=1 width=0)
Index Cond: (id = 42)
-> Bitmap Index Scan on test_name_idx (cost=0.00..4.44 rows=1 width=0)
Index Cond: (name = 'zephanja'::text)
(7 rows)
Time: 0.652 ms
```
Bitmap index scan: What is this?

Creates a bitmap in memory find matches.
Then make an OR of the two bitmaps to produce a final bitmap that finds rows that matches both conditions.
bitmap is orderd in physical order of the database table.
## Multi-column indexes
When is it useful to have multiple columns in an index?
```sql
DROP INDEX test_name_idx;
ALTER TABLE test DROP CONSTRAINT test_pkey;
CREATE INDEX ON test(id, name);
# \d test
Table "public.test"
Column | Type | Collation | Nullable | Default
--------+--------+-----------+----------+------------------------------
id | bigint | | not null | generated always as identity
name | text | | not null |
Indexes:
"test_id_name_idx" btree (id, name)
# \di+ test_id_name_idx
List of relations
Schema | Name | Type | Owner | Table | Size | Description
--------+------------------+-------+-------+-------+--------+-------------
public | test_id_name_idx | index | mokha | test | 189 MB |
(1 row)
# EXPLAIN SELECT * FROM test WHERE id = 42 AND name = 'zephanja';
QUERY PLAN
-----------------------------------------------------------------------------------
Index Only Scan using test_id_name_idx on test (cost=0.43..8.45 rows=1 width=14)
Index Cond: ((id = 42) AND (name = 'zephanja'::text))
(2 rows)
Time: 1.605 ms
```
A multi-column index can still be used by queries that only filter on the first column.
The index is larger but it still satisfy the needs of the one column and both.
```sql
# EXPLAIN SELECT * FROM test WHERE id = 42;
QUERY PLAN
-----------------------------------------------------------------------------------
Index Only Scan using test_id_name_idx on test (cost=0.43..8.45 rows=1 width=14)
Index Cond: (id = 42)
(2 rows)
Time: 0.447 ms
```
However, index cannot be used if the secondary column in the index is used as the only item in the query.
```sql
# EXPLAIN SELECT * FROM test WHERE name = 'zephanja';
QUERY PLAN
------------------------------------------------------------------------
Gather (cost=1000.00..67776.10 rows=1 width=14)
Workers Planned: 2
-> Parallel Seq Scan on test (cost=0.00..66776.00 rows=1 width=14)
Filter: (name = 'zephanja'::text)
(4 rows)
Time: 0.476 ms
```
What about?
```sql
# EXPLAIN SELECT * FROM test WHERE id = 42 AND name < 'smith';
QUERY PLAN
-----------------------------------------------------------------------------------
Index Only Scan using test_id_name_idx on test (cost=0.43..8.45 rows=1 width=14)
Index Cond: ((id = 42) AND (name < 'smith'::text))
(2 rows)
Time: 0.597 ms
```
Index can use both conditions.
```sql
# EXPLAIN SELECT * FROM test WHERE id < 42 ORDER BY name;
QUERY PLAN
-------------------------------------------------------------------------------------------
Sort (cost=80.25..80.35 rows=41 width=14)
Sort Key: name
-> Index Only Scan using test_id_name_idx on test (cost=0.43..79.15 rows=41 width=14)
Index Cond: (id < 42)
(4 rows)
Time: 0.434 ms
```
## Expressions
```sql
# \d test
Table "public.test"
Column | Type | Collation | Nullable | Default
--------+--------+-----------+----------+------------------------------
id | bigint | | not null | generated always as identity
name | text | | not null |
Indexes:
"test_name_idx" btree (name)
```
Case insensitive search.
one way `WHERE upper(name) = upper('zephanja');`
```sql
# EXPLAIN SELECT * FROM test WHERE upper(name) = upper('zephanja');
QUERY PLAN
----------------------------------------------------------------------------
Gather (cost=1000.00..77475.30 rows=31457 width=14)
Workers Planned: 2
-> Parallel Seq Scan on test (cost=0.00..73329.60 rows=13107 width=14)
Filter: (upper(name) = 'ZEPHANJA'::text)
(4 rows)
Time: 1.444 ms
```
Index not used.
Create index on expression;
```sql
CREATE INDEX on test (upper(name));
# EXPLAIN SELECT * FROM test WHERE upper(name) = upper('zephanja');
QUERY PLAN
-----------------------------------------------------------------------------------
Bitmap Heap Scan on test (cost=592.22..35783.53 rows=31457 width=14)
Recheck Cond: (upper(name) = 'ZEPHANJA'::text)
-> Bitmap Index Scan on test_upper_idx (cost=0.00..584.36 rows=31457 width=0)
Index Cond: (upper(name) = 'ZEPHANJA'::text)
(4 rows)
Time: 1.049 ms
```
`ANALYZE` command
```sql
ANALYZE test;
# EXPLAIN SELECT * FROM test WHERE upper(name) = upper('zephanja');
QUERY PLAN
----------------------------------------------------------------------------
Index Scan using test_upper_idx on test (cost=0.43..7.44 rows=1 width=14)
Index Cond: (upper(name) = 'ZEPHANJA'::text)
(2 rows)
Time: 0.909 ms
```
* postgres: autovacuum launcher
```sql
# SELECT * FROM pg_stats WHERE tablename = 'test' AND attname = 'name';
-[ RECORD 1 ]----------+--------------------
schemaname | public
tablename | test
attname | name
inherited | f
null_frac | 0
avg_width | 6
n_distinct | 2
most_common_vals | {hans,laurenz}
most_common_freqs | {0.505233,0.494767}
histogram_bounds | [NULL]
correlation | 0.503458
most_common_elems | [NULL]
most_common_elem_freqs | [NULL]
elem_count_histogram | [NULL]
Time: 2.666 ms
```
# Extensions
* command `\dx+`
`CREATE EXTENSION citext;`
`DROP EXTENSION citext`;
* /usr/share/pgsql/extension/ : extensions directory
* /usr/share/pgsql/extension/citext--1.4.sql : sql file for citext extension
* /usr/share/pgsql/extension/citext.control : control file for working with extension
* /usr/share/pgsql/extension/citext--1.4--1.5.sql : upgrade file from v1.4 to v1.5 of the extension
```
Sometimes you need to change the query to optimize it instead of depending
on an index.
```sql
SELECT * FROM person WHERE age(birthday) < INTERVAL '40 years';
CREATE INDEX ON person (age(birthday));
ERROR: functions in index expression must be marked IMMUTABLE
SELECT * FROM person WHERE birthday < current_timestamp - INTERVAL '40 years';
```
```sql
SELECT * FROM test WHERE name LIKE '%ephanj%';
SELECT * FROM test WHERE name LIKE 'zephanj%';
# EXPLAIN SELECT * FROM test WHERE name LIKE 'zephan%';
QUERY PLAN
------------------------------------------------------------------------
Gather (cost=1000.00..67776.23 rows=1 width=14)
Workers Planned: 2
-> Parallel Seq Scan on test (cost=0.00..66776.12 rows=1 width=14)
Filter: (name ~~ 'zephan%'::text)
(4 rows)
Time: 1.261 ms
```
Why?
```sql
# SELECT 'c' < 'd';
?column?
----------
t
(1 row)
Time: 0.338 ms
# SELECT 'ch' < 'd';
?column?
----------
t
(1 row)
Time: 0.344 ms
# SELECT 'ch' < 'd' COLLATE "cs_CZ.utf8";
?column?
----------
f
(1 row)
Time: 2.935 ms
```
* c library or icu library
```sql
# CREATE INDEX ON test (name text_pattern_ops);
CREATE INDEX
Time: 5361.821 ms (00:05.362)
# EXPLAIN SELECT * FROM test WHERE name LIKE 'zephan%';
QUERY PLAN
----------------------------------------------------------------------------
Index Scan using test_name_idx1 on test (cost=0.43..8.45 rows=1 width=14)
Index Cond: ((name ~>=~ 'zephan'::text) AND (name ~<~ 'zephao'::text))
Filter: (name ~~ 'zephan%'::text)
(3 rows)
Time: 1.377 ms
```
Use `text_pattern_ops` operator class index for case insensitive search that can leverage an index.
Different ways to index data.
```sql
# TABLE pg_am;
amname | amhandler | amtype
--------+-------------+--------
btree | bthandler | i
hash | hashhandler | i
gist | gisthandler | i
gin | ginhandler | i
spgist | spghandler | i
brin | brinhandler | i
(6 rows)
Time: 0.968 ms
```
When do you need a different index access method?
`btree` indexes are well understood.
limitation: can only be used for datatypes that have a total ordering.
There are datatypes where you cannot order them.
If the data cannot be ordered then it cannot fit into a btree index.
E.g. composite data types or JSON datatype, geometric data types or points.
```sql
# SELECT JSONB '{"a": 2, "b": [1, 2, 3]}';
jsonb
--------------------------
{"a": 2, "b": [1, 2, 3]}
(1 row)
Time: 0.330 ms
SELECT point '(10, 20)';
# SELECT ARRAY[1, 2, 3, 55];
array
------------
{1,2,3,55}
(1 row)
Time: 0.313 ms
```
`gist` and `gin` indexes.
For composite datatypes like json, point, array then use `gin` indexes.
Weird data types then use `gist` like geometry and time ranges.
## JSON data in the database.
```sql
CREATE TABLE json(id bigint PRIMARY KEY, j json NOT NULL);
INSERT INTO json VALUES (1, '{"a": 2, "b": [1, 2, 3]}');
INSERT INTO json VALUES (2, '{"a": false, "b": [4, 5, 6], "extra": "yes"}');
# SELECT j->>'a' FROM json where id = 2;
?column?
----------
false
(1 row)
Time: 0.779 ms
# SELECT * FROM json WHERE j->>'a' = '2';
id | j
----+--------------------------
1 | {"a": 2, "b": [1, 2, 3]}
(1 row)
Time: 0.577 ms
# ALTER TABLE json ALTER j TYPE jsonb;
ALTER TABLE
Time: 4.560 ms
# SELECT * FROM json WHERE j @> '{"b": [3]}';
id | j
----+--------------------------
1 | {"a": 2, "b": [1, 2, 3]}
(1 row)
Time: 0.973 ms
# EXPLAIN SELECT * FROM json WHERE j @> '{"b": [3]}';
QUERY PLAN
-----------------------------------------------------
Seq Scan on json (cost=0.00..1.02 rows=1 width=40)
Filter: (j @> '{"b": [3]}'::jsonb)
(2 rows)
Time: 0.491 ms
# CREATE INDEX ON json USING gin (j);
CREATE INDEX
Time: 1.517 ms
# SET enable_seqscan = off;
SET
Time: 0.238 ms
# EXPLAIN SELECT * FROM json WHERE j @> '{"b": [3]}';
QUERY PLAN
--------------------------------------------------------------------------
Bitmap Heap Scan on json (cost=12.00..16.01 rows=1 width=40)
Recheck Cond: (j @> '{"b": [3]}'::jsonb)
-> Bitmap Index Scan on json_j_idx (cost=0.00..12.00 rows=1 width=0)
Index Cond: (j @> '{"b": [3]}'::jsonb)
(4 rows)
Time: 0.625 ms
# TABLE json;
id | j
----+----------------------------------------------
1 | {"a": 2, "b": [1, 2, 3]}
2 | {"a": false, "b": [4, 5, 6], "extra": "yes"}
(2 rows)
Time: 0.376 ms
```
## `gist` index example
```sql
CREATE TABLE reservation (
id bigint PRIMARY KEY,
name text NOT NULL,
res_from timestamp,
res_to timestamp
);
# Better way is to use a range type
CREATE TABLE reservation (
id bigint PRIMARY KEY,
name text NOT NULL,
res tsrange NOT NULL
);
INSERT INTO reservation VALUES (1, 'room 1', '[2020-04-24 9:00:00,2020-04-24 12:00:00]');
SELECT * FROM reservation WHERE res && '[2020-04-24 9:00:00,2020-04-24 12:00:00]';
# EXPLAIN SELECT * FROM reservation WHERE res && '[2020-04-24 9:00:00,2020-04-24 12:00:00]';
QUERY PLAN
--------------------------------------------------------------------------------
Seq Scan on reservation (cost=10000000000.00..10000000020.12 rows=8 width=72)
Filter: (res && '["2020-04-24 09:00:00","2020-04-24 12:00:00"]'::tsrange)
(2 rows)
Time: 0.551 ms
# SHOW enable_seqscan;
enable_seqscan
----------------
off
(1 row)
CREATE INDEX ON reservation USING gist (res);
# EXPLAIN SELECT * FROM reservation WHERE res && '[2020-04-24 9:00:00,2020-04-24 12:00:00]';
QUERY PLAN
----------------------------------------------------------------------------------------
Index Scan using reservation_res_idx on reservation (cost=0.12..8.14 rows=1 width=72)
Index Cond: (res && '["2020-04-24 09:00:00","2020-04-24 12:00:00"]'::tsrange)
(2 rows)
Time: 0.774 ms
```
Add constraint to prevent overlap. Exclusion constraint and it uses gist indexes.
```sql
ALTER TABLE reservation ADD EXCLUDE USING gist(res WITH &&);
# INSERT INTO reservation VALUES (2, 'room 1', '[2020-04-24 9:00:00,2020-04-24 12:00:00]');
ERROR: 23P01: conflicting key value violates exclusion constraint "reservation_res_excl"
DETAIL: Key (res)=(["2020-04-24 09:00:00","2020-04-24 12:00:00"]) conflicts with existing key (res)=(["2020-04-24 09:00:00","2020-04-24 12:00:00")).
SCHEMA NAME: public
TABLE NAME: reservation
CONSTRAINT NAME: reservation_res_excl
LOCATION: check_exclusion_or_unique_constraint, execIndexing.c:827
Time: 0.813 ms
```
Using a range type can sometimes make it easier to model something.
Never use strings to store dates or numbers.
Use a range type to store a range.
* Primary key constraint
* only on per table
* unique
* not null
* unique constraint
* more than one per table allowed
* unique
* nulls are allowed
NULL is strange.
```sql
# SELECT 1 = 1;
?column?
----------
t
(1 row)
# SELECT 1 = 2;
?column?
----------
f
(1 row)
# SELECT NULL = NULL;
?column?
----------
[NULL]
(1 row)
# SELECT 1 <> NULL;
?column?
----------
[NULL]
(1 row)
```
## Trigram indexes
```sql
CREATE EXTENSION pg_trgm;
# \do %
List of operators
Schema | Name | Left arg type | Right arg type | Result type | Description
------------+------+---------------+----------------+-------------+-------------
pg_catalog | % | bigint | bigint | bigint | modulus
pg_catalog | % | integer | integer | integer | modulus
pg_catalog | % | numeric | numeric | numeric | modulus
pg_catalog | % | smallint | smallint | smallint | modulus
public | % | text | text | boolean |
(5 rows)
# SELECT * FROM test WHERE name % 'zefanja';
id | name
----+------
(0 rows)
Time: 2683.199 ms (00:02.683)
CREATE INDEX ON test USING gin (name gin_trgm_ops);
# SELECT * FROM test WHERE name % 'zefanja';
id | name
----+------
(0 rows)
Time: 0.685 ms
# EXPLAIN SELECT * FROM test WHERE name % 'zefanja';
QUERY PLAN
----------------------------------------------------------------------------------
Bitmap Heap Scan on test (cost=2724.76..18729.70 rows=6291 width=14)
Recheck Cond: (name % 'zefanja'::text)
-> Bitmap Index Scan on test_name_idx (cost=0.00..2723.19 rows=6291 width=0)
Index Cond: (name % 'zefanja'::text)
(4 rows)
Time: 0.555 ms
```
We can use a trigram index to match like queries with a % that doesn't start
at the beginning of the search expression. We can also use the regex operator (~)
to match results.
```SQL
SELECT show_trgm('zephanja');
```
Two strings are similar if they share many trigrams.
Best to limit to 3 or more characters in search. Otherwise the trigram search
is not useful.
## Bloom indexes
* skipped
## Transactions and things that are related to them
Transactional guarantees or features that databases provide for you.
* A - atomicity
* C - consistency
* I - isolation
* D - durability - stays committed
We haven't used trx explicitly but pg is always running in auto commit mode.
By default each statement will run in it's own transaction.
```sql
# standards way
START TRANSACTION;
# pg specific way
BEGIN;
COMMIT;
ROLLBACK;
```
Transactional DDL (data definition language).
Not all databases support this.
```sql
BEGIN;
DROP TABLE test;
# We haven't commited yet.
ROLLBACK;
# table is back.
```
Errors in transactions will fail the entire transaction.
```sql
BEGIN;
SELECT 42;
SELECT 1/0;
SELECT 42;
ERROR: 25P02: current transaction is aborted, commands ignored until end of transaction block
# error in transaction causes transaction to be stale
```
Try to have short transactions. Sometimes you may need large transactions for
bulk loading or batch transactions.
You can create SAVEPOINTS to save things within a large transaction.
```sql
BEGIN;
SELECT 42;
SAVEPOINT a;
SELECT 1/0;
SELECT 42;
ERROR: 25P02: current transaction is aborted, commands ignored until end of transaction block
ROLLBACK TO SAVEPOINT a;
SELECT 42;
COMMIT;
```
Avoid using `SAVEPOINT` too much. As soon as you have more than 64 subtransactions
then this spills to disk and then performance goes down the drain.
To view the `psql` client settings. (not server)
```sql
# \set
AUTOCOMMIT = 'on'
COMP_KEYWORD_CASE = 'upper'
DBNAME = 'postgres'
ECHO = 'none'
ECHO_HIDDEN = 'off'
ENCODING = 'UTF8'
FETCH_COUNT = '0'
HISTCONTROL = 'ignoredups'
HISTFILE = '~/.psql_history-postgres'
HISTSIZE = '500'
HOST = '/home/mokha/development/2020-04-pg-training/tmp/sockets'
IGNOREEOF = '0'
LASTOID = '0'
ON_ERROR_ROLLBACK = 'off'
ON_ERROR_STOP = 'off'
PORT = '5432'
PROMPT1 = '%[%033[1m%]%M/%/%R%[%033[0m%]%
# '
PROMPT2 = ''
PROMPT3 = '>> '
QUIET = 'off'
SERVER_VERSION_NAME = '10.10'
SERVER_VERSION_NUM = '100010'
SHOW_CONTEXT = 'errors'
SINGLELINE = 'off'
SINGLESTEP = 'off'
USER = 'mokha'
VERBOSITY = 'verbose'
VERSION = 'PostgreSQL 10.10 on x86_64-redhat-linux-gnu, compiled by gcc (GCC) 9.1.1 20190605 (Red Hat 9.1.1-2), 64-bit'
VERSION_NAME = '10.10'
VERSION_NUM = '100010'
extensions = 'select * from pg_available_extensions;'
version = 'SELECT version();'
```
Be careful with the `ON_ERROR_ROLLBACK` option specified in the client configuration.
This can have unintended side affects.
```sql
# CREATE TABLE account (id bigint PRIMARY KEY, name text NOT NULL, amount numeric(10,2) NOT NULL);
# \d account
Table "public.account"
Column | Type | Collation | Nullable | Default
--------+---------------+-----------+----------+---------
id | bigint | | not null |
name | text | | not null |
amount | numeric(10,2) | | not null |
Indexes:
"account_pkey" PRIMARY KEY, btree (id)
```
`numeric` datatype.
```sql
# SELECT DOUBLE PRECISION '3.14';
float8
--------
3.14
(1 row)
# SELECT REAL '3.14';
float4
--------
3.14
# SELECT NUMERIC '3.14';
numeric
---------
3.14
```
* `float8`, `float4` are 8,4 byte binary. So they are fast but not precise.
* `numeric` is a binary coded decimal and more precise. Better for precision but slower. (e.g. money)
```sql
INSERT INTO account VALUES(1, 'laurenz', 1000);
INSERT INTO account VALUES(2, 'george', 1000);
# TABLE account;
id | name | amount
----+---------+---------
1 | laurenz | 1000.00
2 | george | 1000.00
(2 rows)
UPDATE account SET amount = amount - 100 WHERE id = 1;
UPDATE 1
UPDATE account SET amount = amount + 100 WHERE id = 2;
# simulate a crash or power failure
BEGIN;
UPDATE account SET amount = amount - 100 WHERE id = 1;
# not committed yet
UPDATE account SET amount = amount + 100 WHERE id = 2;
# crash will rollback change
COMMIT;
# commited
```
Use a `transaction` to rollback the full change or it will get rolled back if it is not committed.
Two different sessions are isolated from each other. A transaction that is only partly
done is not visible to another connection. Within the transaction you can see the new
state of the data. Outside of the transaction you can see the old value. The readers
outside of the transaction are protected from uncommited change.
Readers never block writers and writers never block readers. :magic:
What happens if I try to update that account while another transaction is open elsewhere?
Now it's not as easy to uphold the illusion. It will block the write by using a row lock.
Data modifying statement will take an exclusive lock on the row. This is compatible with
a read but another update will need to take an exclusive lock.
* Read committed is the default isolation level.
* You never see any dirty reads. Or see data from uncommitted transactions.
```sql
BEGIN;
SELECT amount FROM account WHERE id = 2;
UPDATE account SET amount = 10300 WHERE id = 2;
# from another connection
RESET lock_timeout;
UPDATE account SET amount = 10300 WHERE id = 2; # will block because of the other trx in another connection
```
## Pessimistic locking
```sql
SELECT amount from account WHERE id = 2 FOR UPDATE; # pessimisstic lock on row
```
`FOR UPDATE`: all the selected rows will be locked. Lots of locking if joins are involved.
`FOR UPDATE of account`: will lock only rows in the `account` table.
`FOR UPDATE NOWAIT`: it wont wait at all. It gets the lock immediately or fails immediately.
`FOR UPDATE SKIP LOCKED`: appears as if the row does not exist. (weird) useful for implementing something like a queue in the database.
```sql
SELECT * from jobs LIMIT 1 FOR UPDATE SKIP LOCKED; # fetch next item from a queue of jobs
```
## Optimistic Locking
4 isolation levels:
* read uncommitted
* read committed
* repeatable read
* serializable

Isolation level: repeatable read
Will make sure that you continue to see the stale read within a transaction if
the same row was modified and committed in another transaction.
```sql
BEGIN ISOLATION LEVEL REPEATABLE READ;
SELECT amount FROM account WHERE id = 2;
UPDATE account SET amount = 100 WHERE id = 2;
```
Pessimistic locking means blocking and taking more locks. Optimistic locking
means retrying a transaction when a collision occurs.
### How does Postgresql do this?
```sql
SELECT * FROM account;
SELECT ctid, xmin, xmax, * FROM account;
# SELECT ctid, xmin, xmax, * FROM account;
ctid | xmin | xmax | id | name | amount
-------+------+------+----+---------+---------
(0,2) | 616 | 0 | 2 | george | 1000.00
(0,3) | 617 | 0 | 1 | laurenz | 900.00
(2 rows)
Time: 0.432 ms
```
* ctid: physical location of table row. (number of 8 block,entry in the block) (0,2) => 0 block, entry 2.
Instead of modifying an existing row, it creates a new row and leaves the original row in place.
This allows stale readers to continue to read from the old location. Who sees what is the difference.
`xmin` and `xmax` determines who sees what. Every modification is assigned a transaction id
```sql
Time: 2.664 ms
[local:/home/mokha/development/2020-04-pg-training/tmp/sockets]/course=
# SELECT ctid, xmin, xmax, * FROM account;
ctid | xmin | xmax | id | name | amount
-------+------+------+----+---------+---------
(0,2) | 616 | 0 | 2 | george | 1000.00
(0,3) | 617 | 0 | 1 | laurenz | 900.00
(2 rows)
Time: 0.370 ms
# SELECT txid_current();
txid_current
--------------
618
(1 row)
```
* xmin: id of transaction that introduced the row
* xmax: id of transaction that invalidated the row. (0) means it's not invalidated and still in use.
Commit log is stored on disk.
Commit log has the id of each transaction and provides the current state of the transaction.
## Locks
* table level locks
* row level locks
* `CREATE INDEX CONCURRENTLY`
How to view locks:
```sql
BEGIN;
TRUNCATE account;
# SELECT pg_backend_pid();
pg_backend_pid
----------------
1827882
(1 row)
Time: 2.159 ms
# SELECT * FROM pg_locks WHERE pid = 1827882;
SELECT oid FROM pg_class WHERE relname = 'account';
# SELECT oid FROM pg_class WHERE relname = 'account';
oid
-------
16588
(1 row)
SELECT 16588::oid::regclass;
# SELECT 16588::oid::regclass;
regclass
----------
account
(1 row)
Time: 0.224 ms
SELECT relation::regclass, mode from pg_locks where pid = 1827882;
# SELECT relation::regclass, mode from pg_locks where pid = 1827882;
relation | mode
-----------------------------------+---------------------
pg_class_tblspc_relfilenode_index | AccessShareLock
pg_class_relname_nsp_index | AccessShareLock
pg_class_oid_index | AccessShareLock
pg_class | AccessShareLock
pg_locks | AccessShareLock
[NULL] | ExclusiveLock
account | AccessShareLock
account | ShareLock
account | AccessExclusiveLock
pg_toast.pg_toast_16588 | ShareLock
pg_toast.pg_toast_16588 | AccessExclusiveLock
pg_toast.pg_toast_16588_index | AccessExclusiveLock
[NULL] | ExclusiveLock
account_pkey | AccessShareLock
account_pkey | AccessExclusiveLock
(15 rows)
Time: 0.662 ms
```
Let's create a deadlock.
session1
```sql
BEGIN;
UPDATE account SET amount = amount + 100 WHERE id = 1;
# switch to session 2
UPDATE account SET amount = amount - 100 WHERE id = 2;
```
session2
```sql
BEGIN;
UPDATE account SET amount = amount + 100 WHERE id = 2;
UPDATE account SET amount = amount - 100 WHERE id = 1;
# switch to session 1
```
pg runs a deadlock detector that will abort one of the transactions to remove
the deadlock. The other transaction is unaware that the other transaction was aborted.
Bow and array analogy. 1 person grabs bow and the other person grabs the arrow.
```sql
CREATE TABLE guard_on_duty(prison text NOT NULL, guard text NOT NULL);
INSERT INTO guard_on_duty VALUES('alcatraz', 'alice');
INSERT INTO guard_on_duty VALUES('alcatraz', 'bob');
INSERT INTO guard_on_duty VALUES('st. quentin', 'joe');
BEGIN ISOLATION LEVEL REPEATABLE READ;
SELECT COUNT(*) from guard_on_duty where prison = 'alcatraz';
```
```sql
CREATE TABLE parent(pid integer PRIMARY KEY);
INSERT into parent VALUES (1), (2);
CREATE TABLE child(cid integer not null, pid integer not null);
INSERT INTO child SELECT i, 1 FROM generate_series(1, 1000000) AS i;
SELECT * FROM generate_series(1, 10);
ALTER TABLE child ADD FOREIGN KEY (pid) REFERENCES parent;
BEGIN;
DELETE FROM parent WHERE pid = 1;
EXPLAIN (ANALYZE) DELETE FROM parent WHERE pid = 2; # ANALYZE actually runs delete
```
Foreign key constraints are implemented with triggers in pg.
You should also create an index on the foreign key constraint.
## Vacuum
```sql
VACUUM (VERBOSE) account;
```
`autovacuum launcher` process starts the vacuum jobs when it detects
a certain percentage of the table are dead rows. It doesn't make
the table smaller, it becomes emptier. It does impact runtime operations.
```sql
SELECT ctid, xmin, xmax * FROM account;
```
Bulk operations are a good reason to run a manual vacuum.
E.g.
```sql
UPDATE account SET amount = 0; # this creates a new entry for every row in the db.
```
Do the update in batches and run the vacuum explicitly, to free the data as
needed rather than waiting for the vacuum process to pick it up.

Every table has a companion called the visibility map.
This map is small and contains only two bits for each 8k block of the table.
It tells us if all items in the block is visible to all transactions.
An index scan will check the visibility map which is always cached in
memory to consult the two bits for the block to know that all entries
in the block is visible. This allows us to know that all entries in the
block is usable. One necessary pre-requisite is that most of the blocks
must be visible. Vacuum has a side job to maintain the visibility map.
Vacuum looks at all the table rows and removes the non visible ones.
```sql
EXPLAIN (ANALYZE) SELECT id FROM test WHERE id < 10000;
```
## Auto vacuum configuration
```sql
ALTER TABLE account SET (autovacuum_vacuum_scale_factor = 0.01);
SHOW log_autovacuum_min_duration;
\d pg_stat_all_tables; # wealth of info about the tables
```
If we update a row, that creates a new row version which is probably in another block.
We need to create a new index entry that points to a new table block.
One update can dirty 3 blocks with dead tuples.
Optimization:
* create new entry in the same block and link old entry to the new entry. HOT heap only tuple.
* nice to only touch one block, also need to touch index because it points to old row, then find pointer to new entry in the same block file.
```sql
CREATE TABLE hot(id bigint PRIMARY KEY, val text) WITH (fillfactor = 70); # only insert into block files with at least 30% free space.
```
pg was originally written in lisp as a research project.
## Functions
One of the ways where pg shows how wonderfully extensible it is.
```sql
# CREATE EXTENSION<tab>
adminpack dict_xsyn intagg pgcrypto sslinfo
amcheck earthdistance intarray pg_freespacemap tablefunc
autoinc file_fdw isn pg_prewarm tcn
bloom fuzzystrmatch lo pgrowlocks timetravel
btree_gin hstore ltree pg_stat_statements tsm_system_rows
btree_gist hstore_plperl ltree_plpython2u pgstattuple tsm_system_time
chkpass hstore_plperlu ltree_plpython3u pg_trgm unaccent
citext hstore_plpython2u ltree_plpythonu pg_visibility "uuid-ossp"
cube hstore_plpython3u moddatetime postgres_fdw xml2
dblink hstore_plpythonu pageinspect refint
dict_int insert_username pg_buffercache seg
```
You can write stored procedures in perl, python, tcl, c or sql.
```sql
# \h CREATE LANGUAGE
Command: CREATE LANGUAGE
Description: define a new procedural language
Syntax:
CREATE [ OR REPLACE ] [ PROCEDURAL ] LANGUAGE name
CREATE [ OR REPLACE ] [ TRUSTED ] [ PROCEDURAL ] LANGUAGE name
HANDLER call_handler [ INLINE inline_handler ] [ VALIDATOR valfunction ]
```
```sql
# \h CREATE FUNCTION
Command: CREATE FUNCTION
Description: define a new function
Syntax:
CREATE [ OR REPLACE ] FUNCTION
name ( [ [ argmode ] [ argname ] argtype [ { DEFAULT | = } default_expr ] [, ...] ] )
[ RETURNS rettype
| RETURNS TABLE ( column_name column_type [, ...] ) ]
{ LANGUAGE lang_name
| TRANSFORM { FOR TYPE type_name } [, ... ]
| WINDOW
| IMMUTABLE | STABLE | VOLATILE | [ NOT ] LEAKPROOF
| CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
| [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
| PARALLEL { UNSAFE | RESTRICTED | SAFE }
| COST execution_cost
| ROWS result_rows
| SET configuration_parameter { TO value | = value | FROM CURRENT }
| AS 'definition'
| AS 'obj_file', 'link_symbol'
} ...
[ WITH ( attribute [, ...] ) ]
```
A function always returns something.
You must specify which language you would like to use.
A function always runs in the back end as the postgres operating system user.
It could delete files on the database server and other things that are not so nice.
This can be potentially unsafe. Languages are divided into trusted and untrusted languages.
```sql
CREATE FUNCTION doubleme(i integer) RETURNS integer LANUGAGE sql AS 'SELECT i * 2';
SELECT doubleme(21);
```
We can also have a function that returns more than one value by specifying `in` and `out` parameters.
```sql
CREATE FUNCTION another (IN i integer, OUT x integer, OUT y integer) RETURNS record LANGUAGE sql AS 'SELECT i, i + 5';
# SELECT another(2);
another
---------
(2,7)
```
Or return a set of records.
```sql
CREATE FUNCTION tabf (IN i integer, OUT x integer, OUT y integer) RETURNS SETOF record LANGUAGE sql AS 'SELECT i, j FROM generate_series(1, i) AS j';
# SELECT * from tabf(5);
x | y
---+---
5 | 1
5 | 2
5 | 3
5 | 4
5 | 5
```
## Functions Part ||
When to use it? When to not?
* You can write code in the database or you can do it in the client in your program or application.
* Should we put code in the database or not?
* No extreme is totally right.
* It depends on what you prefer to be dependent on.
* Triggers are run when specific actions occur in the database. It's guaranteed to run.
* always runs in the same transaction as the statement that triggers it.
```sql
# \h CREATE FUNCTION
Command: CREATE FUNCTION
Description: define a new function
Syntax:
CREATE [ OR REPLACE ] FUNCTION
name ( [ [ argmode ] [ argname ] argtype [ { DEFAULT | = } default_expr ] [, ...] ] )
[ RETURNS rettype
| RETURNS TABLE ( column_name column_type [, ...] ) ]
{ LANGUAGE lang_name
| TRANSFORM { FOR TYPE type_name } [, ... ]
| WINDOW
| IMMUTABLE | STABLE | VOLATILE | [ NOT ] LEAKPROOF
| CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
| [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
| PARALLEL { UNSAFE | RESTRICTED | SAFE }
| COST execution_cost
| ROWS result_rows
| SET configuration_parameter { TO value | = value | FROM CURRENT }
| AS 'definition'
| AS 'obj_file', 'link_symbol'
} ...
[ WITH ( attribute [, ...] ) ]
```
* AS `definition`.
The code is always a string constant for a function.
```sql
CREATE FUNCTION hello() RETURNS text LANGUAGE sql AS 'SELECT 'hello world'';
# to escape double the single quotes
CREATE FUNCTION hello() RETURNS text LANGUAGE sql AS 'SELECT ''hello world''';
# but this is cumbersome. another way to quote string is to sue $ quoting.
SELECT $abc$hello$abc$;
SELECT $abc$hello' $_$string$_$$abc$;
CREATE FUNCTION hello() RETURNS text LANGUAGE sql AS $$SELECT 'hello world'$$;
CREATE OR REPLACE FUNCTION hello() RETURNS text LANGUAGE sql AS $$SELECT 'hello world'$$;
```
* AS 'obj_file', 'link_symbol' : for interop to shared libraries.
* TRANSFORM for mapping types in a programming lang to pg data types.
* WINDOW functions are extremely powerful and wonderful.
* must be written in C.
* COST
For explain to know the cost of a query it needs to know the cost of a function.
If you don't specify the cost when you declare a function then pg uses a default cost of 100.
It's good to specify a realistic cost on a function so that the query optimizer can
avoid costly functions where it can.
STABLE functions are functions that read from the database. They do not modify the database,
they do not change other state, they maybe read from the database and do some evaluation
on that.
In the `CREATE FUNCTION` declaration you must declare whether it is `IMMUTABLE`, `STABLE`, `VOLATILE`
otherwise it will use the default of `VOLATILE`. This is relavent for performance.
Choosing the proper volatility will impact performance.
```sql
SELECT pi(); # immutable
SELECT random(); # volatile. not stable returns different values each time.
# explain select pi() from test;
QUERY PLAN
--------------------------------------------------------------
Seq Scan on test (cost=0.00..96922.56 rows=6291456 width=8)
(1 row)
# explain select random() from test;
QUERY PLAN
---------------------------------------------------------------
Seq Scan on test (cost=0.00..112651.20 rows=6291456 width=8)
(1 row)
# pi() is called once because of immutable volatility
# explain (VERBOSE) select pi() from test;
QUERY PLAN
---------------------------------------------------------------------
Seq Scan on public.test (cost=0.00..96922.56 rows=6291456 width=8)
Output: '3.14159265358979'::double precision
# random() is called once for each row because of volatile volatility.
# explain (VERBOSE) select random() from test;
QUERY PLAN
----------------------------------------------------------------------
Seq Scan on public.test (cost=0.00..112651.20 rows=6291456 width=8)
Output: random()
```
### Function inlining:
* Only works for SQL language functions.
```sql
CREATE FUNCTION addon(integer) RETURNS integer LANGUAGE sql AS 'SELECT $1 + 1';
# $1 for first unnamed argument
EXPLAIN (VERBOSE) SELECT addone(id::integer) FROM test;
```
Optimizer can use the inline function declaration and optimize it.
### Triggers
A trigger in pg works with two objects.
* First is a trigger function. (something that `RETURNS trigger`. no real meaning just syntax stuff)
```sql
# \h CREATE TRIGGER
Command: CREATE TRIGGER
Description: define a new trigger
Syntax:
CREATE [ CONSTRAINT ] TRIGGER name { BEFORE | AFTER | INSTEAD OF } { event [ OR ... ] }
ON table_name
[ FROM referenced_table_name ]
[ NOT DEFERRABLE | [ DEFERRABLE ] [ INITIALLY IMMEDIATE | INITIALLY DEFERRED ] ]
[ REFERENCING { { OLD | NEW } TABLE [ AS ] transition_relation_name } [ ... ] ]
[ FOR [ EACH ] { ROW | STATEMENT } ]
[ WHEN ( condition ) ]
EXECUTE PROCEDURE function_name ( arguments )
where event can be one of:
INSERT
UPDATE [ OF column_name [, ... ] ]
DELETE
TRUNCATE
```
* `{ BEFORE | AFTER | INSTEAD OF }`: When to run the trigger.
* sometimes you want a trigger to modify the data or add a default value.
* `BEFORE` trigger
* can modify the data before they hit the table.
* can also cancel the action by erroring out before the insert or update.
* `AFTER` trigger
* Useful for `DEFERRABLE` functions. Can delay the execution of the trigger to the end of the transaction.
* `ROW` and `STATEMENT` level triggers.
* for each row. gives you the affected row.
* or for each statement. doesn't give you the affected row(s)
* Transition tables are something that you can use in statement level triggers.
* You get both the old and new table of rows in the function.
* Can build a safe guard to not allow deletes more than 5 rows.
```sql
CREATE TABLE realdata (
id bigint GENERATED BY DEFAULT AS IDENTITY NOT NULL,
value text,
valid tstzrange DEFAULT tstzrange(current_timestamp, NULL) NOT NULL,
EXCLUDE USING gist (valid WITH &&, id WITH =) # with overlap and equal
)
CREATE VIEW data AS SELECT id, value FROM realdata WHERE valid @> current_timestamp;
```
```sql
SELECT '2020-01-01'::timestamp WITH TIME ZONE;
SELECT '2020-01-01'::timestampz;
CREATE TABLE aside(x timestamp with time zone);
INSERT INTO aside VALUES ('2020-01-01 00:00:00');
SHOW timezone;
SET timezone = 'Europe/Vienna';
```
timestamps stored in utc as an 8 byte integer.
timestampz will convert to the timezone parameter.
```sql
# \dx
List of installed extensions
Name | Version | Schema | Description
---------+---------+------------+-------------------------------------------------------------------
citext | 1.4 | public | data type for case-insensitive character strings
pg_trgm | 1.3 | public | text similarity measurement and index searching based on trigrams
plpgsql | 1.0 | pg_catalog | PL/pgSQL procedural language
\e -- open editor
-- PL/pgSQL is a rip-off of plsql from oracle.
CREATE FUNCTION data_trig() RETURNS trigger LANGUAGE plpgsql
AS $$
BEGIN -- not same as starting a transaction. this is the start of a plpgsql statement.
CASE TG_OP -- variable that available in a trigger function.
WHEN 'INSERT' THEN
IF NEW.id IS NULL THEN
INSERT INTO realdata (value) VALUES (NEW.value);
ELSE
INSERT INTO realdata (id, value) VALUES (NEW.id, NEW.value);
END IF;
RETURN NEW;
WHEN 'DELETE' THEN
UPDATE realdata SET valid = tstzrange(lower(valid), current_timestamp)
WHERE id = OLD.id AND valid @> TIMESTAMPZ 'infinity';
RETURN OLD;
WHEN 'UPDATE' THEN
UPDATE realdata SET valid = tstzrange(lower(valid), current_timestamp)
WHERE id = OLD.id AND valid @> TIMESTAMPZ 'infinity';
INSERT INTO realdata (id, value) VALUES (NEW.id, NEW.value);
RETURN NEW;
END CASE;
END;
$$;
CREATE TRIGGER data_trig INSTEAD OF INSERT OR UPDATE OR DELETE ON data
FOR EACH ROW EXECUTE PROCEDURE data_trig();
INSERT INTO data (value) VALUES ('first');
TABLE data;
UPDATE data SET value = 'changed' WHERE id = 1;
TABLE realdata;
SELECT id, value FROM realdata WHERE valid @> '2020-04-29 17:18:37';
```
[TG_OP](https://www.postgresql.org/docs/11/plpgsql-trigger.html)
* `NEW`
* `OLD`
Depending on the context you will have access to different globals in the context of the
function.
```sql
-- describe operator
# \do @>
List of operators
Schema | Name | Left arg type | Right arg type | Result type | Description
------------+------+---------------+----------------+-------------+-------------
pg_catalog | @> | aclitem[] | aclitem | boolean | contains
pg_catalog | @> | anyarray | anyarray | boolean | contains
pg_catalog | @> | anyrange | anyelement | boolean | contains
pg_catalog | @> | anyrange | anyrange | boolean | contains
pg_catalog | @> | box | box | boolean | contains
pg_catalog | @> | box | point | boolean | contains
pg_catalog | @> | circle | circle | boolean | contains
pg_catalog | @> | circle | point | boolean | contains
pg_catalog | @> | jsonb | jsonb | boolean | contains
pg_catalog | @> | path | point | boolean | contains
pg_catalog | @> | polygon | point | boolean | contains
pg_catalog | @> | polygon | polygon | boolean | contains
pg_catalog | @> | tsquery | tsquery | boolean | contains
-- source of function
\sf trig
```
```sql
\h CREATE EVENT TRIGGER
```
## Views
Postgres wont let you drop a table if a view depends on it. pg tracks
dependencies to make sure that you don't break the consistency of the database.
Renaming a table will also update the reference to the table name in the view.
You can use a trigger to keep a materialized view current.
```sql
# \h CREATE MATERIALIZED VIEW
Command: CREATE MATERIALIZED VIEW
Description: define a new materialized view
Syntax:
CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] table_name
[ (column_name [, ...] ) ]
[ WITH ( storage_parameter [= value] [, ... ] ) ]
[ TABLESPACE tablespace_name ]
AS query
[ WITH [ NO ] DATA ]
# \h REFRESH MATERIALIZED VIEW
Command: REFRESH MATERIALIZED VIEW
Description: replace the contents of a materialized view
Syntax:
REFRESH MATERIALIZED VIEW [ CONCURRENTLY ] name
[ WITH [ NO ] DATA ]
```
## Procedures
Procedures do not return anything.
Only added in pg 11.
* can commit and rollback transactions and support is very limited and very early stages. lots of limitations.
You cannot use a savepoint in a function or procedure but you can do something equivalent.
```sql
BEGIN;
BEGIN
-- possible error here
EXCEPTION -- implicit rollback to savepoint
WHEN division_by_zero THEN
--- exception handling code
END;
END;
```
## Architecture of postgres for performance
* Each client connection produces an process.
```bash
モ ps | grep postgres
| \_ postgres -F -D /home/mokha/development/2020-04-pg-training/db/data -k /home/mokha/development/2020-04-pg-training/tmp/sockets
| \_ postgres: logger process
| \_ postgres: checkpointer process
| \_ postgres: writer process
| \_ postgres: wal writer process
| \_ postgres: autovacuum launcher process
| \_ postgres: stats collector process
| \_ postgres: bgworker: logical replication launcher
| \_ postgres: mokha course [local] idle
| \_ psql -h /home/mokha/development/2020-04-pg-training/tmp/sockets postgres
```

* every process that looks for a block.
* find a free space in shared buffers.
```text
------------
| backends |
------------
|
|-------------|
| make change in wal before change is accepted in the system.
-------------------------------
| shared buffers | wal buffer|
| -------------- |------------
| |copy of block| | lock | |
| -------------- |------- |
| | |
| | |
| | | wal writer
------------------- |
| |
V V
------------- ------------- WAL ----
| disk | | |
| | | |
| 8k blocks | ----------------------
-------------
A
|
-----------
| bg writer |
----------
|
|
---------------
| checkpointer | every 5 minutes pull from shared buffers and clean dirty buffers
---------------
```
* we could write every block to disk every time we get it. bad perf
* we also want to commit to disk
* transaction log -> wal -> write ahead log
* read the block from shared buffers.
* the transaction log is used to repair a database after a crash.
Some databases use a technique known as direct i/o which skips the operating
system. pg issues a write to the kernel. So just because it sent a
write to the kernel doesn't mean that it has hit the iron.
`fsync` is necessary to flush to disk.
Example:
```sql
CREATE TABLE waltest (id integer);
-- x 30K
INSERT INTO waltest VALUES(1);
```
Without an explicit transaction then it will create an implicit
transaction for each insert statement which will call `fsync`
for each transaction which is slow and will bottleneck on I/O.
It's better to wrap in a transaction to fsync once rather than 30K times.
## Data directory tour
* base: default table space. actual data is stored here
* 1
* 13880 : object id of database
* 13881 : object id of database
* 16384 : object id of `course` database
* `*_fsm` free space map file
* `*_vm` file is.
* pgsql_tmp
* postgresql.conf
* global settings or default values.
* `ALTER SYSTEM SET enable_seqscan = off;`
* this updates the `postgresql.auto.conf`
## Configuration
* `shared_buffers = 128MB` is the default. This is too small and perf will suck.
* how big? no single good answer.
* start with 1/4 of available RAM but not more than 8GB.
* 8GB is max because we also have the file system cache on top of that.
* You might run into double cache if you choose a higher cache size because you will have a shared buffer cache and a file system cache.
```sql
CREATE EXTENSION pg_buffercache;
\d pg_buffercache;
SELECT usagecount, count(*)
FROM pg_buffercache GROUP BY 1 ORDER BY 1;
```
* `huge_pages = try` is good to use on linux.
* `work_mem` default is 4MB.
* `max_connections` has a default of 100. This can be a rather high default.
* `synchronous_commit = on` default is `on`. Setting it to `off` means not every commit will flush to the transaction log.
* `commit_delay` default to `0`. Can be used to batch transaction to log. Will wait 5 seconds to see what else needs to be flushed and flush them together. Does make transactions a little bit longer.
```text
RAM >= shared_buffers + (work_mem * max_connections)
```
If you're generous with `max_connections` then you cannot be generous with `work_mem`
but `work_mem` has value in performing queries faster. If you can lower `max_connections`
then you can increase `work_mem` which will serve those connections faster.
```sql
CREATE TABLE mem (id serial, name text);
INSERT INTO mem (name) SELECT 'carl' FROM generate_series(1, 100000);
INSERT INTO mem (name) SELECT 'paul' FROM generate_series(1, 100000);
ANALYZE mem;
VACUUM mem;
EXPLAIN SELECT name, count(*) FROM mem GROUP BY name;
SET max_parallel_workers_per_gather = 0;
EXPLAIN SELECT name, count(*) FROM mem GROUP BY name;
EXPLAIN id, count(*) FROM mem GROUP BY id;
SET work_mem = '1GB';
-- now same query can use HashAggregate which is faster.
EXPLAIN id, count(*) FROM mem GROUP BY id;
```
* HashAggregate: piece of paper with two sections. Do a sequential scan and make a tick on the left and on the right.
* GroupAggregate: hash wouldn't fit in work mem so move to group. Sort them then count them as they pass by.
Larger `work_mem` can make some queries operate faster.
Sorting rows in memory is faster than having to spill to disk.
Too many idle connections is a risk because if those idle connections become active
then this can overwhelm the resources available.
Try to keep `max_connections` down. How? use a connection pooler

```text
------------------
| app | app | app |
------------------
| pool|pool| pool | <- not needed anymore with a connection pooler
------------------
| | | | | | | | |
| | | | | | | | |
---------------------
| connection pooler | <- re-use connections (pgbouncer)
---------------------
| | |
| | |
----------
| db | <- limit the # of connections
----------
```
* You don't want more processes than CPU cores. CPU bound.
* You don't want more `work_mem` * `max_connections` to be more than the available RAM.
## pgbench
```bash
$ pgbench -h $PWD/tmp/sockets -i -s 100 dbname
$ pgbench -c 10 -T 30
# simulate an application that opens and closes connections constantly
$ pgbench -C -c 10 -T 30
```
## Security
Users permissions and related things.
`postgres` user is a `SUPERUSER` they can do anything. It's like the
root user in unix systems. Permissions are inspired by file system
permissions. pg doesn't have users it has roles.
A role is a user and a user group. There is no difference.
Some roles are `LOGIN` roles and some are not.
```sql
# \h CREATE ROLE
Command: CREATE ROLE
Description: define a new database role
Syntax:
CREATE ROLE name [ [ WITH ] option [ ... ] ]
where option can be:
SUPERUSER | NOSUPERUSER
| CREATEDB | NOCREATEDB
| CREATEROLE | NOCREATEROLE
| INHERIT | NOINHERIT
| LOGIN | NOLOGIN
| REPLICATION | NOREPLICATION
| BYPASSRLS | NOBYPASSRLS
| CONNECTION LIMIT connlimit
| [ ENCRYPTED ] PASSWORD 'password'
| VALID UNTIL 'timestamp'
| IN ROLE role_name [, ...]
| IN GROUP role_name [, ...]
| ROLE role_name [, ...]
| ADMIN role_name [, ...]
| USER role_name [, ...]
| SYSID uid
```
```sql
# \h CREATE USER
Command: CREATE USER
Description: define a new database role
Syntax:
CREATE USER name [ [ WITH ] option [ ... ] ]
where option can be:
SUPERUSER | NOSUPERUSER
| CREATEDB | NOCREATEDB
| CREATEROLE | NOCREATEROLE
| INHERIT | NOINHERIT
| LOGIN | NOLOGIN
| REPLICATION | NOREPLICATION
| BYPASSRLS | NOBYPASSRLS
| CONNECTION LIMIT connlimit
| [ ENCRYPTED ] PASSWORD 'password'
| VALID UNTIL 'timestamp'
| IN ROLE role_name [, ...]
| IN GROUP role_name [, ...]
| ROLE role_name [, ...]
| ADMIN role_name [, ...]
| USER role_name [, ...]
| SYSID uid
```
Create user is the same as create role except that it will create it
with `LOGIN`.
3 things that roles can be:
* SUPERUSER
* CREATEDB
* CREATEROLE
Don't use a super user for an application. `SUPERUSER` is meant
to be use for admistration. Limit the use of `SUPERUSER`.
You can specify a connection limit for a user.
You can expire an account at some timestamp.
```sql
# not smart to specify a password like this.
# it will be stored in psql history file.
# it will be sent in clear text to server.
# We don't know what statements will end up in the database log.
CREATE ROLE joe LOGIN PASSWORD 'secret';
```
```sql
- create user without password.
CREATE ROLE joe LOGIN;
```
Storing passwords in the database is not great security.
You can tell pg to use an external authority server.
* kerberos
* radius
Use `\password` command. This is more secure.
```psql
\password joe
```
```sql
CREATE ROLE logistics;
GRANT logistics TO JOE;
# \du
List of roles
Role name | Attributes | Member of
-----------+------------------------------------------------------------+-------------
joe | | {logistics}
logistics | Cannot login | {}
mokha | Superuser, Create role, Create DB, Replication, Bypass RLS | {}
```
Each database object has an owner.
```sql
# \dt
List of relations
Schema | Name | Type | Owner
--------+------------------+-------+-------
public | account | table | mokha
public | guard_on_duty | table | mokha
public | pgbench_accounts | table | mokha
public | pgbench_branches | table | mokha
public | pgbench_history | table | mokha
public | pgbench_tellers | table | mokha
public | waltest | table | mokha
```
Only owner may alter an object. Only an owner may drop an object.
Owner can delegating granting priviliges. This is a great way
to lose control of your db.
There are also system users and groups. They start with `pg_` prefix.
```sql
# \duS+
List of roles
-[ RECORD 1 ]-------------------------------------------------------------
Role name | joe
Attributes |
Member of | {logistics}
Description |
-[ RECORD 2 ]-------------------------------------------------------------
Role name | logistics
Attributes | Cannot login
Member of | {}
Description |
-[ RECORD 3 ]-------------------------------------------------------------
Role name | mokha
Attributes | Superuser, Create role, Create DB, Replication, Bypass RLS
Member of | {}
Description |
-[ RECORD 4 ]-------------------------------------------------------------
Role name | pg_monitor
Attributes | Cannot login
Member of | {pg_read_all_settings,pg_read_all_stats,pg_stat_scan_tables}
Description |
-[ RECORD 5 ]-------------------------------------------------------------
Role name | pg_read_all_settings
Attributes | Cannot login
Member of | {}
Description |
-[ RECORD 6 ]-------------------------------------------------------------
Role name | pg_read_all_stats
Attributes | Cannot login
Member of | {}
Description |
-[ RECORD 7 ]-------------------------------------------------------------
Role name | pg_signal_backend
Attributes | Cannot login
Member of | {}
Description |
-[ RECORD 8 ]-------------------------------------------------------------
Role name | pg_stat_scan_tables
Attributes | Cannot login
Member of | {}
Description |
# SHOW data_directory;
data_directory
-----------------------------------------------------
/home/mokha/development/2020-04-pg-training/db/data
```
Obstacles:
* listen addresses
* authentation (pg_hba.conf)
* database
* schema (create, usage)
* tables
* columns
* row level security

Default listen address is on loopback interface.
```sql
# SHOW listen_addresses;
listen_addresses
------------------
localhost
(1 row)
```
To change the listen address change in the postgresqlconf
`listen_adresses = '*'`
```bash
psql -h 64.225.109.133 -U joe course
```
To turn on authentication:
* pg_hba.conf
* list of
```bash
cat pg_hba.conf
# TYPE DATABASE USER ADDRESS METHOD
# "local" is for Unix domain socket connections only
local all all trust
# IPv4 local connections:
host all all 127.0.0.1/32 trust
# IPv6 local connections:
host all all ::1/128 trust
# Allow replication connections from localhost, by a user with the
# replication privilege.
local replication all trust
host replication all 127.0.0.1/32 trust
host replication all ::1/128 trust
```
pg reads ^ that file from top to bottom to see what matches when a
client connects. `trust` mean no password is needed for `local all`.
`peer` only for local, like `trust` but the pg user needs to match the
operating system user.
```text
host course joe 0.0.0.0/0 md5 # add this entry above other.
``
```bash
pg_ctl -D var/lib.../data -l logfile reload # to reload the pg_hba.conf file
```
```sql
# \dn
List of schemas
Name | Owner
--------+----------
myapp | postgres
public | postgres
(2 rows)
```
* To use an object in a schema you need the usage privilege.
```sql
# \dx+ pg_buffercache ;
Objects in extension "pg_buffercache"
Object description
---------------------------------
function pg_buffercache_pages()
view pg_buffercache
(2 rows)
# \dn+
List of schemas
Name | Owner | Access privileges | Description
--------+----------+----------------------+------------------------
myapp | postgres | |
public | postgres | postgres=UC/postgres+| standard public schema
| | =UC/postgres |
(2 rows)
```
ACL access controll list
* postgres=UC/postgres
* <role>=UC/<role that granted the privilege, usually the owner>
* =UC/postgres
* space before `=` means it is granted to everybody.
```sql
# \dnS
List of schemas
Name | Owner
--------------------+-------
information_schema | mokha
pg_catalog | mokha
pg_temp_1 | mokha
pg_toast | mokha
pg_toast_temp_1 | mokha
public | mokha
(6 rows)
TABLE pg_attribute;
```
* pg_catalog:
* information_schema:
* includes metadata of the db in a user friendly way.
One way is to always fully qualify objects. Another way is to never do it
and control the search path.
```sql
# CREATE SCHEMA myapp;
# CREATE TABLE myapp.new (x inet);
# SHOW search_path;
search_path
-----------------
"$user", public
(1 row)
SET search_path = myapp, public;
```
```sql
\h GRANT
GRANT SELECT ON account TO logistics;
\dp -- to view view privileges
# \dp account
Access privileges
Schema | Name | Type | Access privileges | Column privileges | Policies
--------+---------+-------+-------------------+-------------------+----------
public | account | table | | |
# \dp account
Access privileges
Schema | Name | Type | Access privileges | Column privileges | Policies
--------+---------+-------+---------------------------+-------------------+----------
public | account | table | postgres=arwdDxt/postgres+| |
| | | logistics=r/postgres | |
(1 row)
SELECT * FROM aclexplode('{postgres=arwdDxt/postgres}');
# SELECT * FROM aclexplode('{postgres=arwdDxt/postgres}');
grantor | grantee | privilege_type | is_grantable
---------+---------+----------------+--------------
10 | 10 | INSERT | f
10 | 10 | SELECT | f
10 | 10 | UPDATE | f
10 | 10 | DELETE | f
10 | 10 | TRUNCATE | f
10 | 10 | REFERENCES | f
10 | 10 | TRIGGER | f
(7 rows)
```
* don't use `*` in `SELECT * from table JOIN b;` be explicit about the columns to fetch.
* `SELECT count(*) FROM a` == `SELECT count() FROM`
* `SELECT count(1)` is worse performance than `SELECT count(*)`
Make privileges depend on the group and not the user.
```sql
CREATE ROLE read_only NOLOGIN;
```
We can change the default privileges for objects that are created in the future.
```sql
ALTER DEFAULT PRIVILEGES FOR ROLE postgres IN SCHEMA myapp GRANT SELECT ON TABLES TO read_only;
```
Tools for security
* functions
* LEAKPROOF
* SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER
```sql
CREATE FUNCTION harmless(integer) RETURNS integer LANGUAGE sql SECURITY DEFINER AS 'SELECT $1 + 1';
```
Create shadow function in public schema that is picked up by the search path.
```sql
# CREATE OR REPLACE FUNCTION myapp.harmless(integer) RETURNS integer LANGUAGE plpgsql SECURITY DEFINER AS
$$
BEGIN
ALTER USER joe WITH SUPERUSER;
SELECT $1 + 1;
END
$$;
```
```sql
CREATE FUNCTION public.sum(integer, integer) RETURNS integer LANGUAGE sql AS 'ALTER ROLE joe SUPERUSER; SELECT $1 + $2';
```
Override the `+` operator in the public schema.
Modify the search path to pick up the new `+` operator.
```sql
CREATE OPERATOR public.+ (LEFTARG = integer, RIGHTARG = integer, FUNCTION = public.sum);
SET search_path = public, pg_catalog;
SELECT myapp.harmless(41);
```
To avoid, specify the `search_path` on SECURITY DEFINER functions.
```sql
ALTER FUNCTION myapp.harmless SET search_path = pg_catalog;
```
```sql
CREATE FUNCTION leak(bigint, text) RETURNS bigint LANGUAGE plpgsql COST 1 AS
$$
BEGIN
RAISE NOTICE 'id = %, value = %', $1, $2;
RETURN $1;
END;
$$
```
```sql
ALTER VIEW data SET (security_barrier = true);
```
```sql
CREATE FUNCTION AS LEAKPROOF -- tell pg to optimize it into a security barrier view.
```
Encrypt the filesystem where the data sits. pg 14 might have support for db level encryption.
`pg_crypto` extension for hashing, encryption.
It's possible to also enable tls connections to the pg server. There are settings in the conf file
to specify the crt and key.
## SQL Injection
User input is not to be trusted.
When statement is constructed using user input this is problematic.
```sql
CREATE FUNCTION count_rows(tablename text) RETURNS bigint LANGUAGE plpgsql AS
$$
DECLARE
sql text;
res bigint;
BEGIN
sql := 'SELECT count(*) FROM ' || tablename;
EXECUTE sql INTO res;
RETURN res;
END;
$$
```
Test for sqli, feed it a single quote;
```sql
SELECT count_rows('''');
```
* Don't concat strings.
* Use a prepared statement.
* `SELECT quote_ident('test; some');`
## partitions
* table is like a file in storage.
```text
partition table. (kind of like a table, no actual data in it. data stored in partitions)
-------------| ----------
| | | part 1 |
| | ----------
| |
| | ----------
| | | part 2 |
| | ----------
| |
| | ----------
| | | part 3 |
| | ----------
| |
--------------
partition key chooses which partition is chosen.
```
In pg each partition is like a table.
* paritioning in a new version of pg and entered in pg10.
* if you want parititioning then use pg12. perf better in pg12.
partitioning:
* range partitioning:
* range of time or other ranges.
* partition cannot overlap.
* list partitioning:
* partition by customer.
* hash partitioning:
* hash function on partition key -> out comes a integer then take a modulus of total partitions then spread across partitions.
* spread io randomly across devices.
Create the partition table
```sql
CREATE TABLE part (
id bigint NOT NULL,
created_at timestamp with time zone NOT NULL,
data text
) PARTITION BY RANGE (created_at); -- partition by range using created at
# INSERT INTO part VALUES (1, current_timestamp, 'something');
ERROR: 23514: no partition of relation "part" found for row
DETAIL: Partition key of the failing row contains (created_at) = (2020-04-30 11:10:56.799605-06).
-- need to specify partitions
CREATE TABLE part_2018 PARTITION OF part FOR VALUES FROM ('2018-01-01 00:00:00') TO ('2019-01-01 00:00:00');
CREATE TABLE part_2019 PARTITION OF part FOR VALUES FROM ('2019-01-01 00:00:00') TO ('2020-01-01 00:00:00');
CREATE TABLE part_2020 PARTITION OF part FOR VALUES FROM ('2020-01-01 00:00:00') TO ('2021-01-01 00:00:00');
CREATE TABLE part_2021 PARTITION OF part FOR VALUES FROM ('2021-01-01 00:00:00') TO ('2022-01-01 00:00:00');
\d+ part
# INSERT INTO part VALUES (1, current_timestamp, 'something');
INSERT 0 1
# TABLE part;
id | created_at | data
----+-------------------------------+-----------
1 | 2020-04-30 11:13:54.158917-06 | something
-- you can also create a default partition for everything that doesn't fit anywhere else
CREATE TABLE part_default PARTITION OF part DEFAULT;
ALTER TABLE part DETACH PARTITION part_2018;
INSERT INTO part SELECT i, TIMESTAMPTZ '2019-12-30 00:00:00' + i * INTERVAL '1 day', 'whatever' FROM generate_series(1, 400) AS i;
# EXPLAIN (ANALYZE) SELECT * FROM part where created_at BETWEEN '2019-01-01' AND '2020-01-04';
SELECT * FROM part where createdat BETWEEN '2019-01-01' AND '2020-01-04';
QUERY PLAN >
----------------------------------------------------------------------------------------------->
Append (cost=0.00..34.55 rows=9 width=38) (actual time=0.010..0.087 rows=5 loops=1)
-> Seq Scan on part_2019 (cost=0.00..26.05 rows=5 width=48) (actual time=0.009..0.010 rows>
Filter: ((created_at >= '2019-01-01 00:00:00-07'::timestamp with time zone) AND (creat>
-> Seq Scan on part_2020 (cost=0.00..8.50 rows=4 width=25) (actual time=0.006..0.076 rows=>
Filter: ((created_at >= '2019-01-01 00:00:00-07'::timestamp with time zone) AND (creat>
Rows Removed by Filter: 363
Planning time: 0.316 ms
Execution time: 0.111 ms
(8 rows)
```
Deleting a partition is fast.
You can create an index for partitioned tables. The query plan will only include partitions
that matter if the query includes the partition key. Each partition may have a different
query plan.
```sql
ALTER TABLE part ADD PRIMARY KEY (id); -- doesn't work because primary key is not part of the partition key
ALTER TABLE part ADD PRIMARY KEY (id, created_at); -- primary key must include partition key.
```
Planning time increases for queries when using partitions. So there is a cost.
Each new partition can increase the time to query. Queries that include the partition key
can reduce the # of partitions to query which is better than needing to find data across
partitions. vacuuming is easier.
pg doesn't support sharding natively at the moment. A tool that can be used is `pl/proxy`
until it's implemented natively in postgres. `pl/proxy` was developed by skype people
for sharding their data. [pl/proxy](https://plproxy.github.io/).
## COPY
```sql
# \h COPY
Command: COPY
Description: copy data between a file and a table
Syntax:
COPY table_name [ ( column_name [, ...] ) ]
FROM { 'filename' | PROGRAM 'command' | STDIN }
[ [ WITH ] ( option [, ...] ) ]
COPY { table_name [ ( column_name [, ...] ) ] | ( query ) }
TO { 'filename' | PROGRAM 'command' | STDOUT }
[ [ WITH ] ( option [, ...] ) ]
where option can be one of:
FORMAT format_name
OIDS [ boolean ]
FREEZE [ boolean ]
DELIMITER 'delimiter_character'
NULL 'null_string'
HEADER [ boolean ]
QUOTE 'quote_character'
ESCAPE 'escape_character'
FORCE_QUOTE { ( column_name [, ...] ) | * }
FORCE_NOT_NULL ( column_name [, ...] )
FORCE_NULL ( column_name [, ...] )
ENCODING 'encoding_name'
```
COPY to file or copy from file. COPY runs on the database server.
This refers to files on the database server which means it requires
superuser privileges. Most of the time you want to copy files from the client
via stdin and stdout.
```sql
COPY reservation to STDOUT;
\COPY reservation to 'clientfile'
\COPY reservation to 'clientfile' (FORMAT 'csv')
```
## Query Tuning
Start with looking at the statements and try to make it better before
immediately jumping to scaling.
```psql
-- deactivated by default. slow query log
# SHOW log_min_duration_statement ;
log_min_duration_statement
----------------------------
-1
```
`pg_statspg_stat_statements` is most important.
Always activate this in production and is just worth it.
Hooks into pg server and observes executed statements.
Need to activate at server start.
```sql
SHOW shared_preload_libraries ;
# SHOW shared_preload_libraries ;
shared_preload_libraries
--------------------------
ALTER SYSTEM SET shared_preload_libraries = 'pg_stat_statements';
-- restart server. another reason to due this right at the beginning.
```
```sql
SELECT * FROM pg_settings WHERE name LIKE 'pg_stat_statements.%';
```
set pg_state_statements.track = 'all'
```sql
-- reset back to 0.
SELECT pg_stat_statement_reset();
```
```sql
\dx pg_stat_statements
# CREATE EXTENSION pg_stat_statements;
```
```sql
SELECT relname, seq_scan, seq_tup_read, seq_tup_read::float8 / seq_scan AS tup_per_scan
FROM pg_stat_user_tables
ORDER BY tup_per_scan DESC
LIMIT 10;
```
```sql
\d pg_stat_user_indexes
-- find all indexes that have never been scanned.
-- candidate indexes for removal.
SELECT relname, indexrelname, pg_total_relation_size(indexrelid)
FROM pg_stat_user_indexes
WHERE idx_scan = 0
ORDER BY 3 DESC;
```
```sql
EXPLAIN SELECT * FROM pg_stats;
EXPLAIN (ANALYZE, BUFFERS) SELECT * FROM pg_stats;
```
* cost are #'s pg comes up with
* estimated rows
* width in bytes
* actual
* actual time
* actual rows returned
* loops: ?
* loops * time = actual time
* buffers
* hit: blocks read. if it touches lots of blocks then it is probably slow.
* read: from io
* dirtied:
* if estimates are close to actual that is good.
Use [https://explain.depesz.com](https://explain.depesz.com) to format
execution plans.
### Nested Loop join
* How does it work?
* Well... nested loops.
* When is it good?
* when the outer table is small.
* Do indexes help?
* Helps for the inner table
## Hash join
* How does it work?
* sequential scan on inner table
* builds a hash table hash(join condition) a little more prep work for inner scan.
* seq scan on outer table and probe the hash.
* When is it good?
* for bigger tables
* when hash fits into `work_mem`
* Do indexes help?
* wont impact or help
## Merge join
* How does it work?
* sort both tables according to join condition
* scan and join results from both sides
* When is it good?
* good for large tables (too big for work mem)
* Do indexes help?
* can be used to speed up sorting

cost comes from cost of each object.
```sql
select * from pg_settings where name like '%_cost';
select reltuples, relpages from pg_class where relname = 'test';
```

```sql
create table large(id integer, x integer);
INSERT INTO large SELECT i, 1/1000 + 1 FROM generate_series(1, 1000000) as i;
TABLE large
create table small(x integer);
insert into small values(1)
ANALYZE small; -- to calculate statistics which can improve query planner like in this case.
```
* auto analyze happens by the auto vacuum.
* Look at `autovacuum_analyze_scale_factor` and `autovacuum_analyze_threshold`.
* with OLTP you want planning time as short as possible.
* with OLAP you might not mind planning time of 1 minute so that processing time is down from 1 hour to 30 minutes.
```sql
# \h CREATE STATISTICS
Command: CREATE STATISTICS
Description: define extended statistics
Syntax:
CREATE STATISTICS [ IF NOT EXISTS ] statistics_name
[ ( statistics_kind [, ... ] ) ]
ON column_name, column_name [, ...]
FROM table_name
```
* (problem query)[https://gitlab.com/snippets/1973130]
```sql
SELECT 1 as one
FROM (
(SELECT "projects".*
FROM "projects"
WHERE "projects"."namespace_id" IN
(WITH RECURSIVE "base_and_descendants" AS (
(SELECT "namespaces".*
FROM "namespaces"
WHERE "namespaces"."id" IN
(SELECT "elasticsearch_indexed_namespaces"."namespace_id"
FROM "elasticsearch_indexed_namespaces"))
UNION
(SELECT "namespaces".*
FROM "namespaces",
"base_and_descendants"
WHERE "namespaces"."parent_id" = "base_and_descendants"."id")) SELECT "id"
FROM "base_and_descendants" AS "namespaces"))
UNION
(SELECT "projects".*
FROM "projects"
WHERE "projects"."id" IN
(SELECT "elasticsearch_indexed_projects"."project_id"
FROM "elasticsearch_indexed_projects"))) projects
WHERE "projects"."id" = 278964
LIMIT 100
```
## pg and rails
Instructor: Carlos from Cybertec Training
```yaml
# client parameters to use
default:
encoding: unicode
variables: # optional hash of variables to use via the SET commands
schema_search_path: myapp,sharedapp,public
```
Review datatypes.
```ruby
create_table :users do |t|
t.string :username
t.binary # limited to 1GB in storage, allows non printable characters.
end
```
array datatype
example: multiple email addresses for a user
```ruby
def change
add_column :users, :emails, :string, array: true, default: []
# character varying[] type in pg
end
```
# [insert_all](https://api.rubyonrails.org/classes/ActiveRecord/Persistence/ClassMethods.html#method-i-insert_all)
```ruby
users = []
100.times do
users << {
username: SecureRandom.uuid,
emails: ["email#{n}@example.com", "email#{n}+#{n}@example.com"]
}
end
User.insert_all(users) # uses a single transaction instead of one for each insert.
# ice cream cone operator. contains operator
User.where("emails @> '{email@example.com}'")
# run explain on the query
User.where("emails @> '{email@example.com}'").explain
# gist for geometrical data
# gin designed for arrays
add_index :users, :emails, using: 'gin'
# jsonb datatype can be indexed
# range datatype in pg is mapped to the ruby range data type.
create_table :events do |t|
t.daterange :duration
t.timestamps
end
Event.create(duration: Date.new(2014, 2, 11)..Date.new(2014, 2, 12))
Event.first.duration # returns a ruby range
Event
.select("lower(duration) as starts_at")
.select("upper(duration) as ends_at")
.first
# using uuid as primary key prevents enumeration attacks that are possible by using an integer id in the url.
create_table :people, id: :uuid do |t|
enable_extension 'pgcrypto' # this enables the extension on the db
t.string :name
end
# config/initializers/generators.rb
Rails.application.config.generators do |g|
g.orm :active_record, primary_key_type: :uuid
end
```
|