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
|
-- For PostgreSQL 10+ and native partitioning, privilege inheritance is now optional and turned off by default. This now allows pg_partman to run fully as a non-superuser when using native partitioning. (Github Issue #231)
-- This means that all interaction with these partition sets must be done through the parent table.
-- A new column in the part_config table, inherit_privileges, is available if you require direct access to the child tables. Note that this will then require superuser at some level (superuser ownershipt of pg_partman functions for SECURITY DEFINER or running maintenance as a superuser). Just set this option to true and run the reapply_privileges() function to set all child privileges to match the parent. From then on, all new child tables will inherit the parent's privileges.
-- Note that for non-native partitioning on all versions, privileges will continue to be inherited to avoid backward compatability issues and will therefore require a superuser as the above bullet notes.
-- All existing partition sets have had their configuration values set to true so they will continue to act as they did before this update.
-- Updated GRANTS that are required for a non-superuser are in the INSTALLATION section of the readme.
-- The partition_data*() functions now work with the new DEFAULT table feature of PG11. Running these functions will now move data out of the default partition and into the proper child tables, creating them if necessary (Github Issue #230).
-- Note that normal maintenance can fail if data goes into the default table since data that exists in the default cannot have a corresponding child created without taking extra steps. Those extra steps are now handled by partition_data*() and, once that is run, maintenance should be able to proceed as normal.
-- Renamed check_parent() function to check_default(). This function now checks both the parent table in trigger-based partition sets as well as the default table introduced in PostgreSQL 11.
-- The reapply_indexes.py script now only works on trigger-based partition sets or native partition sets in PG10. This script will likely never work with native partitioning in PG11+ without being extremely prone to unexpected behavior, so it is currently not supported at all. Be aware that non-unique index inheritance is built in for PG11+ and that should be used if possible (Github Issue #232).
-- Fixed partition_data_proc() not working for epoch time partitioned sets (Github Pull Request #239).
-- Use SplitIdentifierString() in BGW for more recent versions of PostgreSQL (10.5+) (Github Pull Request #241)
-- Fixed show_partition_info() to account for quarterly/3month partitioning that may not use the "q" naming convention (Github Issue #252, PR #251).
-- Set the drop indexes retention feature to only be usable with trigger-based partitioning or for native, only on PG10 and lower. Natively inherited indexes cannot be dropped from children.
ALTER TABLE @extschema@.part_config ADD COLUMN inherit_privileges boolean DEFAULT false;
ALTER TABLE @extschema@.part_config_sub ADD COLUMN sub_inherit_privileges boolean DEFAULT false;
UPDATE @extschema@.part_config SET inherit_privileges = true;
UPDATE @extschema@.part_config_sub SET sub_inherit_privileges = true;
ALTER TYPE @extschema@.check_parent_table RENAME TO check_default_table;
ALTER TYPE @extschema@.check_default_table RENAME ATTRIBUTE parent_table TO default_table;
-- ######################## START POSTGRESQL 11 ONLY SECTION ##############################
DO $pg11only$
DECLARE
v_partition_data_sql text;
BEGIN
IF current_setting('server_version_num')::int >= 110000 THEN
-- ######################## START POSTGRESQL 11 ONLY SECTION ##############################
-- Syntax check during extension updating doesn't even allow the CREATE PROCEDURE statement to exist. Using dollar quoting w/ EXECUTE to get around it in this conditional IF block.
v_partition_data_sql := $partition_data$
CREATE OR REPLACE PROCEDURE @extschema@.partition_data_proc (p_parent_table text, p_interval text DEFAULT NULL, p_batch int DEFAULT NULL, p_wait int DEFAULT 1, p_source_table text DEFAULT NULL, p_order text DEFAULT 'ASC', p_lock_wait int DEFAULT 0, p_lock_wait_tries int DEFAULT 10, p_quiet boolean DEFAULT false)
LANGUAGE plpgsql
AS $$
DECLARE
v_adv_lock boolean;
v_batch_count int := 0;
v_control text;
v_control_type text;
v_epoch text;
v_is_autovac_off boolean := false;
v_lockwait_count int := 0;
v_parent_schema text;
v_parent_tablename text;
v_row record;
v_rows_moved bigint;
v_source_schema text;
v_source_tablename text;
v_sql text;
v_total bigint := 0;
BEGIN
v_adv_lock := pg_try_advisory_xact_lock(hashtext('pg_partman partition_data_proc'), hashtext(p_parent_table));
IF v_adv_lock = 'false' THEN
RAISE NOTICE 'Partman partition_data_proc already running for given parent table: %.', p_parent_table;
RETURN;
END IF;
SELECT control, epoch
INTO v_control, v_epoch
FROM @extschema@.part_config
WHERE parent_table = p_parent_table;
IF NOT FOUND THEN
RAISE EXCEPTION 'ERROR: No entry in part_config found for given table: %', p_parent_table;
END IF;
SELECT n.nspname, c.relname INTO v_parent_schema, v_parent_tablename
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = split_part(p_parent_table, '.', 1)::name
AND c.relname = split_part(p_parent_table, '.', 2)::name;
IF v_parent_tablename IS NULL THEN
RAISE EXCEPTION 'Unable to find given parent table in system catalogs. Ensure it is schema qualified: %', p_parent_table;
END IF;
IF p_source_table IS NOT NULL THEN
SELECT n.nspname, c.relname INTO v_source_schema, v_source_tablename
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = split_part(p_source_table, '.', 1)::name
AND c.relname = split_part(p_source_table, '.', 2)::name;
IF v_source_tablename IS NULL THEN
RAISE EXCEPTION 'Unable to find given source table in system catalogs. Ensure it is schema qualified: %', p_source_table;
END IF;
END IF;
SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_parent_schema, v_parent_tablename, v_control);
IF v_control_type = 'id' AND v_epoch <> 'none' THEN
v_control_type := 'time';
END IF;
/*
-- Currently no way to catch exception and reset autovac settings back to normal. Until I can do that, leaving this feature out for now
-- Leaving the functions to turn off/reset in to let people do that manually if desired
IF p_autovacuum_on = false THEN -- Add this parameter back to definition when this is working
-- Turn off autovac for parent, source table if set, and all child tables
v_is_autovac_off := @extschema@.autovacuum_off(v_parent_schema, v_parent_tablename, v_source_schema, v_source_tablename);
COMMIT;
END IF;
*/
v_sql := format('SELECT %I.partition_data_%s (%L, p_lock_wait := %L, p_order := %L, p_analyze := false'
, '@extschema@', v_control_type, p_parent_table, p_lock_wait, p_order);
IF p_interval IS NOT NULL THEN
v_sql := v_sql || format(', p_batch_interval := %L', p_interval);
END IF;
IF p_source_table IS NOT NULL THEN
v_sql := v_sql || format(', p_source_table := %L', p_source_table);
END IF;
v_sql := v_sql || ')';
RAISE DEBUG 'partition_data sql: %', v_sql;
LOOP
EXECUTE v_sql INTO v_rows_moved;
-- If lock wait timeout, do not increment the counter
IF v_rows_moved != -1 THEN
v_batch_count := v_batch_count + 1;
v_total := v_total + v_rows_moved;
v_lockwait_count := 0;
ELSE
v_lockwait_count := v_lockwait_count + 1;
IF v_lockwait_count > p_lock_wait_tries THEN
RAISE EXCEPTION 'Quitting due to inability to get lock on next batch of rows to be moved';
END IF;
END IF;
IF p_quiet = false THEN
IF v_rows_moved > 0 THEN
RAISE NOTICE 'Batch: %, Rows moved: %', v_batch_count, v_rows_moved;
ELSIF v_rows_moved = -1 THEN
RAISE NOTICE 'Unable to obtain row locks for data to be moved. Trying again...';
END IF;
END IF;
-- If no rows left or given batch argument limit is reached
IF v_rows_moved = 0 OR (p_batch > 0 AND v_batch_count >= p_batch) THEN
EXIT;
END IF;
COMMIT;
PERFORM pg_sleep(p_wait);
RAISE DEBUG 'v_rows_moved: %, v_batch_count: %, v_total: %, v_lockwait_count: %, p_wait: %', p_wait, v_rows_moved, v_batch_count, v_total, v_lockwait_count;
END LOOP;
/*
IF v_is_autovac_off = true THEN
-- Reset autovac back to default if it was turned off by this procedure
PERFORM @extschema@.autovacuum_reset(v_parent_schema, v_parent_tablename, v_source_schema, v_source_tablename);
COMMIT;
END IF;
*/
IF p_quiet = false THEN
RAISE NOTICE 'Total rows moved: %', v_total;
END IF;
RAISE NOTICE 'Ensure to VACUUM ANALYZE the parent (and source table if used) after partitioning data';
/* Leaving here until I can figure out what's wrong with procedures and exception handling
EXCEPTION
WHEN QUERY_CANCELED THEN
ROLLBACK;
-- Reset autovac back to default if it was turned off by this procedure
IF v_is_autovac_off = true THEN
PERFORM @extschema@.autovacuum_reset(v_parent_schema, v_parent_tablename, v_source_schema, v_source_tablename);
END IF;
RAISE EXCEPTION '%', SQLERRM;
WHEN OTHERS THEN
ROLLBACK;
-- Reset autovac back to default if it was turned off by this procedure
IF v_is_autovac_off = true THEN
PERFORM @extschema@.autovacuum_reset(v_parent_schema, v_parent_tablename, v_source_schema, v_source_tablename);
END IF;
RAISE EXCEPTION '%', SQLERRM;
*/
END;
$$;
$partition_data$;
EXECUTE v_partition_data_sql;
-- ######################## END POSTGRESQL 11 ONLY SECTION ##############################
END IF;
END
$pg11only$;
-- ######################## END POSTGRESQL 11 ONLY SECTION ##############################
CREATE OR REPLACE FUNCTION @extschema@.drop_partition_id(p_parent_table text, p_retention bigint DEFAULT NULL, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL, p_retention_schema text DEFAULT NULL) RETURNS int
LANGUAGE plpgsql
AS $$
DECLARE
ex_context text;
ex_detail text;
ex_hint text;
ex_message text;
v_adv_lock boolean;
v_control text;
v_control_type text;
v_count int;
v_drop_count int := 0;
v_index record;
v_job_id bigint;
v_jobmon boolean;
v_jobmon_schema text;
v_max bigint;
v_new_search_path text := '@extschema@,pg_temp';
v_old_search_path text;
v_parent_schema text;
v_parent_tablename text;
v_partition_interval bigint;
v_partition_id bigint;
v_partition_type text;
v_retention bigint;
v_retention_keep_index boolean;
v_retention_keep_table boolean;
v_retention_schema text;
v_row record;
v_row_max_id record;
v_step_id bigint;
BEGIN
/*
* Function to drop child tables from an id-based partition set.
* Options to move table to different schema, drop only indexes or actually drop the table from the database.
*/
v_adv_lock := pg_try_advisory_xact_lock(hashtext('pg_partman drop_partition_id'));
IF v_adv_lock = 'false' THEN
RAISE NOTICE 'drop_partition_id already running.';
RETURN 0;
END IF;
IF p_retention IS NULL THEN
SELECT
partition_interval::bigint
, partition_type
, control
, retention::bigint
, retention_keep_table
, retention_keep_index
, retention_schema
, jobmon
INTO
v_partition_interval
, v_partition_type
, v_control
, v_retention
, v_retention_keep_table
, v_retention_keep_index
, v_retention_schema
, v_jobmon
FROM @extschema@.part_config
WHERE parent_table = p_parent_table
AND retention IS NOT NULL;
IF v_partition_interval IS NULL THEN
RAISE EXCEPTION 'Configuration for given parent table with a retention period not found: %', p_parent_table;
END IF;
ELSE -- Allow override of configuration options
SELECT
partition_interval::bigint
, partition_type
, control
, retention_keep_table
, retention_keep_index
, retention_schema
, jobmon
INTO
v_partition_interval
, v_partition_type
, v_control
, v_retention_keep_table
, v_retention_keep_index
, v_retention_schema
, v_jobmon
FROM @extschema@.part_config
WHERE parent_table = p_parent_table;
v_retention := p_retention;
IF v_partition_interval IS NULL THEN
RAISE EXCEPTION 'Configuration for given parent table not found: %', p_parent_table;
END IF;
END IF;
SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_parent_schema, v_parent_tablename, v_control);
IF v_control_type <> 'id' THEN
RAISE EXCEPTION 'Data type of control column in given partition set is not an integer type';
END IF;
SELECT current_setting('search_path') INTO v_old_search_path;
IF v_jobmon THEN
SELECT nspname INTO v_jobmon_schema FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_jobmon'::name AND e.extnamespace = n.oid;
IF v_jobmon_schema IS NOT NULL THEN
v_new_search_path := '@extschema@,'||v_jobmon_schema||',pg_temp';
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false');
IF p_keep_table IS NOT NULL THEN
v_retention_keep_table = p_keep_table;
END IF;
IF p_keep_index IS NOT NULL THEN
v_retention_keep_index = p_keep_index;
END IF;
IF p_retention_schema IS NOT NULL THEN
v_retention_schema = p_retention_schema;
END IF;
SELECT schemaname, tablename INTO v_parent_schema, v_parent_tablename
FROM pg_catalog.pg_tables
WHERE schemaname = split_part(p_parent_table, '.', 1)::name
AND tablename = split_part(p_parent_table, '.', 2)::name;
-- Loop through child tables starting from highest to get current max value in partition set
-- Avoids doing a scan on entire partition set and/or getting any values accidentally in parent.
FOR v_row_max_id IN
SELECT partition_schemaname, partition_tablename FROM @extschema@.show_partitions(p_parent_table, 'DESC')
LOOP
EXECUTE format('SELECT max(%I) FROM %I.%I', v_control, v_row_max_id.partition_schemaname, v_row_max_id.partition_tablename) INTO v_max;
IF v_max IS NOT NULL THEN
EXIT;
END IF;
END LOOP;
-- Loop through child tables of the given parent
FOR v_row IN
SELECT partition_schemaname, partition_tablename FROM @extschema@.show_partitions(p_parent_table, 'ASC')
LOOP
SELECT child_start_id INTO v_partition_id FROM @extschema@.show_partition_info(v_row.partition_schemaname||'.'||v_row.partition_tablename
, v_partition_interval::text
, p_parent_table);
-- Add one interval since partition names contain the start of the constraint period
IF v_retention <= (v_max - (v_partition_id + v_partition_interval)) THEN
-- Do not allow final partition to be dropped
SELECT count(*) INTO v_count FROM @extschema@.show_partitions(p_parent_table);
IF v_count = 1 THEN
RAISE WARNING 'Attempt to drop final partition in partition set % as part of retention policy. Advise reviewing retention policy and/or data entry into the partition set.', p_parent_table;
CONTINUE;
END IF;
-- Only create a jobmon entry if there's actual retention work done
IF v_jobmon_schema IS NOT NULL AND v_job_id IS NULL THEN
v_job_id := add_job(format('PARTMAN DROP ID PARTITION: %s', p_parent_table));
END IF;
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Detach/Uninherit table %s.%s from %s', v_row.partition_schemaname, v_row.partition_tablename, p_parent_table));
END IF;
IF v_partition_type = 'native' THEN
EXECUTE format('ALTER TABLE %I.%I DETACH PARTITION %I.%I'
, v_parent_schema
, v_parent_tablename
, v_row.partition_schemaname
, v_row.partition_tablename);
ELSE
EXECUTE format('ALTER TABLE %I.%I NO INHERIT %I.%I'
, v_row.partition_schemaname
, v_row.partition_tablename
, v_parent_schema
, v_parent_tablename);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END IF;
IF v_retention_schema IS NULL THEN
IF v_retention_keep_table = false THEN
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Drop table %s.%s', v_row.partition_schemaname, v_row.partition_tablename));
END IF;
EXECUTE format('DROP TABLE %I.%I CASCADE', v_row.partition_schemaname, v_row.partition_tablename);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
ELSIF v_retention_keep_index = false THEN
IF v_partition_type = 'partman' OR
( v_partition_type = 'native' AND current_setting('server_version_num')::int < 110000) THEN
-- Cannot drop child indexes on native partition sets in PG11+
FOR v_index IN
WITH child_info AS (
SELECT c1.oid
FROM pg_catalog.pg_class c1
JOIN pg_catalog.pg_namespace n1 ON c1.relnamespace = n1.oid
WHERE c1.relname = v_row.partition_tablename::name
AND n1.nspname = v_row.partition_schema::name
)
SELECT c.relname as name
, con.conname
FROM pg_catalog.pg_index i
JOIN pg_catalog.pg_class c ON i.indexrelid = c.oid
LEFT JOIN pg_catalog.pg_constraint con ON i.indexrelid = con.conindid
JOIN child_info ON i.indrelid = child_info.oid
LOOP
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Drop index %s from %s.%s'
, v_index.name
, v_row.partition_schemaname
, v_row.partition_tablename));
END IF;
IF v_index.conname IS NOT NULL THEN
EXECUTE format('ALTER TABLE %I.%I DROP CONSTRAINT %I', v_row.partition_schemaname, v_row.partition_tablename, v_index.conname);
ELSE
EXECUTE format('DROP INDEX %I.%I', v_row.partition_schemaname, v_index.name);
END IF;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END LOOP;
END IF; -- end native/11 check
END IF; -- end v_retention_keep_index IF
ELSE -- Move to new schema
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Moving table %s.%s to schema %s'
, v_row.partition_schemaname
, v_row.partition_tablename
, v_retention_schema));
END IF;
EXECUTE format('ALTER TABLE %I.%I SET SCHEMA %I'
, v_row.partition_schemaname
, v_row.partition_tablename
, v_retention_schema);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END IF; -- End retention schema if
-- If child table is a subpartition, remove it from part_config & part_config_sub (should cascade due to FK)
DELETE FROM @extschema@.part_config WHERE parent_table = v_row.partition_schemaname ||'.'||v_row.partition_tablename;
v_drop_count := v_drop_count + 1;
END IF; -- End retention check IF
END LOOP; -- End child table loop
IF v_jobmon_schema IS NOT NULL THEN
IF v_job_id IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Finished partition drop maintenance');
PERFORM update_step(v_step_id, 'OK', format('%s partitions dropped.', v_drop_count));
PERFORM close_job(v_job_id);
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RETURN v_drop_count;
EXCEPTION
WHEN OTHERS THEN
GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT,
ex_context = PG_EXCEPTION_CONTEXT,
ex_detail = PG_EXCEPTION_DETAIL,
ex_hint = PG_EXCEPTION_HINT;
IF v_jobmon_schema IS NOT NULL THEN
IF v_job_id IS NULL THEN
EXECUTE format('SELECT %I.add_job(''PARTMAN DROP ID PARTITION: %s'')', v_jobmon_schema, p_parent_table) INTO v_job_id;
EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before job logging started'')', v_jobmon_schema, v_job_id, p_parent_table) INTO v_step_id;
ELSIF v_step_id IS NULL THEN
EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before first step logged'')', v_jobmon_schema, v_job_id) INTO v_step_id;
END IF;
EXECUTE format('SELECT %I.update_step(%s, ''CRITICAL'', %L)', v_jobmon_schema, v_step_id, 'ERROR: '||coalesce(SQLERRM,'unknown'));
EXECUTE format('SELECT %I.fail_job(%s)', v_jobmon_schema, v_job_id);
END IF;
RAISE EXCEPTION '%
CONTEXT: %
DETAIL: %
HINT: %', ex_message, ex_context, ex_detail, ex_hint;
END
$$;
CREATE OR REPLACE FUNCTION @extschema@.drop_partition_time(p_parent_table text, p_retention interval DEFAULT NULL, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL, p_retention_schema text DEFAULT NULL) RETURNS int
LANGUAGE plpgsql
AS $$
DECLARE
ex_context text;
ex_detail text;
ex_hint text;
ex_message text;
v_adv_lock boolean;
v_control text;
v_control_type text;
v_count int;
v_datetime_string text;
v_drop_count int := 0;
v_epoch text;
v_index record;
v_job_id bigint;
v_jobmon boolean;
v_jobmon_schema text;
v_new_search_path text := '@extschema@,pg_temp';
v_old_search_path text;
v_parent_schema text;
v_parent_tablename text;
v_partition_interval interval;
v_partition_timestamp timestamptz;
v_partition_type text;
v_retention interval;
v_retention_keep_index boolean;
v_retention_keep_table boolean;
v_retention_schema text;
v_row record;
v_step_id bigint;
BEGIN
/*
* Function to drop child tables from a time-based partition set.
* Options to move table to different schema, drop only indexes or actually drop the table from the database.
*/
v_adv_lock := pg_try_advisory_xact_lock(hashtext('pg_partman drop_partition_time'));
IF v_adv_lock = 'false' THEN
RAISE NOTICE 'drop_partition_time already running.';
RETURN 0;
END IF;
-- Allow override of configuration options
IF p_retention IS NULL THEN
SELECT
partition_type
, control
, partition_interval::interval
, epoch
, retention::interval
, retention_keep_table
, retention_keep_index
, datetime_string
, retention_schema
, jobmon
INTO
v_partition_type
, v_control
, v_partition_interval
, v_epoch
, v_retention
, v_retention_keep_table
, v_retention_keep_index
, v_datetime_string
, v_retention_schema
, v_jobmon
FROM @extschema@.part_config
WHERE parent_table = p_parent_table
AND retention IS NOT NULL;
IF v_partition_interval IS NULL THEN
RAISE EXCEPTION 'Configuration for given parent table with a retention period not found: %', p_parent_table;
END IF;
ELSE
SELECT
partition_type
, partition_interval::interval
, epoch
, retention_keep_table
, retention_keep_index
, datetime_string
, retention_schema
, jobmon
INTO
v_partition_type
, v_partition_interval
, v_epoch
, v_retention_keep_table
, v_retention_keep_index
, v_datetime_string
, v_retention_schema
, v_jobmon
FROM @extschema@.part_config
WHERE parent_table = p_parent_table;
v_retention := p_retention;
IF v_partition_interval IS NULL THEN
RAISE EXCEPTION 'Configuration for given parent table not found: %', p_parent_table;
END IF;
END IF;
SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_parent_schema, v_parent_tablename, v_control);
IF v_control_type <> 'time' THEN
IF (v_control_type = 'id' AND v_epoch = 'none') OR v_control_type <> 'id' THEN
RAISE EXCEPTION 'Cannot run on partition set without time based control column or epoch flag set with an id column. Found control: %, epoch: %', v_control_type, v_epoch;
END IF;
END IF;
SELECT current_setting('search_path') INTO v_old_search_path;
IF v_jobmon THEN
SELECT nspname INTO v_jobmon_schema FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_jobmon'::name AND e.extnamespace = n.oid;
IF v_jobmon_schema IS NOT NULL THEN
v_new_search_path := '@extschema@,'||v_jobmon_schema||',pg_temp';
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false');
IF p_keep_table IS NOT NULL THEN
v_retention_keep_table = p_keep_table;
END IF;
IF p_keep_index IS NOT NULL THEN
v_retention_keep_index = p_keep_index;
END IF;
IF p_retention_schema IS NOT NULL THEN
v_retention_schema = p_retention_schema;
END IF;
SELECT schemaname, tablename INTO v_parent_schema, v_parent_tablename
FROM pg_catalog.pg_tables
WHERE schemaname = split_part(p_parent_table, '.', 1)::name
AND tablename = split_part(p_parent_table, '.', 2)::name;
-- Loop through child tables of the given parent
FOR v_row IN
SELECT partition_schemaname, partition_tablename FROM @extschema@.show_partitions(p_parent_table, 'DESC')
LOOP
-- pull out datetime portion of partition's tablename to make the next one
SELECT child_start_time INTO v_partition_timestamp FROM @extschema@.show_partition_info(v_row.partition_schemaname||'.'||v_row.partition_tablename
, v_partition_interval::text
, p_parent_table);
-- Add one interval since partition names contain the start of the constraint period
IF v_retention < (CURRENT_TIMESTAMP - (v_partition_timestamp + v_partition_interval)) THEN
-- Do not allow final partition to be dropped
SELECT count(*) INTO v_count FROM @extschema@.show_partitions(p_parent_table);
IF v_count = 1 THEN
RAISE WARNING 'Attempt to drop final partition in partition set % as part of retention policy. If you see this message multiple times for the same table, advise reviewing retention policy and/or data entry into the partition set. Also consider setting "infinite_time_partitions = true" if there are large gaps in data insertion.).', p_parent_table;
CONTINUE;
END IF;
-- Only create a jobmon entry if there's actual retention work done
IF v_jobmon_schema IS NOT NULL AND v_job_id IS NULL THEN
v_job_id := add_job(format('PARTMAN DROP TIME PARTITION: %s', p_parent_table));
END IF;
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Detach/Uninherit table %s.%s from %s'
, v_row.partition_schemaname
, v_row.partition_tablename
, p_parent_table));
END IF;
IF v_partition_type = 'native' THEN
EXECUTE format('ALTER TABLE %I.%I DETACH PARTITION %I.%I'
, v_parent_schema
, v_parent_tablename
, v_row.partition_schemaname
, v_row.partition_tablename);
ELSE
EXECUTE format('ALTER TABLE %I.%I NO INHERIT %I.%I'
, v_row.partition_schemaname
, v_row.partition_tablename
, v_parent_schema
, v_parent_tablename);
END IF;
IF v_partition_type = 'time-custom' THEN
DELETE FROM @extschema@.custom_time_partitions WHERE parent_table = p_parent_table AND child_table = v_row.partition_schemaname||'.'||v_row.partition_tablename;
END IF;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
IF v_retention_schema IS NULL THEN
IF v_retention_keep_table = false THEN
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Drop table %s.%s', v_row.partition_schemaname, v_row.partition_tablename));
END IF;
EXECUTE format('DROP TABLE %I.%I CASCADE', v_row.partition_schemaname, v_row.partition_tablename);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
ELSIF v_retention_keep_index = false THEN
IF v_partition_type = 'partman' OR
( v_partition_type = 'native' AND current_setting('server_version_num')::int < 110000) THEN
-- Cannot drop child indexes on native partition sets in PG11+
FOR v_index IN
WITH child_info AS (
SELECT c1.oid
FROM pg_catalog.pg_class c1
JOIN pg_catalog.pg_namespace n1 ON c1.relnamespace = n1.oid
WHERE c1.relname = v_row.partition_tablename::name
AND n1.nspname = v_row.partition_schemaname::name
)
SELECT c.relname as name
, con.conname
FROM pg_catalog.pg_index i
JOIN pg_catalog.pg_class c ON i.indexrelid = c.oid
LEFT JOIN pg_catalog.pg_constraint con ON i.indexrelid = con.conindid
JOIN child_info ON i.indrelid = child_info.oid
LOOP
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Drop index %s from %s.%s'
, v_index.name
, v_row.partition_schemaname
, v_row.partition_tablename));
END IF;
IF v_index.conname IS NOT NULL THEN
EXECUTE format('ALTER TABLE %I.%I DROP CONSTRAINT %I'
, v_row.partition_schemaname
, v_row.partition_tablename
, v_index.conname);
ELSE
EXECUTE format('DROP INDEX %I.%I', v_parent_schema, v_index.name);
END IF;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END LOOP;
END IF; -- end native/11 check
END IF; -- end v_retention_keep_index IF
ELSE -- Move to new schema
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Moving table %s.%s to schema %s'
, v_row.partition_schemaname
, v_row.partition_tablename
, v_retention_schema));
END IF;
EXECUTE format('ALTER TABLE %I.%I SET SCHEMA %I', v_row.partition_schemaname, v_row.partition_tablename, v_retention_schema);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END IF; -- End retention schema if
-- If child table is a subpartition, remove it from part_config & part_config_sub (should cascade due to FK)
DELETE FROM @extschema@.part_config WHERE parent_table = v_row.partition_schemaname||'.'||v_row.partition_tablename;
v_drop_count := v_drop_count + 1;
END IF; -- End retention check IF
END LOOP; -- End child table loop
IF v_jobmon_schema IS NOT NULL THEN
IF v_job_id IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Finished partition drop maintenance');
PERFORM update_step(v_step_id, 'OK', format('%s partitions dropped.', v_drop_count));
PERFORM close_job(v_job_id);
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RETURN v_drop_count;
EXCEPTION
WHEN OTHERS THEN
GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT,
ex_context = PG_EXCEPTION_CONTEXT,
ex_detail = PG_EXCEPTION_DETAIL,
ex_hint = PG_EXCEPTION_HINT;
IF v_jobmon_schema IS NOT NULL THEN
IF v_job_id IS NULL THEN
EXECUTE format('SELECT %I.add_job(''PARTMAN DROP TIME PARTITION: %s'')', v_jobmon_schema, p_parent_table) INTO v_job_id;
EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before job logging started'')', v_jobmon_schema, v_job_id, p_parent_table) INTO v_step_id;
ELSIF v_step_id IS NULL THEN
EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before first step logged'')', v_jobmon_schema, v_job_id) INTO v_step_id;
END IF;
EXECUTE format('SELECT %I.update_step(%s, ''CRITICAL'', %L)', v_jobmon_schema, v_step_id, 'ERROR: '||coalesce(SQLERRM,'unknown'));
EXECUTE format('SELECT %I.fail_job(%s)', v_jobmon_schema, v_job_id);
END IF;
RAISE EXCEPTION '%
CONTEXT: %
DETAIL: %
HINT: %', ex_message, ex_context, ex_detail, ex_hint;
END
$$;
CREATE OR REPLACE FUNCTION @extschema@.create_partition_id(p_parent_table text, p_partition_ids bigint[], p_analyze boolean DEFAULT true, p_debug boolean DEFAULT false) RETURNS boolean
LANGUAGE plpgsql
AS $$
DECLARE
ex_context text;
ex_detail text;
ex_hint text;
ex_message text;
v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
v_analyze boolean := FALSE;
v_control text;
v_control_type text;
v_exists text;
v_grantees text[];
v_hasoids boolean;
v_id bigint;
v_inherit_fk boolean;
v_inherit_privileges boolean;
v_job_id bigint;
v_jobmon boolean;
v_jobmon_schema text;
v_new_search_path text := '@extschema@,pg_temp';
v_old_search_path text;
v_parent_grant record;
v_parent_schema text;
v_parent_tablename text;
v_parent_tablespace text;
v_partition_interval bigint;
v_partition_created boolean := false;
v_partition_name text;
v_partition_type text;
v_publications text[];
v_revoke text;
v_row record;
v_sql text;
v_step_id bigint;
v_sub_control text;
v_sub_partition_type text;
v_sub_id_max bigint;
v_sub_id_min bigint;
v_template_table text;
v_unlogged char;
BEGIN
/*
* Function to create id partitions
*/
SELECT control
, partition_type
, partition_interval
, inherit_fk
, jobmon
, template_table
, publications
, inherit_privileges
INTO v_control
, v_partition_type
, v_partition_interval
, v_inherit_fk
, v_jobmon
, v_template_table
, v_publications
, v_inherit_privileges
FROM @extschema@.part_config
WHERE parent_table = p_parent_table;
IF NOT FOUND THEN
RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
END IF;
SELECT n.nspname, c.relname, t.spcname
INTO v_parent_schema, v_parent_tablename, v_parent_tablespace
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
LEFT OUTER JOIN pg_catalog.pg_tablespace t ON c.reltablespace = t.oid
WHERE n.nspname = split_part(p_parent_table, '.', 1)::name
AND c.relname = split_part(p_parent_table, '.', 2)::name;
SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_parent_schema, v_parent_tablename, v_control);
IF v_control_type <> 'id' THEN
RAISE EXCEPTION 'ERROR: Given parent table is not set up for id/serial partitioning';
END IF;
SELECT current_setting('search_path') INTO v_old_search_path;
IF v_jobmon THEN
SELECT nspname INTO v_jobmon_schema FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_jobmon'::name AND e.extnamespace = n.oid;
IF v_jobmon_schema IS NOT NULL THEN
v_new_search_path := '@extschema@,'||v_jobmon_schema||',pg_temp';
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false');
-- Determine if this table is a child of a subpartition parent. If so, get limits of what child tables can be created based on parent suffix
SELECT sub_min::bigint, sub_max::bigint INTO v_sub_id_min, v_sub_id_max FROM @extschema@.check_subpartition_limits(p_parent_table, 'id');
IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job(format('PARTMAN CREATE TABLE: %s', p_parent_table));
END IF;
FOREACH v_id IN ARRAY p_partition_ids LOOP
-- Do not create the child table if it's outside the bounds of the top parent.
IF v_sub_id_min IS NOT NULL THEN
IF v_id < v_sub_id_min OR v_id > v_sub_id_max THEN
CONTINUE;
END IF;
END IF;
v_partition_name := @extschema@.check_name_length(v_parent_tablename, v_id::text, TRUE);
-- If child table already exists, skip creation
-- Have to check pg_class because if subpartitioned, table will not be in pg_tables
SELECT c.relname INTO v_exists
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = v_parent_schema::name AND c.relname = v_partition_name::name;
IF v_exists IS NOT NULL THEN
CONTINUE;
END IF;
-- Ensure analyze is run if a new partition is created. Otherwise if one isn't, will be false and analyze will be skipped
v_analyze := TRUE;
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_id||' to '||(v_id + v_partition_interval)-1);
END IF;
SELECT relpersistence INTO v_unlogged
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schema::name;
v_sql := 'CREATE';
IF v_unlogged = 'u' THEN
v_sql := v_sql || ' UNLOGGED';
END IF;
-- Close parentheses on LIKE are below due to differing requirements of native subpartitioning
-- Same INCLUDING list is used in create_parent()
v_sql := v_sql || format(' TABLE %I.%I (LIKE %I.%I INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING STORAGE INCLUDING COMMENTS '
, v_parent_schema
, v_partition_name
, v_parent_schema
, v_parent_tablename);
SELECT sub_partition_type, sub_control INTO v_sub_partition_type, v_sub_control
FROM @extschema@.part_config_sub
WHERE sub_parent = p_parent_table;
IF v_sub_partition_type = 'native' THEN
-- NOTE: Need to handle this differently when index inheritance is supported natively
-- Cannot include indexes since they cannot exist on native parents.
v_sql := v_sql || format(') PARTITION BY RANGE (%I) ', v_sub_control);
ELSE
v_sql := v_sql || format(' INCLUDING INDEXES) ', v_sub_control);
END IF;
SELECT relhasoids INTO v_hasoids
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schema::name;
IF v_hasoids IS TRUE THEN
v_sql := v_sql || ' WITH (OIDS)';
END IF;
EXECUTE v_sql;
IF v_partition_type = 'native' THEN
IF v_template_table IS NOT NULL THEN
PERFORM @extschema@.inherit_template_properties(p_parent_table, v_parent_schema, v_partition_name);
END IF;
EXECUTE format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I FOR VALUES FROM (%L) TO (%L)'
, v_parent_schema
, v_parent_tablename
, v_parent_schema
, v_partition_name
, v_id
, v_id + v_partition_interval);
ELSE
-- Handled in inherit_template_properties for native because CREATE TABLE ignores TABLESPACE flag for native partition parents
IF v_parent_tablespace IS NOT NULL THEN
EXECUTE format('ALTER TABLE %I.%I SET TABLESPACE %I', v_parent_schema, v_partition_name, v_parent_tablespace);
END IF;
EXECUTE format('ALTER TABLE %I.%I ADD CONSTRAINT %I CHECK (%I >= %s AND %I < %s )'
, v_parent_schema
, v_partition_name
, v_partition_name||'_partition_check'
, v_control
, v_id
, v_control
, v_id + v_partition_interval);
EXECUTE format('ALTER TABLE %I.%I INHERIT %I.%I', v_parent_schema, v_partition_name, v_parent_schema, v_parent_tablename);
-- Indexes cannot be created on the parent, so clustering cannot be used for native yet.
PERFORM @extschema@.apply_cluster(v_parent_schema, v_parent_tablename, v_parent_schema, v_partition_name);
-- Foreign keys to other tables not supported on native parent tables
IF v_inherit_fk THEN
PERFORM @extschema@.apply_foreign_keys(p_parent_table, v_parent_schema||'.'||v_partition_name, v_job_id);
END IF;
END IF;
-- NOTE: Privileges not automatically inherited for native. Only do so if config flag is set
IF v_partition_type != 'native' OR (v_partition_type = 'native' AND v_inherit_privileges = TRUE) THEN
PERFORM @extschema@.apply_privileges(v_parent_schema, v_parent_tablename, v_parent_schema, v_partition_name, v_job_id);
END IF;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
-- Will only loop once and only if sub_partitioning is actually configured
-- This seemed easier than assigning a bunch of variables then doing an IF condition
FOR v_row IN
SELECT sub_parent
, sub_partition_type
, sub_control
, sub_partition_interval
, sub_constraint_cols
, sub_premake
, sub_optimize_trigger
, sub_optimize_constraint
, sub_epoch
, sub_inherit_fk
, sub_retention
, sub_retention_schema
, sub_retention_keep_table
, sub_retention_keep_index
, sub_automatic_maintenance
, sub_infinite_time_partitions
, sub_jobmon
, sub_trigger_exception_handling
, sub_template_table
, sub_inherit_privileges
FROM @extschema@.part_config_sub
WHERE sub_parent = p_parent_table
LOOP
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Subpartitioning '||v_partition_name);
END IF;
v_sql := format('SELECT @extschema@.create_parent(
p_parent_table := %L
, p_control := %L
, p_type := %L
, p_interval := %L
, p_constraint_cols := %L
, p_premake := %L
, p_automatic_maintenance := %L
, p_inherit_fk := %L
, p_epoch := %L
, p_template_table := %L
, p_jobmon := %L )'
, v_parent_schema||'.'||v_partition_name
, v_row.sub_control
, v_row.sub_partition_type
, v_row.sub_partition_interval
, v_row.sub_constraint_cols
, v_row.sub_premake
, v_row.sub_automatic_maintenance
, v_row.sub_inherit_fk
, v_row.sub_epoch
, v_row.sub_template_table
, v_row.sub_jobmon);
EXECUTE v_sql;
UPDATE @extschema@.part_config SET
retention_schema = v_row.sub_retention_schema
, retention_keep_table = v_row.sub_retention_keep_table
, retention_keep_index = v_row.sub_retention_keep_index
, optimize_trigger = v_row.sub_optimize_trigger
, optimize_constraint = v_row.sub_optimize_constraint
, infinite_time_partitions = v_row.sub_infinite_time_partitions
, trigger_exception_handling = v_row.sub_trigger_exception_handling
, inherit_privileges = v_row.sub_inherit_privileges
WHERE parent_table = v_parent_schema||'.'||v_partition_name;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END LOOP; -- end sub partitioning LOOP
-- Manage additonal constraints if set
PERFORM @extschema@.apply_constraints(p_parent_table, p_job_id := v_job_id, p_debug := p_debug);
IF v_publications IS NOT NULL THEN
-- NOTE: Publications currently not supported on parent table, but are supported on the table partitions if individually assigned.
PERFORM @extschema@.apply_publications(p_parent_table, v_parent_schema, v_partition_name);
END IF;
v_partition_created := true;
END LOOP;
-- v_analyze is a local check if a new table is made.
-- p_analyze is a parameter to say whether to run the analyze at all. Used by create_parent() to avoid long exclusive lock or run_maintenence() to avoid long creation runs.
IF v_analyze AND p_analyze THEN
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Analyzing partition set: %s', p_parent_table));
END IF;
EXECUTE format('ANALYZE %I.%I', v_parent_schema, v_parent_tablename);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END IF;
IF v_jobmon_schema IS NOT NULL THEN
IF v_partition_created = false THEN
v_step_id := add_step(v_job_id, format('No partitions created for partition set: %s', p_parent_table));
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
PERFORM close_job(v_job_id);
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RETURN v_partition_created;
EXCEPTION
WHEN OTHERS THEN
GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT,
ex_context = PG_EXCEPTION_CONTEXT,
ex_detail = PG_EXCEPTION_DETAIL,
ex_hint = PG_EXCEPTION_HINT;
IF v_jobmon_schema IS NOT NULL THEN
IF v_job_id IS NULL THEN
EXECUTE format('SELECT %I.add_job(''PARTMAN CREATE TABLE: %s'')', v_jobmon_schema, p_parent_table) INTO v_job_id;
EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before job logging started'')', v_jobmon_schema, v_job_id, p_parent_table) INTO v_step_id;
ELSIF v_step_id IS NULL THEN
EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before first step logged'')', v_jobmon_schema, v_job_id) INTO v_step_id;
END IF;
EXECUTE format('SELECT %I.update_step(%s, ''CRITICAL'', %L)', v_jobmon_schema, v_step_id, 'ERROR: '||coalesce(SQLERRM,'unknown'));
EXECUTE format('SELECT %I.fail_job(%s)', v_jobmon_schema, v_job_id);
END IF;
RAISE EXCEPTION '%
CONTEXT: %
DETAIL: %
HINT: %', ex_message, ex_context, ex_detail, ex_hint;
END
$$;
CREATE OR REPLACE FUNCTION @extschema@.create_partition_time(p_parent_table text, p_partition_times timestamptz[], p_analyze boolean DEFAULT true, p_debug boolean DEFAULT false)
RETURNS boolean
LANGUAGE plpgsql
AS $$
DECLARE
ex_context text;
ex_detail text;
ex_hint text;
ex_message text;
v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
v_analyze boolean := FALSE;
v_control text;
v_control_type text;
v_datetime_string text;
v_epoch text;
v_exists smallint;
v_grantees text[];
v_hasoids boolean;
v_inherit_privileges boolean;
v_inherit_fk boolean;
v_job_id bigint;
v_jobmon boolean;
v_jobmon_schema text;
v_new_search_path text := '@extschema@,pg_temp';
v_old_search_path text;
v_parent_grant record;
v_parent_schema text;
v_parent_tablename text;
v_part_col text;
v_partition_created boolean := false;
v_partition_name text;
v_partition_suffix text;
v_parent_tablespace text;
v_partition_expression text;
v_partition_interval interval;
v_partition_timestamp_end timestamptz;
v_partition_timestamp_start timestamptz;
v_publications text[];
v_quarter text;
v_revoke text;
v_row record;
v_sql text;
v_step_id bigint;
v_step_overflow_id bigint;
v_sub_control text;
v_sub_parent text;
v_sub_partition_type text;
v_sub_timestamp_max timestamptz;
v_sub_timestamp_min timestamptz;
v_template_table text;
v_trunc_value text;
v_time timestamptz;
v_partition_type text;
v_unlogged char;
v_year text;
BEGIN
/*
* Function to create a child table in a time-based partition set
*/
SELECT partition_type
, control
, partition_interval
, epoch
, inherit_fk
, jobmon
, datetime_string
, template_table
, publications
, inherit_privileges
INTO v_partition_type
, v_control
, v_partition_interval
, v_epoch
, v_inherit_fk
, v_jobmon
, v_datetime_string
, v_template_table
, v_publications
, v_inherit_privileges
FROM @extschema@.part_config
WHERE parent_table = p_parent_table;
IF NOT FOUND THEN
RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
END IF;
SELECT n.nspname, c.relname, t.spcname
INTO v_parent_schema, v_parent_tablename, v_parent_tablespace
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
LEFT OUTER JOIN pg_catalog.pg_tablespace t ON c.reltablespace = t.oid
WHERE n.nspname = split_part(p_parent_table, '.', 1)::name
AND c.relname = split_part(p_parent_table, '.', 2)::name;
SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_parent_schema, v_parent_tablename, v_control);
IF v_control_type <> 'time' THEN
IF (v_control_type = 'id' AND v_epoch = 'none') OR v_control_type <> 'id' THEN
RAISE EXCEPTION 'Cannot run on partition set without time based control column or epoch flag set with an id column. Found control: %, epoch: %', v_control_type, v_epoch;
END IF;
END IF;
SELECT current_setting('search_path') INTO v_old_search_path;
IF v_jobmon THEN
SELECT nspname INTO v_jobmon_schema FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_jobmon'::name AND e.extnamespace = n.oid;
IF v_jobmon_schema IS NOT NULL THEN
v_new_search_path := '@extschema@,'||v_jobmon_schema||',pg_temp';
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false');
-- Determine if this table is a child of a subpartition parent. If so, get limits of what child tables can be created based on parent suffix
SELECT sub_min::timestamptz, sub_max::timestamptz INTO v_sub_timestamp_min, v_sub_timestamp_max FROM @extschema@.check_subpartition_limits(p_parent_table, 'time');
IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job(format('PARTMAN CREATE TABLE: %s', p_parent_table));
END IF;
v_partition_expression := CASE
WHEN v_epoch = 'seconds' THEN format('to_timestamp(%I)', v_control)
WHEN v_epoch = 'milliseconds' THEN format('to_timestamp((%I/1000)::float)', v_control)
ELSE format('%I', v_control)
END;
IF p_debug THEN
RAISE NOTICE 'create_partition_time: v_partition_expression: %', v_partition_expression;
END IF;
FOREACH v_time IN ARRAY p_partition_times LOOP
v_partition_timestamp_start := v_time;
BEGIN
v_partition_timestamp_end := v_time + v_partition_interval;
EXCEPTION WHEN datetime_field_overflow THEN
RAISE WARNING 'Attempted partition time interval is outside PostgreSQL''s supported time range.
Child partition creation after time % skipped', v_time;
v_step_overflow_id := add_step(v_job_id, 'Attempted partition time interval is outside PostgreSQL''s supported time range.');
PERFORM update_step(v_step_overflow_id, 'CRITICAL', 'Child partition creation after time '||v_time||' skipped');
CONTINUE;
END;
-- Do not create the child table if it's outside the bounds of the top parent.
IF v_sub_timestamp_min IS NOT NULL THEN
IF v_time < v_sub_timestamp_min OR v_time > v_sub_timestamp_max THEN
CONTINUE;
END IF;
END IF;
-- This suffix generation code is in partition_data_time() as well
v_partition_suffix := to_char(v_time, v_datetime_string);
v_partition_name := @extschema@.check_name_length(v_parent_tablename, v_partition_suffix, TRUE);
-- Check if child exists.
SELECT count(*) INTO v_exists
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = v_parent_schema::name
AND c.relname = v_partition_name::name;
IF v_exists > 0 THEN
CONTINUE;
END IF;
-- Ensure analyze is run if a new partition is created. Otherwise if one isn't, will be false and analyze will be skipped
v_analyze := TRUE;
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Creating new partition %s.%s with interval from %s to %s'
, v_parent_schema
, v_partition_name
, v_partition_timestamp_start
, v_partition_timestamp_end-'1sec'::interval));
END IF;
SELECT relpersistence INTO v_unlogged
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schema::name;
v_sql := 'CREATE';
IF v_unlogged = 'u' THEN
v_sql := v_sql || ' UNLOGGED';
END IF;
-- Close parentheses on LIKE are below due to differing requirements of native subpartitioning
-- Same INCLUDING list is used in create_parent()
v_sql := v_sql || format(' TABLE %I.%I (LIKE %I.%I INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING STORAGE INCLUDING COMMENTS '
, v_parent_schema
, v_partition_name
, v_parent_schema
, v_parent_tablename);
SELECT sub_partition_type, sub_control INTO v_sub_partition_type, v_sub_control
FROM @extschema@.part_config_sub
WHERE sub_parent = p_parent_table;
IF v_sub_partition_type = 'native' THEN
-- NOTE: Need to handle this differently when index inheritance is supported natively
-- Cannot include indexes since they cannot exist on native parents
v_sql := v_sql || format(') PARTITION BY RANGE (%I) ', v_sub_control);
ELSE
v_sql := v_sql || format(' INCLUDING INDEXES) ', v_sub_control);
END IF;
SELECT relhasoids INTO v_hasoids
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schema::name;
IF v_hasoids IS TRUE THEN
v_sql := v_sql || ' WITH (OIDS)';
END IF;
IF p_debug THEN
RAISE NOTICE 'create_partition_time v_sql: %', v_sql;
END IF;
EXECUTE v_sql;
IF v_parent_tablespace IS NOT NULL THEN
EXECUTE format('ALTER TABLE %I.%I SET TABLESPACE %I', v_parent_schema, v_partition_name, v_parent_tablespace);
END IF;
IF v_partition_type = 'native' THEN
IF v_template_table IS NOT NULL THEN
PERFORM @extschema@.inherit_template_properties(p_parent_table, v_parent_schema, v_partition_name);
END IF;
IF v_epoch = 'none' THEN
-- Attach with normal, time-based values for native constraint
EXECUTE format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I FOR VALUES FROM (%L) TO (%L)'
, v_parent_schema
, v_parent_tablename
, v_parent_schema
, v_partition_name
, v_partition_timestamp_start
, v_partition_timestamp_end);
ELSE
-- Must attach with integer based values for native constraint and epoch
IF v_epoch = 'seconds' THEN
EXECUTE format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I FOR VALUES FROM (%L) TO (%L)'
, v_parent_schema
, v_parent_tablename
, v_parent_schema
, v_partition_name
, EXTRACT('epoch' FROM v_partition_timestamp_start)
, EXTRACT('epoch' FROM v_partition_timestamp_end));
ELSIF v_epoch = 'milliseconds' THEN
EXECUTE format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I FOR VALUES FROM (%L) TO (%L)'
, v_parent_schema
, v_parent_tablename
, v_parent_schema
, v_partition_name
, EXTRACT('epoch' FROM v_partition_timestamp_start) * 1000
, EXTRACT('epoch' FROM v_partition_timestamp_end) * 1000);
END IF;
-- Create secondary, time-based constraint since native's constraint is already integer based
EXECUTE format('ALTER TABLE %I.%I ADD CONSTRAINT %I CHECK (%s >= %L AND %4$s < %6$L)'
, v_parent_schema
, v_partition_name
, v_partition_name||'_partition_check'
, v_partition_expression
, v_partition_timestamp_start
, v_partition_timestamp_end);
END IF;
ELSE
-- Non-native always gets time-based constraint
EXECUTE format('ALTER TABLE %I.%I ADD CONSTRAINT %I CHECK (%s >= %L AND %4$s < %6$L)'
, v_parent_schema
, v_partition_name
, v_partition_name||'_partition_check'
, v_partition_expression
, v_partition_timestamp_start
, v_partition_timestamp_end);
IF v_epoch = 'seconds' THEN
-- Non-native needs secondary, integer based constraint for epoch
EXECUTE format('ALTER TABLE %I.%I ADD CONSTRAINT %I CHECK (%I >= %L AND %I < %L)'
, v_parent_schema
, v_partition_name
, v_partition_name||'_partition_int_check'
, v_control
, EXTRACT('epoch' from v_partition_timestamp_start)
, v_control
, EXTRACT('epoch' from v_partition_timestamp_end) );
ELSIF v_epoch = 'milliseconds' THEN
EXECUTE format('ALTER TABLE %I.%I ADD CONSTRAINT %I CHECK (%I >= %L AND %I < %L)'
, v_parent_schema
, v_partition_name
, v_partition_name||'_partition_int_check'
, v_control
, EXTRACT('epoch' from v_partition_timestamp_start) * 1000
, v_control
, EXTRACT('epoch' from v_partition_timestamp_end) * 1000);
END IF;
EXECUTE format('ALTER TABLE %I.%I INHERIT %I.%I'
, v_parent_schema
, v_partition_name
, v_parent_schema
, v_parent_tablename);
-- If custom time, set extra config options.
IF v_partition_type = 'time-custom' THEN
INSERT INTO @extschema@.custom_time_partitions (parent_table, child_table, partition_range)
VALUES ( p_parent_table, v_parent_schema||'.'||v_partition_name, tstzrange(v_partition_timestamp_start, v_partition_timestamp_end, '[)') );
END IF;
-- Indexes cannot be created on the parent, so clustering cannot be used for native yet.
PERFORM @extschema@.apply_cluster(v_parent_schema, v_parent_tablename, v_parent_schema, v_partition_name);
-- Foreign keys to other tables not supported in native
IF v_inherit_fk THEN
PERFORM @extschema@.apply_foreign_keys(p_parent_table, v_parent_schema||'.'||v_partition_name, v_job_id);
END IF;
END IF; -- end native check
-- NOTE: Privileges not automatically inherited for native. Only do so if config flag is set
IF v_partition_type != 'native' OR (v_partition_type = 'native' AND v_inherit_privileges = TRUE) THEN
PERFORM @extschema@.apply_privileges(v_parent_schema, v_parent_tablename, v_parent_schema, v_partition_name, v_job_id);
END IF;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
-- Will only loop once and only if sub_partitioning is actually configured
-- This seemed easier than assigning a bunch of variables then doing an IF condition
FOR v_row IN
SELECT sub_parent
, sub_partition_type
, sub_control
, sub_partition_interval
, sub_constraint_cols
, sub_premake
, sub_optimize_trigger
, sub_optimize_constraint
, sub_epoch
, sub_inherit_fk
, sub_retention
, sub_retention_schema
, sub_retention_keep_table
, sub_retention_keep_index
, sub_automatic_maintenance
, sub_infinite_time_partitions
, sub_jobmon
, sub_trigger_exception_handling
, sub_template_table
, sub_inherit_privileges
FROM @extschema@.part_config_sub
WHERE sub_parent = p_parent_table
LOOP
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Subpartitioning %s.%s', v_parent_schema, v_partition_name));
END IF;
v_sql := format('SELECT @extschema@.create_parent(
p_parent_table := %L
, p_control := %L
, p_type := %L
, p_interval := %L
, p_constraint_cols := %L
, p_premake := %L
, p_automatic_maintenance := %L
, p_inherit_fk := %L
, p_epoch := %L
, p_template_table := %L
, p_jobmon := %L )'
, v_parent_schema||'.'||v_partition_name
, v_row.sub_control
, v_row.sub_partition_type
, v_row.sub_partition_interval
, v_row.sub_constraint_cols
, v_row.sub_premake
, v_row.sub_automatic_maintenance
, v_row.sub_inherit_fk
, v_row.sub_epoch
, v_row.sub_template_table
, v_row.sub_jobmon);
IF p_debug THEN
RAISE NOTICE 'create_partition_time (create_parent loop): %', v_sql;
END IF;
EXECUTE v_sql;
UPDATE @extschema@.part_config SET
retention_schema = v_row.sub_retention_schema
, retention_keep_table = v_row.sub_retention_keep_table
, retention_keep_index = v_row.sub_retention_keep_index
, optimize_trigger = v_row.sub_optimize_trigger
, optimize_constraint = v_row.sub_optimize_constraint
, infinite_time_partitions = v_row.sub_infinite_time_partitions
, trigger_exception_handling = v_row.sub_trigger_exception_handling
, inherit_privileges = v_row.sub_inherit_privileges
WHERE parent_table = v_parent_schema||'.'||v_partition_name;
END LOOP; -- end sub partitioning LOOP
-- Manage additonal constraints if set
PERFORM @extschema@.apply_constraints(p_parent_table, p_job_id := v_job_id, p_debug := p_debug);
IF v_publications IS NOT NULL THEN
-- NOTE: Publications currently not supported on parent table, but are supported on the table partitions if individually assigned.
PERFORM @extschema@.apply_publications(p_parent_table, v_parent_schema, v_partition_name);
END IF;
v_partition_created := true;
END LOOP;
-- v_analyze is a local check if a new table is made.
-- p_analyze is a parameter to say whether to run the analyze at all. Used by create_parent() to avoid long exclusive lock or run_maintenence() to avoid long creation runs.
IF v_analyze AND p_analyze THEN
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, format('Analyzing partition set: %s', p_parent_table));
END IF;
EXECUTE format('ANALYZE %I.%I', v_parent_schema, v_parent_tablename);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
END IF;
IF v_jobmon_schema IS NOT NULL THEN
IF v_partition_created = false THEN
v_step_id := add_step(v_job_id, format('No partitions created for partition set: %s. Attempted intervals: %s', p_parent_table, p_partition_times));
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;
IF v_step_overflow_id IS NOT NULL THEN
PERFORM fail_job(v_job_id);
ELSE
PERFORM close_job(v_job_id);
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RETURN v_partition_created;
EXCEPTION
WHEN OTHERS THEN
GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT,
ex_context = PG_EXCEPTION_CONTEXT,
ex_detail = PG_EXCEPTION_DETAIL,
ex_hint = PG_EXCEPTION_HINT;
IF v_jobmon_schema IS NOT NULL THEN
IF v_job_id IS NULL THEN
EXECUTE format('SELECT %I.add_job(''PARTMAN CREATE TABLE: %s'')', v_jobmon_schema, p_parent_table) INTO v_job_id;
EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before job logging started'')', v_jobmon_schema, v_job_id, p_parent_table) INTO v_step_id;
ELSIF v_step_id IS NULL THEN
EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before first step logged'')', v_jobmon_schema, v_job_id) INTO v_step_id;
END IF;
EXECUTE format('SELECT %I.update_step(%s, ''CRITICAL'', %L)', v_jobmon_schema, v_step_id, 'ERROR: '||coalesce(SQLERRM,'unknown'));
EXECUTE format('SELECT %I.fail_job(%s)', v_jobmon_schema, v_job_id);
END IF;
RAISE EXCEPTION '%
CONTEXT: %
DETAIL: %
HINT: %', ex_message, ex_context, ex_detail, ex_hint;
END
$$;
CREATE OR REPLACE FUNCTION @extschema@.show_partition_info(p_child_table text
, p_partition_interval text DEFAULT NULL
, p_parent_table text DEFAULT NULL
, OUT child_start_time timestamptz
, OUT child_end_time timestamptz
, OUT child_start_id bigint
, OUT child_end_id bigint
, OUT suffix text)
RETURNS record
LANGUAGE plpgsql STABLE
AS $$
DECLARE
v_child_schema text;
v_child_tablename text;
v_control text;
v_control_type text;
v_datetime_string text;
v_epoch text;
v_new_search_path text := '@extschema@,pg_temp';
v_old_search_path text;
v_parent_table text;
v_partition_interval text;
v_partition_type text;
v_quarter text;
v_suffix text;
v_suffix_position int;
v_year text;
BEGIN
/*
* Show the data boundries for a given child table as well as the suffix that will be used.
* Passing the parent table argument improves performance by avoiding a catalog lookup.
* Passing an interval lets you set one different than the default configured one if desired.
*/
SELECT current_setting('search_path') INTO v_old_search_path;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false');
SELECT n.nspname, c.relname INTO v_child_schema, v_child_tablename
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = split_part(p_child_table, '.', 1)::name
AND c.relname = split_part(p_child_table, '.', 2)::name;
IF v_child_tablename IS NULL THEN
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RAISE EXCEPTION 'Child table given does not exist (%)', p_child_table;
END IF;
IF p_parent_table IS NULL THEN
SELECT n.nspname||'.'|| c.relname INTO v_parent_table
FROM pg_catalog.pg_inherits h
JOIN pg_catalog.pg_class c ON c.oid = h.inhparent
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE h.inhrelid::regclass = p_child_table::regclass;
ELSE
v_parent_table := p_parent_table;
END IF;
IF p_partition_interval IS NULL THEN
SELECT control, partition_interval, partition_type, datetime_string, epoch
INTO v_control, v_partition_interval, v_partition_type, v_datetime_string, v_epoch
FROM @extschema@.part_config WHERE parent_table = v_parent_table;
ELSE
v_partition_interval := p_partition_interval;
SELECT control, partition_type, datetime_string, epoch
INTO v_control, v_partition_type, v_datetime_string, v_epoch
FROM @extschema@.part_config WHERE parent_table = v_parent_table;
END IF;
IF v_control IS NULL THEN
RAISE EXCEPTION 'Parent table of given child not managed by pg_partman: %', v_parent_table;
END IF;
SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_child_schema, v_child_tablename, v_control);
v_suffix_position := (length(v_child_tablename) - position('p_' in reverse(v_child_tablename))) + 2;
v_suffix := substring(v_child_tablename from v_suffix_position);
IF v_control_type = 'time' OR (v_control_type = 'id' AND v_epoch <> 'none') THEN
IF v_partition_interval::interval <> '3 months' OR (v_partition_interval::interval = '3 months' AND v_partition_type = 'time-custom') THEN
child_start_time := to_timestamp(v_suffix, v_datetime_string);
ELSE
-- to_timestamp doesn't recognize 'Q' date string formater. Handle it
v_year := split_part(v_suffix, 'q', 1);
v_quarter := split_part(v_suffix, 'q', 2);
CASE
WHEN v_quarter = '1' THEN
child_start_time := to_timestamp(v_year || '-01-01', 'YYYY-MM-DD');
WHEN v_quarter = '2' THEN
child_start_time := to_timestamp(v_year || '-04-01', 'YYYY-MM-DD');
WHEN v_quarter = '3' THEN
child_start_time := to_timestamp(v_year || '-07-01', 'YYYY-MM-DD');
WHEN v_quarter = '4' THEN
child_start_time := to_timestamp(v_year || '-10-01', 'YYYY-MM-DD');
ELSE
-- handle case when partition name did not use "q" convetion
child_start_time := to_timestamp(v_suffix, v_datetime_string);
END CASE;
END IF;
child_end_time := (child_start_time + v_partition_interval::interval) - '1 second'::interval;
ELSIF v_control_type = 'id' THEN
child_start_id := v_suffix::bigint;
child_end_id := (child_start_id + v_partition_interval::bigint) - 1;
ELSE
RAISE EXCEPTION 'Invalid partition type encountered in show_partition_info()';
END IF;
suffix = v_suffix;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RETURN;
END
$$;
CREATE FUNCTION @extschema@.check_default(p_exact_count boolean DEFAULT true) RETURNS SETOF @extschema@.check_default_table
LANGUAGE plpgsql STABLE
SET search_path = @extschema@,pg_temp
AS $$
DECLARE
v_count bigint = 0;
v_default_schemaname text;
v_default_tablename text;
v_parent_schemaname text;
v_parent_tablename text;
v_row record;
v_sql text;
v_trouble @extschema@.check_default_table%rowtype;
BEGIN
/*
* Function to monitor for data getting inserted into parent/default tables
*/
FOR v_row IN
SELECT parent_table, partition_type FROM @extschema@.part_config
LOOP
SELECT schemaname, tablename
INTO v_parent_schemaname, v_parent_tablename
FROM pg_catalog.pg_tables
WHERE schemaname = split_part(v_row.parent_table, '.', 1)::name
AND tablename = split_part(v_row.parent_table, '.', 2)::name;
IF v_row.partition_type = 'partman' THEN
-- trigger based checks parent table
IF p_exact_count THEN
v_sql := format('SELECT count(1) AS n FROM ONLY %I.%I', v_parent_schemaname, v_parent_tablename);
ELSE
v_sql := format('SELECT count(1) AS n FROM (SELECT 1 FROM ONLY %I.%I LIMIT 1) x', v_parent_schemaname, v_parent_tablename);
END IF;
EXECUTE v_sql INTO v_count;
IF v_count > 0 THEN
v_trouble.default_table := v_parent_schemaname ||'.'|| v_parent_tablename;
v_trouble.count := v_count;
RETURN NEXT v_trouble;
END IF;
ELSIF v_row.partition_type = 'native' AND current_setting('server_version_num')::int >= 110000 THEN
-- native PG11+ checks default if it exists
v_sql := format('SELECT n.nspname::text, c.relname::text FROM
pg_catalog.pg_inherits h
JOIN pg_catalog.pg_class c ON c.oid = h.inhrelid
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE h.inhparent = ''%I.%I''::regclass
AND pg_get_expr(relpartbound, c.oid) = ''DEFAULT'''
, v_parent_schemaname
, v_parent_tablename);
EXECUTE v_sql INTO v_default_schemaname, v_default_tablename;
IF v_default_schemaname IS NOT NULL AND v_default_tablename IS NOT NULL THEN
IF p_exact_count THEN
v_sql := format('SELECT count(1) AS n FROM ONLY %I.%I', v_default_schemaname, v_default_tablename);
ELSE
v_sql := format('SELECT count(1) AS n FROM (SELECT 1 FROM ONLY %I.%I LIMIT 1) x', v_default_schemaname, v_default_tablename);
END IF;
EXECUTE v_sql INTO v_count;
IF v_count > 0 THEN
v_trouble.default_table := v_default_schemaname ||'.'|| v_default_tablename;
v_trouble.count := v_count;
RETURN NEXT v_trouble;
END IF;
END IF;
END IF;
v_count := 0;
END LOOP;
RETURN;
END
$$;
CREATE OR REPLACE FUNCTION @extschema@.create_parent(
p_parent_table text
, p_control text
, p_type text
, p_interval text
, p_constraint_cols text[] DEFAULT NULL
, p_premake int DEFAULT 4
, p_automatic_maintenance text DEFAULT 'on'
, p_start_partition text DEFAULT NULL
, p_inherit_fk boolean DEFAULT true
, p_epoch text DEFAULT 'none'
, p_upsert text DEFAULT ''
, p_publications text[] DEFAULT NULL
, p_trigger_return_null boolean DEFAULT true
, p_template_table text DEFAULT NULL
, p_jobmon boolean DEFAULT true
, p_debug boolean DEFAULT false)
RETURNS boolean
LANGUAGE plpgsql
AS $$
DECLARE
ex_context text;
ex_detail text;
ex_hint text;
ex_message text;
v_partattrs smallint[];
v_base_timestamp timestamptz;
v_count int := 1;
v_control_type text;
v_control_exact_type text;
v_datetime_string text;
v_default_partition text;
v_higher_control_type text;
v_higher_parent_control text;
v_higher_parent_schema text := split_part(p_parent_table, '.', 1);
v_higher_parent_table text := split_part(p_parent_table, '.', 2);
v_id_interval bigint;
v_inherit_privileges boolean := false;
v_job_id bigint;
v_jobmon_schema text;
v_last_partition_created boolean;
v_max bigint;
v_native_sub_control text;
v_notnull boolean;
v_new_search_path text := '@extschema@,pg_temp';
v_old_search_path text;
v_parent_owner text;
v_parent_partition_id bigint;
v_parent_partition_timestamp timestamptz;
v_parent_schema text;
v_parent_tablename text;
v_parent_tablespace text;
v_part_col text;
v_part_type text;
v_partition_time timestamptz;
v_partition_time_array timestamptz[];
v_partition_id_array bigint[];
v_partstrat char;
v_publication_exists text;
v_row record;
v_sql text;
v_start_time timestamptz;
v_starting_partition_id bigint;
v_step_id bigint;
v_step_overflow_id bigint;
v_sub_parent text;
v_success boolean := false;
v_template_schema text;
v_template_tablename text;
v_time_interval interval;
v_top_datetime_string text;
v_top_parent_schema text := split_part(p_parent_table, '.', 1);
v_top_parent_table text := split_part(p_parent_table, '.', 2);
v_unlogged char;
BEGIN
/*
* Function to turn a table into the parent of a partition set
*/
IF position('.' in p_parent_table) = 0 THEN
RAISE EXCEPTION 'Parent table must be schema qualified';
END IF;
IF p_upsert <> '' THEN
IF current_setting('server_version_num')::int < 90500 THEN
RAISE EXCEPTION 'INSERT ... ON CONFLICT (UPSERT) feature is only supported in PostgreSQL 9.5 and later';
END IF;
IF p_type = 'native' THEN
RAISE EXCEPTION 'Native partitioning does not currently support upsert. Use pg_partman''s partitioning methods instead if this is required';
END IF;
END IF;
SELECT n.nspname, c.relname, t.spcname, c.relpersistence
INTO v_parent_schema, v_parent_tablename, v_parent_tablespace, v_unlogged
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
LEFT OUTER JOIN pg_catalog.pg_tablespace t ON c.reltablespace = t.oid
WHERE n.nspname = split_part(p_parent_table, '.', 1)::name
AND c.relname = split_part(p_parent_table, '.', 2)::name;
IF v_parent_tablename IS NULL THEN
RAISE EXCEPTION 'Unable to find given parent table in system catalogs. Please create parent table first: %', p_parent_table;
END IF;
SELECT attnotnull INTO v_notnull
FROM pg_catalog.pg_attribute a
JOIN pg_catalog.pg_class c ON a.attrelid = c.oid
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schema::name
AND a.attname = p_control::name;
IF p_type <> 'native' AND (v_notnull = false OR v_notnull IS NULL) THEN
RAISE EXCEPTION 'Control column given (%) for parent table (%) does not exist or must be set to NOT NULL', p_control, p_parent_table;
END IF;
SELECT general_type, exact_type INTO v_control_type, v_control_exact_type
FROM @extschema@.check_control_type(v_parent_schema, v_parent_tablename, p_control);
IF (p_epoch <> 'none' AND v_control_type <> 'id') THEN
RAISE EXCEPTION 'p_epoch can only be used with an integer based control column and does not work for native partitioning';
END IF;
IF NOT @extschema@.check_partition_type(p_type) THEN
RAISE EXCEPTION '% is not a valid partitioning type for pg_partman', p_type;
END IF;
IF p_type = 'native' THEN
IF current_setting('server_version_num')::int < 100000 THEN
RAISE EXCEPTION 'Native partitioning only available in PostgreSQL versions 10.0+';
END IF;
-- Check if given parent table has been already set up as a partitioned table and is ranged
SELECT p.partstrat, partattrs INTO v_partstrat, v_partattrs
FROM pg_catalog.pg_partitioned_table p
JOIN pg_catalog.pg_class c ON p.partrelid = c.oid
JOIN pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = v_parent_schema::name
AND c.relname = v_parent_tablename::name;
IF v_partstrat <> 'r' OR v_partstrat IS NULL THEN
RAISE EXCEPTION 'When using native partitioning, you must have created the given parent table as ranged (not list) partitioned already. Ex: CREATE TABLE ... PARITIONED BY RANGE ...)';
END IF;
IF array_length(v_partattrs, 1) > 1 THEN
RAISE NOTICE 'pg_partman only supports single column native partitioning at this time. Found % columns in given parent definition.', array_length(v_partattrs, 1);
END IF;
SELECT a.attname, t.typname
INTO v_part_col, v_part_type
FROM pg_attribute a
JOIN pg_class c ON a.attrelid = c.oid
JOIN pg_namespace n ON c.relnamespace = n.oid
JOIN pg_type t ON a.atttypid = t.oid
WHERE n.nspname = v_parent_schema::name
AND c.relname = v_parent_tablename::name
AND attnum IN (SELECT unnest(partattrs) FROM pg_partitioned_table p WHERE a.attrelid = p.partrelid);
IF p_control <> v_part_col OR v_control_exact_type <> v_part_type THEN
RAISE EXCEPTION 'Control column and type given in arguments (%, %) does not match the control column and type of the given native partition set (%, %)', p_control, v_control_exact_type, v_part_col, v_part_type;
END IF;
-- Check that control column is a usable type for pg_partman.
IF v_control_type NOT IN ('time', 'id') THEN
RAISE EXCEPTION 'Only date/time or integer types are allowed for the control column with native partitioning.';
END IF;
-- Table to handle properties not natively inherited yet (indexes, fks, etc)
IF p_template_table IS NULL THEN
v_template_schema := '@extschema@';
v_template_tablename := @extschema@.check_name_length('template_'||v_parent_schema||'_'||v_parent_tablename);
EXECUTE format('CREATE TABLE IF NOT EXISTS %I.%I (LIKE %I.%I)', '@extschema@', v_template_tablename, v_parent_schema, v_parent_tablename);
SELECT pg_get_userbyid(c.relowner) INTO v_parent_owner
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = v_parent_schema::name
AND c.relname = v_parent_tablename::name;
EXECUTE format('ALTER TABLE %I.%I OWNER TO %I'
, '@extschema@'
, v_template_tablename
, v_parent_owner);
ELSE
SELECT n.nspname, c.relname INTO v_template_schema, v_template_tablename
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = split_part(p_template_table, '.', 1)::name
AND c.relname = split_part(p_template_table, '.', 2)::name;
IF v_template_tablename IS NULL THEN
RAISE EXCEPTION 'Unable to find given template table in system catalogs (%). Please create template table first or leave parameter NULL to have a default one created for you.', p_parent_table;
END IF;
END IF;
ELSE -- if not native
IF current_setting('server_version_num')::int >= 100000 THEN
SELECT p.partstrat INTO v_partstrat
FROM pg_catalog.pg_partitioned_table p
JOIN pg_catalog.pg_class c ON p.partrelid = c.oid
JOIN pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = v_parent_schema::name
AND c.relname = v_parent_tablename::name;
END IF;
IF v_partstrat IS NOT NULL THEN
RAISE EXCEPTION 'Given parent table has been set up with native partitioning therefore cannot be used with pg_partman''s other partitioning types. Either recreate table non-native or set the type argument to ''native''';
END IF;
END IF; -- end if "native" check
IF p_publications IS NOT NULL THEN
IF current_setting('server_version_num')::int < 100000 THEN
RAISE EXCEPTION 'p_publications argument not null but CREATE PUBLICATION is only available in PostgreSQL versions 10.0+';
END IF;
IF p_publications = '{}' THEN
RAISE EXCEPTION 'p_publications cannot be an empty set';
END IF;
FOR v_row IN
SELECT unnest(p_publications) AS pubname
LOOP
SELECT pubname INTO v_publication_exists FROM pg_catalog.pg_publication where pubname = v_row.pubname::name;
IF v_publication_exists IS NULL THEN
RAISE EXCEPTION 'Given publication name (%) does not exist in system catalog. Ensure it is created first.', v_row.pubname;
END IF;
END LOOP;
END IF;
-- Only inherit parent ownership/privileges on non-native sets by default
-- This is false by default so initial partition set creation doesn't require superuser.
IF p_type = 'native' THEN
v_inherit_privileges = false;
ELSE
v_inherit_privileges = true;
END IF;
SELECT current_setting('search_path') INTO v_old_search_path;
IF p_jobmon THEN
SELECT nspname INTO v_jobmon_schema FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_jobmon'::name AND e.extnamespace = n.oid;
IF v_jobmon_schema IS NOT NULL THEN
v_new_search_path := '@extschema@,'||v_jobmon_schema||',pg_temp';
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false');
EXECUTE format('LOCK TABLE %I.%I IN ACCESS EXCLUSIVE MODE', v_parent_schema, v_parent_tablename);
IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job(format('PARTMAN SETUP PARENT: %s', p_parent_table));
v_step_id := add_step(v_job_id, format('Creating initial partitions on new parent table: %s', p_parent_table));
END IF;
-- If this parent table has siblings that are also partitioned (subpartitions), ensure this parent gets added to part_config_sub table so future maintenance will subpartition it
-- Just doing in a loop to avoid having to assign a bunch of variables (should only run once, if at all; constraint should enforce only one value.)
FOR v_row IN
WITH parent_table AS (
SELECT h.inhparent AS parent_oid
FROM pg_catalog.pg_inherits h
JOIN pg_catalog.pg_class c ON h.inhrelid = c.oid
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schema::name
), sibling_children AS (
SELECT i.inhrelid::regclass::text AS tablename
FROM pg_inherits i
JOIN parent_table p ON i.inhparent = p.parent_oid
)
SELECT DISTINCT sub_partition_type
, sub_control
, sub_partition_interval
, sub_constraint_cols
, sub_premake
, sub_inherit_fk
, sub_retention
, sub_retention_schema
, sub_retention_keep_table
, sub_retention_keep_index
, sub_automatic_maintenance
, sub_epoch
, sub_optimize_trigger
, sub_optimize_constraint
, sub_infinite_time_partitions
, sub_jobmon
, sub_trigger_exception_handling
, sub_upsert
, sub_trigger_return_null
, sub_template_table
, sub_inherit_privileges
FROM @extschema@.part_config_sub a
JOIN sibling_children b on a.sub_parent = b.tablename LIMIT 1
LOOP
INSERT INTO @extschema@.part_config_sub (
sub_parent
, sub_partition_type
, sub_control
, sub_partition_interval
, sub_constraint_cols
, sub_premake
, sub_inherit_fk
, sub_retention
, sub_retention_schema
, sub_retention_keep_table
, sub_retention_keep_index
, sub_automatic_maintenance
, sub_epoch
, sub_optimize_trigger
, sub_optimize_constraint
, sub_infinite_time_partitions
, sub_jobmon
, sub_trigger_exception_handling
, sub_upsert
, sub_trigger_return_null
, sub_template_table
, sub_inherit_privileges)
VALUES (
p_parent_table
, v_row.sub_partition_type
, v_row.sub_control
, v_row.sub_partition_interval
, v_row.sub_constraint_cols
, v_row.sub_premake
, v_row.sub_inherit_fk
, v_row.sub_retention
, v_row.sub_retention_schema
, v_row.sub_retention_keep_table
, v_row.sub_retention_keep_index
, v_row.sub_automatic_maintenance
, v_row.sub_epoch
, v_row.sub_optimize_trigger
, v_row.sub_optimize_constraint
, v_row.sub_infinite_time_partitions
, v_row.sub_jobmon
, v_row.sub_trigger_exception_handling
, v_row.sub_upsert
, v_row.sub_trigger_return_null
, v_row.sub_template_table
, v_row.sub_inherit_privileges);
-- Set this equal to sibling configs so that newly created child table
-- privileges are set properly below during initial setup.
-- This setting is special because it applies immediately to the new child
-- tables of a given parent, not just during maintenance like most other settings.
v_inherit_privileges = v_row.sub_inherit_privileges;
END LOOP;
IF v_control_type = 'time' OR (v_control_type = 'id' AND p_epoch <> 'none') THEN
CASE
WHEN p_interval = 'yearly' THEN
v_time_interval := '1 year';
WHEN p_interval = 'quarterly' THEN
v_time_interval := '3 months';
WHEN p_interval = 'monthly' THEN
v_time_interval := '1 month';
WHEN p_interval = 'weekly' THEN
v_time_interval := '1 week';
WHEN p_interval = 'daily' THEN
v_time_interval := '1 day';
WHEN p_interval = 'hourly' THEN
v_time_interval := '1 hour';
WHEN p_interval = 'half-hour' THEN
v_time_interval := '30 mins';
WHEN p_interval = 'quarter-hour' THEN
v_time_interval := '15 mins';
ELSE
IF p_type <> 'native' THEN
-- Reset for use as part_config type value below
p_type = 'time-custom';
END IF;
v_time_interval := p_interval::interval;
IF v_time_interval < '1 second'::interval THEN
RAISE EXCEPTION 'Partitioning interval must be 1 second or greater';
END IF;
END CASE;
-- First partition is either the min premake or p_start_partition
v_start_time := COALESCE(p_start_partition::timestamptz, CURRENT_TIMESTAMP - (v_time_interval * p_premake));
IF v_time_interval >= '1 year' THEN
v_base_timestamp := date_trunc('year', v_start_time);
IF v_time_interval >= '10 years' THEN
v_base_timestamp := date_trunc('decade', v_start_time);
IF v_time_interval >= '100 years' THEN
v_base_timestamp := date_trunc('century', v_start_time);
IF v_time_interval >= '1000 years' THEN
v_base_timestamp := date_trunc('millennium', v_start_time);
END IF; -- 1000
END IF; -- 100
END IF; -- 10
END IF; -- 1
v_datetime_string := 'YYYY';
IF v_time_interval < '1 year' THEN
IF p_interval = 'quarterly' THEN
v_base_timestamp := date_trunc('quarter', v_start_time);
v_datetime_string = 'YYYY"q"Q';
ELSE
v_base_timestamp := date_trunc('month', v_start_time);
v_datetime_string := v_datetime_string || '_MM';
END IF;
IF v_time_interval < '1 month' THEN
IF p_interval = 'weekly' THEN
v_base_timestamp := date_trunc('week', v_start_time);
v_datetime_string := 'IYYY"w"IW';
ELSE
v_base_timestamp := date_trunc('day', v_start_time);
v_datetime_string := v_datetime_string || '_DD';
END IF;
IF v_time_interval < '1 day' THEN
v_base_timestamp := date_trunc('hour', v_start_time);
v_datetime_string := v_datetime_string || '_HH24MI';
IF v_time_interval < '1 minute' THEN
v_base_timestamp := date_trunc('minute', v_start_time);
v_datetime_string := v_datetime_string || 'SS';
END IF; -- minute
END IF; -- day
END IF; -- month
END IF; -- year
v_partition_time_array := array_append(v_partition_time_array, v_base_timestamp);
LOOP
-- If current loop value is less than or equal to the value of the max premake, add time to array.
IF (v_base_timestamp + (v_time_interval * v_count)) < (CURRENT_TIMESTAMP + (v_time_interval * p_premake)) THEN
BEGIN
v_partition_time := (v_base_timestamp + (v_time_interval * v_count))::timestamptz;
v_partition_time_array := array_append(v_partition_time_array, v_partition_time);
EXCEPTION WHEN datetime_field_overflow THEN
RAISE WARNING 'Attempted partition time interval is outside PostgreSQL''s supported time range.
Child partition creation after time % skipped', v_partition_time;
v_step_overflow_id := add_step(v_job_id, 'Attempted partition time interval is outside PostgreSQL''s supported time range.');
PERFORM update_step(v_step_overflow_id, 'CRITICAL', 'Child partition creation after time '||v_partition_time||' skipped');
CONTINUE;
END;
ELSE
EXIT; -- all needed partitions added to array. Exit the loop.
END IF;
v_count := v_count + 1;
END LOOP;
INSERT INTO @extschema@.part_config (
parent_table
, partition_type
, partition_interval
, epoch
, control
, premake
, constraint_cols
, datetime_string
, automatic_maintenance
, inherit_fk
, jobmon
, upsert
, trigger_return_null
, template_table
, publications
, inherit_privileges)
VALUES (
p_parent_table
, p_type
, v_time_interval
, p_epoch
, p_control
, p_premake
, p_constraint_cols
, v_datetime_string
, p_automatic_maintenance
, p_inherit_fk
, p_jobmon
, p_upsert
, p_trigger_return_null
, v_template_schema||'.'||v_template_tablename
, p_publications
, v_inherit_privileges);
RAISE DEBUG 'create_parent: v_partition_time_array: %', v_partition_time_array;
v_last_partition_created := @extschema@.create_partition_time(p_parent_table, v_partition_time_array, false);
IF v_last_partition_created = false THEN
-- This can happen with subpartitioning when future or past partitions prevent child creation because they're out of range of the parent
-- First see if this parent is a subpartition managed by pg_partman
WITH top_oid AS (
SELECT i.inhparent AS top_parent_oid
FROM pg_catalog.pg_inherits i
JOIN pg_catalog.pg_class c ON c.oid = i.inhrelid
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schema::name
) SELECT n.nspname, c.relname
INTO v_top_parent_schema, v_top_parent_table
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
JOIN top_oid t ON c.oid = t.top_parent_oid
JOIN @extschema@.part_config p ON p.parent_table = n.nspname||'.'||c.relname;
IF v_top_parent_table IS NOT NULL THEN
-- If so create the lowest possible partition that is within the boundary of the parent
SELECT child_start_time INTO v_parent_partition_timestamp FROM @extschema@.show_partition_info(p_parent_table, p_parent_table := v_top_parent_schema||'.'||v_top_parent_table);
IF v_base_timestamp >= v_parent_partition_timestamp THEN
WHILE v_base_timestamp >= v_parent_partition_timestamp LOOP
v_base_timestamp := v_base_timestamp - v_time_interval;
END LOOP;
v_base_timestamp := v_base_timestamp + v_time_interval; -- add one back since while loop set it one lower than is needed
ELSIF v_base_timestamp < v_parent_partition_timestamp THEN
WHILE v_base_timestamp < v_parent_partition_timestamp LOOP
v_base_timestamp := v_base_timestamp + v_time_interval;
END LOOP;
-- Don't need to remove one since new starting time will fit in top parent interval
END IF;
v_partition_time_array := NULL;
v_partition_time_array := array_append(v_partition_time_array, v_base_timestamp);
v_last_partition_created := @extschema@.create_partition_time(p_parent_table, v_partition_time_array, false);
ELSE
RAISE WARNING 'No child tables created. Check that all child tables did not already exist and may not have been part of partition set. Given parent has still been configured with pg_partman, but may not have expected children. Please review schema and config to confirm things are ok.';
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
IF v_step_overflow_id IS NOT NULL THEN
PERFORM fail_job(v_job_id);
ELSE
PERFORM close_job(v_job_id);
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RETURN v_success;
END IF;
END IF; -- End v_last_partition IF
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', format('Time partitions premade: %s', p_premake));
END IF;
END IF;
IF v_control_type = 'id' AND p_epoch = 'none' THEN
v_id_interval := p_interval::bigint;
IF p_type <> 'native' AND v_id_interval < 10 THEN
RAISE EXCEPTION 'Interval for serial, non-native partitioning must be greater than or equal to 10';
END IF;
-- Check if parent table is a subpartition of an already existing id partition set managed by pg_partman.
WHILE v_higher_parent_table IS NOT NULL LOOP -- initially set in DECLARE
WITH top_oid AS (
SELECT i.inhparent AS top_parent_oid
FROM pg_catalog.pg_inherits i
JOIN pg_catalog.pg_class c ON c.oid = i.inhrelid
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE n.nspname = v_higher_parent_schema::name
AND c.relname = v_higher_parent_table::name
) SELECT n.nspname, c.relname, p.control
INTO v_higher_parent_schema, v_higher_parent_table, v_higher_parent_control
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
JOIN top_oid t ON c.oid = t.top_parent_oid
JOIN @extschema@.part_config p ON p.parent_table = n.nspname||'.'||c.relname;
IF v_higher_parent_table IS NOT NULL THEN
SELECT general_type INTO v_higher_control_type
FROM @extschema@.check_control_type(v_higher_parent_schema, v_higher_parent_table, v_higher_parent_control);
IF v_higher_control_type <> 'id' THEN
-- The parent above the p_parent_table parameter is not partitioned by ID
-- so don't check for max values in parents that aren't partitioned by ID.
-- This avoids missing child tables in subpartition sets that have differing ID data
EXIT;
END IF;
-- v_top_parent initially set in DECLARE
v_top_parent_schema := v_higher_parent_schema;
v_top_parent_table := v_higher_parent_table;
END IF;
END LOOP;
-- If custom start partition is set, use that.
-- If custom start is not set and there is already data, start partitioning with the highest current value and ensure it's grabbed from highest top parent table
IF p_start_partition IS NOT NULL THEN
v_max := p_start_partition::bigint;
ELSE
v_sql := format('SELECT COALESCE(max(%I)::bigint, 0) FROM %I.%I LIMIT 1'
, p_control
, v_top_parent_schema
, v_top_parent_table);
EXECUTE v_sql INTO v_max;
END IF;
v_starting_partition_id := v_max - (v_max % v_id_interval);
FOR i IN 0..p_premake LOOP
-- Only make previous partitions if ID value is less than the starting value and positive (and custom start partition wasn't set)
IF p_start_partition IS NULL AND
(v_starting_partition_id - (v_id_interval*i)) > 0 AND
(v_starting_partition_id - (v_id_interval*i)) < v_starting_partition_id
THEN
v_partition_id_array = array_append(v_partition_id_array, (v_starting_partition_id - v_id_interval*i));
END IF;
v_partition_id_array = array_append(v_partition_id_array, (v_id_interval*i) + v_starting_partition_id);
END LOOP;
INSERT INTO @extschema@.part_config (
parent_table
, partition_type
, partition_interval
, control
, premake
, constraint_cols
, automatic_maintenance
, inherit_fk
, jobmon
, upsert
, trigger_return_null
, template_table
, publications
, inherit_privileges)
VALUES (
p_parent_table
, p_type
, v_id_interval
, p_control
, p_premake
, p_constraint_cols
, p_automatic_maintenance
, p_inherit_fk
, p_jobmon
, p_upsert
, p_trigger_return_null
, v_template_schema||'.'||v_template_tablename
, p_publications
, v_inherit_privileges);
v_last_partition_created := @extschema@.create_partition_id(p_parent_table, v_partition_id_array, false);
IF v_last_partition_created = false THEN
-- This can happen with subpartitioning when future or past partitions prevent child creation because they're out of range of the parent
-- See if it's actually a subpartition of a parent id partition
WITH top_oid AS (
SELECT i.inhparent AS top_parent_oid
FROM pg_catalog.pg_inherits i
JOIN pg_catalog.pg_class c ON c.oid = i.inhrelid
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schema::name
) SELECT n.nspname||'.'||c.relname
INTO v_top_parent_table
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
JOIN top_oid t ON c.oid = t.top_parent_oid
JOIN @extschema@.part_config p ON p.parent_table = n.nspname||'.'||c.relname;
IF v_top_parent_table IS NOT NULL THEN
-- Create the lowest possible partition that is within the boundary of the parent
SELECT child_start_id INTO v_parent_partition_id FROM @extschema@.show_partition_info(p_parent_table, p_parent_table := v_top_parent_table);
IF v_starting_partition_id >= v_parent_partition_id THEN
WHILE v_starting_partition_id >= v_parent_partition_id LOOP
v_starting_partition_id := v_starting_partition_id - v_id_interval;
END LOOP;
v_starting_partition_id := v_starting_partition_id + v_id_interval; -- add one back since while loop set it one lower than is needed
ELSIF v_starting_partition_id < v_parent_partition_id THEN
WHILE v_starting_partition_id < v_parent_partition_id LOOP
v_starting_partition_id := v_starting_partition_id + v_id_interval;
END LOOP;
-- Don't need to remove one since new starting id will fit in top parent interval
END IF;
v_partition_id_array = NULL;
v_partition_id_array = array_append(v_partition_id_array, v_starting_partition_id);
v_last_partition_created := @extschema@.create_partition_id(p_parent_table, v_partition_id_array, false);
ELSE
-- Currently unknown edge case if code gets here
RAISE WARNING 'No child tables created. Check that all child tables did not already exist and may not have been part of partition set. Given parent has still been configured with pg_partman, but may not have expected children. Please review schema and config to confirm things are ok.';
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
IF v_step_overflow_id IS NOT NULL THEN
PERFORM fail_job(v_job_id);
ELSE
PERFORM close_job(v_job_id);
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RETURN v_success;
END IF;
END IF; -- End v_last_partition_created IF
END IF; -- End IF id
IF p_type = 'native' AND current_setting('server_version_num')::int >= 110000 THEN
-- Add default partition to native sets in PG11+
v_default_partition := @extschema@.check_name_length(v_parent_tablename, '_default', FALSE);
v_sql := 'CREATE';
IF v_unlogged = 'u' THEN
v_sql := v_sql ||' UNLOGGED';
END IF;
-- Same INCLUDING list is used in create_partition_*()
v_sql := v_sql || format(' TABLE %I.%I (LIKE %I.%I INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING STORAGE INCLUDING COMMENTS)'
, v_parent_schema, v_default_partition, v_parent_schema, v_parent_tablename);
EXECUTE v_sql;
v_sql := format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I DEFAULT'
, v_parent_schema, v_parent_tablename, v_parent_schema, v_default_partition);
EXECUTE v_sql;
IF v_parent_tablespace IS NOT NULL THEN
EXECUTE format('ALTER TABLE %I.%I SET TABLESPACE %I', v_parent_schema, v_default_partition, v_parent_tablespace);
END IF;
END IF;
IF p_type <> 'native' THEN
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Creating partition function');
END IF;
IF v_control_type = 'time' OR (v_control_type = 'id' AND p_epoch <> 'none') THEN
PERFORM @extschema@.create_function_time(p_parent_table, v_job_id);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Time function created');
END IF;
ELSIF v_control_type = 'id' THEN
PERFORM @extschema@.create_function_id(p_parent_table, v_job_id);
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'ID function created');
END IF;
END IF;
IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Creating partition trigger');
END IF;
PERFORM @extschema@.create_trigger(p_parent_table);
END IF; -- end native check
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
IF v_step_overflow_id IS NOT NULL THEN
PERFORM fail_job(v_job_id);
ELSE
PERFORM close_job(v_job_id);
END IF;
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
v_success := true;
RETURN v_success;
EXCEPTION
WHEN OTHERS THEN
GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT,
ex_context = PG_EXCEPTION_CONTEXT,
ex_detail = PG_EXCEPTION_DETAIL,
ex_hint = PG_EXCEPTION_HINT;
IF v_jobmon_schema IS NOT NULL THEN
IF v_job_id IS NULL THEN
EXECUTE format('SELECT %I.add_job(''PARTMAN CREATE PARENT: %s'')', v_jobmon_schema, p_parent_table) INTO v_job_id;
EXECUTE format('SELECT %I.add_step(%s, ''Partition creation for table '||p_parent_table||' failed'')', v_jobmon_schema, v_job_id, p_parent_table) INTO v_step_id;
ELSIF v_step_id IS NULL THEN
EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before first step logged'')', v_jobmon_schema, v_job_id) INTO v_step_id;
END IF;
EXECUTE format('SELECT %I.update_step(%s, ''CRITICAL'', %L)', v_jobmon_schema, v_step_id, 'ERROR: '||coalesce(SQLERRM,'unknown'));
EXECUTE format('SELECT %I.fail_job(%s)', v_jobmon_schema, v_job_id);
END IF;
RAISE EXCEPTION '%
CONTEXT: %
DETAIL: %
HINT: %', ex_message, ex_context, ex_detail, ex_hint;
END
$$;
CREATE OR REPLACE FUNCTION @extschema@.partition_data_id(p_parent_table text
, p_batch_count int DEFAULT 1
, p_batch_interval bigint DEFAULT NULL
, p_lock_wait numeric DEFAULT 0
, p_order text DEFAULT 'ASC'
, p_analyze boolean DEFAULT true
, p_source_table text DEFAULT NULL)
RETURNS bigint
LANGUAGE plpgsql
AS $$
DECLARE
v_control text;
v_control_type text;
v_current_partition_name text;
v_default_exists boolean;
v_default_schemaname text;
v_default_tablename text;
v_epoch text;
v_lock_iter int := 1;
v_lock_obtained boolean := FALSE;
v_max_partition_id bigint;
v_min_partition_id bigint;
v_new_search_path text := '@extschema@,pg_temp';
v_old_search_path text;
v_parent_tablename text;
v_partition_interval bigint;
v_partition_id bigint[];
v_partition_type text;
v_rowcount bigint;
v_source_schemaname text;
v_source_tablename text;
v_sql text;
v_start_control bigint;
v_total_rows bigint := 0;
BEGIN
/*
* Populate the child table(s) of an id-based partition set with old data from the original parent
*/
SELECT partition_interval::bigint
, partition_type
, control
, epoch
INTO v_partition_interval
, v_partition_type
, v_control
, v_epoch
FROM @extschema@.part_config
WHERE parent_table = p_parent_table;
IF NOT FOUND THEN
RAISE EXCEPTION 'ERROR: No entry in part_config found for given table: %', p_parent_table;
END IF;
SELECT schemaname, tablename INTO v_source_schemaname, v_source_tablename
FROM pg_catalog.pg_tables
WHERE schemaname = split_part(p_parent_table, '.', 1)::name
AND tablename = split_part(p_parent_table, '.', 2)::name;
-- Preserve real parent tablename for use below
v_parent_tablename := v_source_tablename;
SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_source_schemaname, v_source_tablename, v_control);
IF v_control_type <> 'id' OR (v_control_type = 'id' AND v_epoch <> 'none') THEN
RAISE EXCEPTION 'Control column for given partition set is not id/serial based or epoch flag is set for time-based partitioning.';
END IF;
IF p_source_table IS NOT NULL THEN
-- Set source table to user given source table instead of parent table
v_source_schemaname := NULL;
v_source_tablename := NULL;
SELECT schemaname, tablename INTO v_source_schemaname, v_source_tablename
FROM pg_catalog.pg_tables
WHERE schemaname = split_part(p_source_table, '.', 1)::name
AND tablename = split_part(p_source_table, '.', 2)::name;
IF v_source_tablename IS NULL THEN
RAISE EXCEPTION 'Given source table does not exist in system catalogs: %', p_source_table;
END IF;
ELSIF v_partition_type = 'native' AND current_setting('server_version_num')::int >= 110000 THEN
IF p_batch_interval IS NOT NULL AND p_batch_interval != v_partition_interval THEN
-- This is true because all data for a given child table must be moved out of the default partition before the child table can be created.
-- So cannot create the child table when only some of the data has been moved out of the default partition.
RAISE EXCEPTION 'Custom intervals are not allowed when moving data out of the DEFAULT partition in a native set. Please leave p_interval/p_batch_interval parameters unset or NULL to allow use of partition set''s default partitioning interval.';
END IF;
-- Set source table to default table if PG11+, p_source_table is not set, and it exists
-- Otherwise just return with a DEBUG that no data source exists
v_sql := format('SELECT n.nspname::text, c.relname::text FROM
pg_catalog.pg_inherits h
JOIN pg_catalog.pg_class c ON c.oid = h.inhrelid
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE h.inhparent = ''%I.%I''::regclass
AND pg_get_expr(relpartbound, c.oid) = ''DEFAULT'''
, v_source_schemaname
, v_source_tablename);
EXECUTE v_sql INTO v_default_schemaname, v_default_tablename;
IF v_default_tablename IS NOT NULL THEN
v_source_schemaname := v_default_schemaname;
v_source_tablename := v_default_tablename;
v_default_exists := true;
EXECUTE format ('CREATE TEMP TABLE IF NOT EXISTS partman_temp_data_storage (LIKE %I.%I INCLUDING INDEXES)', v_source_schemaname, v_source_tablename);
ELSE
RAISE DEBUG 'No default table found when partition_data_id() was called';
RETURN v_total_rows;
END IF;
END IF;
SELECT current_setting('search_path') INTO v_old_search_path;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false');
IF p_batch_interval IS NULL OR p_batch_interval > v_partition_interval THEN
p_batch_interval := v_partition_interval;
END IF;
FOR i IN 1..p_batch_count LOOP
IF p_order = 'ASC' THEN
EXECUTE format('SELECT min(%I) FROM ONLY %I.%I', v_control, v_source_schemaname, v_source_tablename) INTO v_start_control;
IF v_start_control IS NULL THEN
EXIT;
END IF;
v_min_partition_id = v_start_control - (v_start_control % v_partition_interval);
v_partition_id := ARRAY[v_min_partition_id];
-- Check if custom batch interval overflows current partition maximum
IF (v_start_control + p_batch_interval) >= (v_min_partition_id + v_partition_interval) THEN
v_max_partition_id := v_min_partition_id + v_partition_interval;
ELSE
v_max_partition_id := v_start_control + p_batch_interval;
END IF;
ELSIF p_order = 'DESC' THEN
EXECUTE format('SELECT max(%I) FROM ONLY %I.%I', v_control, v_source_schemaname, v_source_tablename) INTO v_start_control;
IF v_start_control IS NULL THEN
EXIT;
END IF;
v_min_partition_id = v_start_control - (v_start_control % v_partition_interval);
-- Must be greater than max value still in parent table since query below grabs < max
v_max_partition_id := v_min_partition_id + v_partition_interval;
v_partition_id := ARRAY[v_min_partition_id];
-- Make sure minimum doesn't underflow current partition minimum
IF (v_start_control - p_batch_interval) >= v_min_partition_id THEN
v_min_partition_id = v_start_control - p_batch_interval;
END IF;
ELSE
RAISE EXCEPTION 'Invalid value for p_order. Must be ASC or DESC';
END IF;
-- do some locking with timeout, if required
IF p_lock_wait > 0 THEN
v_lock_iter := 0;
WHILE v_lock_iter <= 5 LOOP
v_lock_iter := v_lock_iter + 1;
BEGIN
v_sql := format('SELECT * FROM ONLY %I.%I WHERE %I >= %s AND %I < %s FOR UPDATE NOWAIT'
, v_source_schemaname
, v_source_tablename
, v_control
, v_min_partition_id
, v_control
, v_max_partition_id);
EXECUTE v_sql;
v_lock_obtained := TRUE;
EXCEPTION
WHEN lock_not_available THEN
PERFORM pg_sleep( p_lock_wait / 5.0 );
CONTINUE;
END;
EXIT WHEN v_lock_obtained;
END LOOP;
IF NOT v_lock_obtained THEN
RETURN -1;
END IF;
END IF;
v_current_partition_name := @extschema@.check_name_length(COALESCE(v_parent_tablename), v_min_partition_id::text, TRUE);
IF v_default_exists THEN
-- Child tables cannot be created in native partitioning if data that belongs to it exists in the default
-- Have to move data out to temporary location, create child table, then move it back
-- Temp table created above to avoid excessive temp creation in loop
EXECUTE format('WITH partition_data AS (
DELETE FROM %1$I.%2$I WHERE %3$I >= %4$s AND %3$I < %5$s RETURNING *)
INSERT INTO partman_temp_data_storage SELECT * FROM partition_data'
, v_source_schemaname
, v_source_tablename
, v_control
, v_min_partition_id
, v_max_partition_id);
PERFORM @extschema@.create_partition_id(p_parent_table, v_partition_id, p_analyze);
EXECUTE format('WITH partition_data AS (
DELETE FROM partman_temp_data_storage RETURNING *)
INSERT INTO %I.%I SELECT * FROM partition_data'
, v_source_schemaname
, v_current_partition_name);
ELSE
PERFORM @extschema@.create_partition_id(p_parent_table, v_partition_id, p_analyze);
EXECUTE format('WITH partition_data AS (
DELETE FROM ONLY %1$I.%2$I WHERE %3$I >= %4$s AND %3$I < %5$s RETURNING *)
INSERT INTO %1$I.%6$I SELECT * FROM partition_data'
, v_source_schemaname
, v_source_tablename
, v_control
, v_min_partition_id
, v_max_partition_id
, v_current_partition_name);
END IF;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
v_total_rows := v_total_rows + v_rowcount;
IF v_rowcount = 0 THEN
EXIT;
END IF;
END LOOP;
IF v_partition_type = 'partman' THEN
PERFORM @extschema@.create_function_id(p_parent_table);
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RETURN v_total_rows;
END
$$;
CREATE OR REPLACE FUNCTION @extschema@.partition_data_time(
p_parent_table text
, p_batch_count int DEFAULT 1
, p_batch_interval interval DEFAULT NULL
, p_lock_wait numeric DEFAULT 0
, p_order text DEFAULT 'ASC'
, p_analyze boolean DEFAULT true
, p_source_table text DEFAULT NULL)
RETURNS bigint
LANGUAGE plpgsql
AS $$
DECLARE
v_control text;
v_control_type text;
v_datetime_string text;
v_current_partition_name text;
v_default_exists boolean;
v_default_schemaname text;
v_default_tablename text;
v_epoch text;
v_last_partition text;
v_lock_iter int := 1;
v_lock_obtained boolean := FALSE;
v_max_partition_timestamp timestamptz;
v_min_partition_timestamp timestamptz;
v_new_search_path text := '@extschema@,pg_temp';
v_old_search_path text;
v_parent_tablename text;
v_parent_tablename_real text;
v_partition_expression text;
v_partition_interval interval;
v_partition_suffix text;
v_partition_timestamp timestamptz[];
v_partition_type text;
v_source_schemaname text;
v_source_tablename text;
v_rowcount bigint;
v_sql text;
v_start_control timestamptz;
v_total_rows bigint := 0;
BEGIN
/*
* Populate the child table(s) of a time-based partition set with old data from the original parent
*/
SELECT partition_type
, partition_interval::interval
, control
, datetime_string
, epoch
INTO v_partition_type
, v_partition_interval
, v_control
, v_datetime_string
, v_epoch
FROM @extschema@.part_config
WHERE parent_table = p_parent_table;
IF NOT FOUND THEN
RAISE EXCEPTION 'ERROR: No entry in part_config found for given table: %', p_parent_table;
END IF;
SELECT schemaname, tablename INTO v_source_schemaname, v_source_tablename
FROM pg_catalog.pg_tables
WHERE schemaname = split_part(p_parent_table, '.', 1)::name
AND tablename = split_part(p_parent_table, '.', 2)::name;
-- Preserve real parent tablename for use below
v_parent_tablename := v_source_tablename;
SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_source_schemaname, v_source_tablename, v_control);
IF v_control_type <> 'time' THEN
IF (v_control_type = 'id' AND v_epoch = 'none') OR v_control_type <> 'id' THEN
RAISE EXCEPTION 'Cannot run on partition set without time based control column or epoch flag set with an id column. Found control: %, epoch: %', v_control_type, v_epoch;
END IF;
END IF;
-- Replace the parent variables with the source variables if using source table for child table data
IF p_source_table IS NOT NULL THEN
-- Set source table to user given source table instead of parent table
v_source_schemaname := NULL;
v_source_tablename := NULL;
SELECT schemaname, tablename INTO v_source_schemaname, v_source_tablename
FROM pg_catalog.pg_tables
WHERE schemaname = split_part(p_source_table, '.', 1)::name
AND tablename = split_part(p_source_table, '.', 2)::name;
IF v_source_tablename IS NULL THEN
RAISE EXCEPTION 'Given source table does not exist in system catalogs: %', p_source_table;
END IF;
ELSIF v_partition_type = 'native' AND current_setting('server_version_num')::int >= 110000 THEN
IF p_batch_interval IS NOT NULL AND p_batch_interval != v_partition_interval THEN
-- This is true because all data for a given child table must be moved out of the default partition before the child table can be created.
-- So cannot create the child table when only some of the data has been moved out of the default partition.
RAISE EXCEPTION 'Custom intervals are not allowed when moving data out of the DEFAULT partition in a native set. Please leave p_interval/p_batch_interval parameters unset or NULL to allow use of partition set''s default partitioning interval.';
END IF;
-- Set source table to default table if PG11+, p_source_table is not set, and it exists
-- Otherwise just return with a DEBUG that no data source exists
v_sql := format('SELECT n.nspname::text, c.relname::text FROM
pg_catalog.pg_inherits h
JOIN pg_catalog.pg_class c ON c.oid = h.inhrelid
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE h.inhparent = ''%I.%I''::regclass
AND pg_get_expr(relpartbound, c.oid) = ''DEFAULT'''
, v_source_schemaname
, v_source_tablename);
EXECUTE v_sql INTO v_default_schemaname, v_default_tablename;
IF v_default_tablename IS NOT NULL THEN
v_source_schemaname := v_default_schemaname;
v_source_tablename := v_default_tablename;
v_default_exists := true;
EXECUTE format ('CREATE TEMP TABLE IF NOT EXISTS partman_temp_data_storage (LIKE %I.%I INCLUDING INDEXES)', v_source_schemaname, v_source_tablename);
ELSE
RAISE DEBUG 'No default table found when partition_data_id() was called';
RETURN v_total_rows;
END IF;
END IF;
SELECT current_setting('search_path') INTO v_old_search_path;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false');
IF p_batch_interval IS NULL OR p_batch_interval > v_partition_interval THEN
p_batch_interval := v_partition_interval;
END IF;
SELECT partition_tablename INTO v_last_partition FROM @extschema@.show_partitions(p_parent_table, 'DESC') LIMIT 1;
v_partition_expression := CASE
WHEN v_epoch = 'seconds' THEN format('to_timestamp(%I)', v_control)
WHEN v_epoch = 'milliseconds' THEN format('to_timestamp((%I/1000)::float)', v_control)
ELSE format('%I', v_control)
END;
FOR i IN 1..p_batch_count LOOP
IF p_order = 'ASC' THEN
EXECUTE format('SELECT min(%s) FROM ONLY %I.%I', v_partition_expression, v_source_schemaname, v_source_tablename) INTO v_start_control;
ELSIF p_order = 'DESC' THEN
EXECUTE format('SELECT max(%s) FROM ONLY %I.%I', v_partition_expression, v_source_schemaname, v_source_tablename) INTO v_start_control;
ELSE
RAISE EXCEPTION 'Invalid value for p_order. Must be ASC or DESC';
END IF;
IF v_start_control IS NULL THEN
EXIT;
END IF;
IF v_partition_type = 'partman' THEN
CASE
WHEN v_partition_interval = '15 mins' THEN
v_min_partition_timestamp := date_trunc('hour', v_start_control) +
'15min'::interval * floor(date_part('minute', v_start_control) / 15.0);
WHEN v_partition_interval = '30 mins' THEN
v_min_partition_timestamp := date_trunc('hour', v_start_control) +
'30min'::interval * floor(date_part('minute', v_start_control) / 30.0);
WHEN v_partition_interval = '1 hour' THEN
v_min_partition_timestamp := date_trunc('hour', v_start_control);
WHEN v_partition_interval = '1 day' THEN
v_min_partition_timestamp := date_trunc('day', v_start_control);
WHEN v_partition_interval = '1 week' THEN
v_min_partition_timestamp := date_trunc('week', v_start_control);
WHEN v_partition_interval = '1 month' THEN
v_min_partition_timestamp := date_trunc('month', v_start_control);
WHEN v_partition_interval = '3 months' THEN
v_min_partition_timestamp := date_trunc('quarter', v_start_control);
WHEN v_partition_interval = '1 year' THEN
v_min_partition_timestamp := date_trunc('year', v_start_control);
END CASE;
ELSIF v_partition_type IN ('time-custom', 'native') THEN
SELECT child_start_time INTO v_min_partition_timestamp FROM @extschema@.show_partition_info(v_source_schemaname||'.'||v_last_partition
, v_partition_interval::text
, p_parent_table);
v_max_partition_timestamp := v_min_partition_timestamp + v_partition_interval;
LOOP
IF v_start_control >= v_min_partition_timestamp AND v_start_control < v_max_partition_timestamp THEN
EXIT;
ELSE
BEGIN
IF v_start_control > v_max_partition_timestamp THEN
-- Keep going forward in time, checking if child partition time interval encompasses the current v_start_control value
v_min_partition_timestamp := v_max_partition_timestamp;
v_max_partition_timestamp := v_max_partition_timestamp + v_partition_interval;
ELSE
-- Keep going backwards in time, checking if child partition time interval encompasses the current v_start_control value
v_max_partition_timestamp := v_min_partition_timestamp;
v_min_partition_timestamp := v_min_partition_timestamp - v_partition_interval;
END IF;
EXCEPTION WHEN datetime_field_overflow THEN
RAISE EXCEPTION 'Attempted partition time interval is outside PostgreSQL''s supported time range.
Unable to create partition with interval before timestamp % ', v_min_partition_timestamp;
END;
END IF;
END LOOP;
END IF;
v_partition_timestamp := ARRAY[v_min_partition_timestamp];
IF p_order = 'ASC' THEN
-- Ensure batch interval given as parameter doesn't cause maximum to overflow the current partition maximum
IF (v_start_control + p_batch_interval) >= (v_min_partition_timestamp + v_partition_interval) THEN
v_max_partition_timestamp := v_min_partition_timestamp + v_partition_interval;
ELSE
v_max_partition_timestamp := v_start_control + p_batch_interval;
END IF;
ELSIF p_order = 'DESC' THEN
-- Must be greater than max value still in parent table since query below grabs < max
v_max_partition_timestamp := v_min_partition_timestamp + v_partition_interval;
-- Ensure batch interval given as parameter doesn't cause minimum to underflow current partition minimum
IF (v_start_control - p_batch_interval) >= v_min_partition_timestamp THEN
v_min_partition_timestamp = v_start_control - p_batch_interval;
END IF;
ELSE
RAISE EXCEPTION 'Invalid value for p_order. Must be ASC or DESC';
END IF;
-- do some locking with timeout, if required
IF p_lock_wait > 0 THEN
v_lock_iter := 0;
WHILE v_lock_iter <= 5 LOOP
v_lock_iter := v_lock_iter + 1;
BEGIN
EXECUTE format('SELECT * FROM ONLY %I.%I WHERE %s >= %L AND %3$s < %5$L FOR UPDATE NOWAIT'
, v_source_schemaname
, v_source_tablename
, v_partition_expression
, v_min_partition_timestamp
, v_max_partition_timestamp);
v_lock_obtained := TRUE;
EXCEPTION
WHEN lock_not_available THEN
PERFORM pg_sleep( p_lock_wait / 5.0 );
CONTINUE;
END;
EXIT WHEN v_lock_obtained;
END LOOP;
IF NOT v_lock_obtained THEN
RETURN -1;
END IF;
END IF;
-- This suffix generation code is in create_partition_time() as well
v_partition_suffix := to_char(v_min_partition_timestamp, v_datetime_string);
v_current_partition_name := @extschema@.check_name_length(v_parent_tablename, v_partition_suffix, TRUE);
IF v_default_exists THEN
-- Child tables cannot be created in native partitioning if data that belongs to it exists in the default
-- Have to move data out to temporary location, create child table, then move it back
-- Temp table created above to avoid excessive temp creation in loop
EXECUTE format('WITH partition_data AS (
DELETE FROM %1$I.%2$I WHERE %3$I >= %4$L AND %3$I < %5$L RETURNING *)
INSERT INTO partman_temp_data_storage SELECT * FROM partition_data'
, v_source_schemaname
, v_source_tablename
, v_control
, v_min_partition_timestamp
, v_max_partition_timestamp);
PERFORM @extschema@.create_partition_time(p_parent_table, v_partition_timestamp, p_analyze);
EXECUTE format('WITH partition_data AS (
DELETE FROM partman_temp_data_storage RETURNING *)
INSERT INTO %I.%I SELECT * FROM partition_data'
, v_source_schemaname
, v_current_partition_name);
ELSE
PERFORM @extschema@.create_partition_time(p_parent_table, v_partition_timestamp, p_analyze);
EXECUTE format('WITH partition_data AS (
DELETE FROM ONLY %I.%I WHERE %s >= %L AND %3$s < %5$L RETURNING *)
INSERT INTO %I.%I SELECT * FROM partition_data'
, v_source_schemaname
, v_source_tablename
, v_partition_expression
, v_min_partition_timestamp
, v_max_partition_timestamp
, v_source_schemaname
, v_current_partition_name);
END IF;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
v_total_rows := v_total_rows + v_rowcount;
IF v_rowcount = 0 THEN
EXIT;
END IF;
END LOOP;
IF v_partition_type IN ('partman', 'time-custom') THEN
PERFORM @extschema@.create_function_time(p_parent_table);
END IF;
EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false');
RETURN v_total_rows;
END
$$;
|