/usr/share/postgresql/9.4/contrib/pgq.sql is in postgresql-9.4-pgq3 3.2-2.
This file is owned by root:root, with mode 0o644.
The actual contents of the file can be viewed below.
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 | -- ----------------------------------------------------------------------
-- Section: Internal Tables
--
-- Overview:
-- pgq.queue - Queue configuration
-- pgq.consumer - Consumer names
-- pgq.subscription - Consumer registrations
-- pgq.tick - Per-queue snapshots (ticks)
-- pgq.event_* - Data tables
-- pgq.retry_queue - Events to be retried later
--
--
-- Standard triggers store events in the pgq.event_* data tables
-- There is one top event table pgq.event_<queue_id> for each queue
-- inherited from pgq.event_template wuith three tables for actual data
-- pgq.event_<queue_id>_0 to pgq.event_<queue_id>_2.
--
-- The active table is rotated at interval, so that if all the consubers
-- have passed some poin the oldes one can be emptied using TRUNCATE command
-- for efficiency
--
--
-- ----------------------------------------------------------------------
set client_min_messages = 'warning';
set default_with_oids = 'off';
-- drop schema if exists pgq cascade;
create schema pgq;
-- ----------------------------------------------------------------------
-- Table: pgq.consumer
--
-- Name to id lookup for consumers
--
-- Columns:
-- co_id - consumer's id for internal usage
-- co_name - consumer's id for external usage
-- ----------------------------------------------------------------------
create table pgq.consumer (
co_id serial,
co_name text not null,
constraint consumer_pkey primary key (co_id),
constraint consumer_name_uq UNIQUE (co_name)
);
-- ----------------------------------------------------------------------
-- Table: pgq.queue
--
-- Information about available queues
--
-- Columns:
-- queue_id - queue id for internal usage
-- queue_name - queue name visible outside
-- queue_ntables - how many data tables the queue has
-- queue_cur_table - which data table is currently active
-- queue_rotation_period - period for data table rotation
-- queue_switch_step1 - tx when rotation happened
-- queue_switch_step2 - tx after rotation was committed
-- queue_switch_time - time when switch happened
-- queue_external_ticker - ticks come from some external sources
-- queue_ticker_paused - ticker is paused
-- queue_disable_insert - disallow pgq.insert_event()
-- queue_ticker_max_count - batch should not contain more events
-- queue_ticker_max_lag - events should not age more
-- queue_ticker_idle_period - how often to tick when no events happen
-- queue_per_tx_limit - Max number of events single TX can insert
-- queue_data_pfx - prefix for data table names
-- queue_event_seq - sequence for event id's
-- queue_tick_seq - sequence for tick id's
-- ----------------------------------------------------------------------
create table pgq.queue (
queue_id serial,
queue_name text not null,
queue_ntables integer not null default 3,
queue_cur_table integer not null default 0,
queue_rotation_period interval not null default '2 hours',
queue_switch_step1 bigint not null default txid_current(),
queue_switch_step2 bigint default txid_current(),
queue_switch_time timestamptz not null default now(),
queue_external_ticker boolean not null default false,
queue_disable_insert boolean not null default false,
queue_ticker_paused boolean not null default false,
queue_ticker_max_count integer not null default 500,
queue_ticker_max_lag interval not null default '3 seconds',
queue_ticker_idle_period interval not null default '1 minute',
queue_per_tx_limit integer,
queue_data_pfx text not null,
queue_event_seq text not null,
queue_tick_seq text not null,
constraint queue_pkey primary key (queue_id),
constraint queue_name_uq unique (queue_name)
);
-- ----------------------------------------------------------------------
-- Table: pgq.tick
--
-- Snapshots for event batching
--
-- Columns:
-- tick_queue - queue id whose tick it is
-- tick_id - ticks id (per-queue)
-- tick_time - time when tick happened
-- tick_snapshot - transaction state
-- tick_event_seq - last value for event seq
-- ----------------------------------------------------------------------
create table pgq.tick (
tick_queue int4 not null,
tick_id bigint not null,
tick_time timestamptz not null default now(),
tick_snapshot txid_snapshot not null default txid_current_snapshot(),
tick_event_seq bigint not null, -- may be NULL on upgraded dbs
constraint tick_pkey primary key (tick_queue, tick_id),
constraint tick_queue_fkey foreign key (tick_queue)
references pgq.queue (queue_id)
);
-- ----------------------------------------------------------------------
-- Sequence: pgq.batch_id_seq
--
-- Sequence for batch id's.
-- ----------------------------------------------------------------------
create sequence pgq.batch_id_seq;
-- ----------------------------------------------------------------------
-- Table: pgq.subscription
--
-- Consumer registration on a queue.
--
-- Columns:
--
-- sub_id - subscription id for internal usage
-- sub_queue - queue id
-- sub_consumer - consumer's id
-- sub_last_tick - last tick the consumer processed
-- sub_batch - shortcut for queue_id/consumer_id/tick_id
-- sub_next_tick - batch end pos
-- ----------------------------------------------------------------------
create table pgq.subscription (
sub_id serial not null,
sub_queue int4 not null,
sub_consumer int4 not null,
sub_last_tick bigint,
sub_active timestamptz not null default now(),
sub_batch bigint,
sub_next_tick bigint,
constraint subscription_pkey primary key (sub_queue, sub_consumer),
constraint subscription_batch_idx unique (sub_batch),
constraint sub_queue_fkey foreign key (sub_queue)
references pgq.queue (queue_id),
constraint sub_consumer_fkey foreign key (sub_consumer)
references pgq.consumer (co_id)
);
-- ----------------------------------------------------------------------
-- Table: pgq.event_template
--
-- Parent table for all event tables
--
-- Columns:
-- ev_id - event's id, supposed to be unique per queue
-- ev_time - when the event was inserted
-- ev_txid - transaction id which inserted the event
-- ev_owner - subscription id that wanted to retry this
-- ev_retry - how many times the event has been retried, NULL for new events
-- ev_type - consumer/producer can specify what the data fields contain
-- ev_data - data field
-- ev_extra1 - extra data field
-- ev_extra2 - extra data field
-- ev_extra3 - extra data field
-- ev_extra4 - extra data field
-- ----------------------------------------------------------------------
create table pgq.event_template (
ev_id bigint not null,
ev_time timestamptz not null,
ev_txid bigint not null default txid_current(),
ev_owner int4,
ev_retry int4,
ev_type text,
ev_data text,
ev_extra1 text,
ev_extra2 text,
ev_extra3 text,
ev_extra4 text
);
-- ----------------------------------------------------------------------
-- Table: pgq.retry_queue
--
-- Events to be retried. When retry time reaches, they will
-- be put back into main queue.
--
-- Columns:
-- ev_retry_after - time when it should be re-inserted to main queue
-- ev_queue - queue id, used to speed up event copy into queue
-- * - same as pgq.event_template
-- ----------------------------------------------------------------------
create table pgq.retry_queue (
ev_retry_after timestamptz not null,
ev_queue int4 not null,
like pgq.event_template,
constraint rq_pkey primary key (ev_owner, ev_id),
constraint rq_queue_id_fkey foreign key (ev_queue)
references pgq.queue (queue_id)
);
alter table pgq.retry_queue alter column ev_owner set not null;
alter table pgq.retry_queue alter column ev_txid drop not null;
create index rq_retry_idx on pgq.retry_queue (ev_retry_after);
-- Section: Internal Functions
-- install & launch schema upgrade
create or replace function pgq.upgrade_schema()
returns int4 as $$
-- updates table structure if necessary
declare
cnt int4 = 0;
begin
-- pgq.subscription.sub_last_tick: NOT NULL -> NULL
perform 1 from information_schema.columns
where table_schema = 'pgq'
and table_name = 'subscription'
and column_name ='sub_last_tick'
and is_nullable = 'NO';
if found then
alter table pgq.subscription
alter column sub_last_tick
drop not null;
cnt := cnt + 1;
end if;
-- create roles
perform 1 from pg_catalog.pg_roles where rolname = 'pgq_reader';
if not found then
create role pgq_reader;
cnt := cnt + 1;
end if;
perform 1 from pg_catalog.pg_roles where rolname = 'pgq_writer';
if not found then
create role pgq_writer;
cnt := cnt + 1;
end if;
perform 1 from pg_catalog.pg_roles where rolname = 'pgq_admin';
if not found then
create role pgq_admin in role pgq_reader, pgq_writer;
cnt := cnt + 1;
end if;
return cnt;
end;
$$ language plpgsql;
select pgq.upgrade_schema();
-- Group: Low-level event handling
create or replace function pgq.batch_event_sql(x_batch_id bigint)
returns text as $$
-- ----------------------------------------------------------------------
-- Function: pgq.batch_event_sql(1)
-- Creates SELECT statement that fetches events for this batch.
--
-- Parameters:
-- x_batch_id - ID of a active batch.
--
-- Returns:
-- SQL statement.
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- Algorithm description:
-- Given 2 snapshots, sn1 and sn2 with sn1 having xmin1, xmax1
-- and sn2 having xmin2, xmax2 create expression that filters
-- right txid's from event table.
--
-- Simplest solution would be
-- > WHERE ev_txid >= xmin1 AND ev_txid <= xmax2
-- > AND NOT txid_visible_in_snapshot(ev_txid, sn1)
-- > AND txid_visible_in_snapshot(ev_txid, sn2)
--
-- The simple solution has a problem with long transactions (xmin1 very low).
-- All the batches that happen when the long tx is active will need
-- to scan all events in that range. Here is 2 optimizations used:
--
-- 1) Use [xmax1..xmax2] for range scan. That limits the range to
-- txids that actually happened between two snapshots. For txids
-- in the range [xmin1..xmax1] look which ones were actually
-- committed between snapshots and search for them using exact
-- values using IN (..) list.
--
-- 2) As most TX are short, there could be lot of them that were
-- just below xmax1, but were committed before xmax2. So look
-- if there are ID's near xmax1 and lower the range to include
-- them, thus decresing size of IN (..) list.
-- ----------------------------------------------------------------------
declare
rec record;
sql text;
tbl text;
arr text;
part text;
select_fields text;
retry_expr text;
batch record;
begin
select s.sub_last_tick, s.sub_next_tick, s.sub_id, s.sub_queue,
txid_snapshot_xmax(last.tick_snapshot) as tx_start,
txid_snapshot_xmax(cur.tick_snapshot) as tx_end,
last.tick_snapshot as last_snapshot,
cur.tick_snapshot as cur_snapshot
into batch
from pgq.subscription s, pgq.tick last, pgq.tick cur
where s.sub_batch = x_batch_id
and last.tick_queue = s.sub_queue
and last.tick_id = s.sub_last_tick
and cur.tick_queue = s.sub_queue
and cur.tick_id = s.sub_next_tick;
if not found then
raise exception 'batch not found';
end if;
-- load older transactions
arr := '';
for rec in
-- active tx-es in prev_snapshot that were committed in cur_snapshot
select id1 from
txid_snapshot_xip(batch.last_snapshot) id1 left join
txid_snapshot_xip(batch.cur_snapshot) id2 on (id1 = id2)
where id2 is null
order by 1 desc
loop
-- try to avoid big IN expression, so try to include nearby
-- tx'es into range
if batch.tx_start - 100 <= rec.id1 then
batch.tx_start := rec.id1;
else
if arr = '' then
arr := rec.id1::text;
else
arr := arr || ',' || rec.id1::text;
end if;
end if;
end loop;
-- must match pgq.event_template
select_fields := 'select ev_id, ev_time, ev_txid, ev_retry, ev_type,'
|| ' ev_data, ev_extra1, ev_extra2, ev_extra3, ev_extra4';
retry_expr := ' and (ev_owner is null or ev_owner = '
|| batch.sub_id::text || ')';
-- now generate query that goes over all potential tables
sql := '';
for rec in
select xtbl from pgq.batch_event_tables(x_batch_id) xtbl
loop
tbl := pgq.quote_fqname(rec.xtbl);
-- this gets newer queries that definitely are not in prev_snapshot
part := select_fields
|| ' from pgq.tick cur, pgq.tick last, ' || tbl || ' ev '
|| ' where cur.tick_id = ' || batch.sub_next_tick::text
|| ' and cur.tick_queue = ' || batch.sub_queue::text
|| ' and last.tick_id = ' || batch.sub_last_tick::text
|| ' and last.tick_queue = ' || batch.sub_queue::text
|| ' and ev.ev_txid >= ' || batch.tx_start::text
|| ' and ev.ev_txid <= ' || batch.tx_end::text
|| ' and txid_visible_in_snapshot(ev.ev_txid, cur.tick_snapshot)'
|| ' and not txid_visible_in_snapshot(ev.ev_txid, last.tick_snapshot)'
|| retry_expr;
-- now include older tx-es, that were ongoing
-- at the time of prev_snapshot
if arr <> '' then
part := part || ' union all '
|| select_fields || ' from ' || tbl || ' ev '
|| ' where ev.ev_txid in (' || arr || ')'
|| retry_expr;
end if;
if sql = '' then
sql := part;
else
sql := sql || ' union all ' || part;
end if;
end loop;
if sql = '' then
raise exception 'could not construct sql for batch %', x_batch_id;
end if;
return sql || ' order by 1';
end;
$$ language plpgsql; -- no perms needed
create or replace function pgq.batch_event_tables(x_batch_id bigint)
returns setof text as $$
-- ----------------------------------------------------------------------
-- Function: pgq.batch_event_tables(1)
--
-- Returns set of table names where this batch events may reside.
--
-- Parameters:
-- x_batch_id - ID of a active batch.
-- ----------------------------------------------------------------------
declare
nr integer;
tbl text;
use_prev integer;
use_next integer;
batch record;
begin
select
txid_snapshot_xmin(last.tick_snapshot) as tx_min, -- absolute minimum
txid_snapshot_xmax(cur.tick_snapshot) as tx_max, -- absolute maximum
q.queue_data_pfx, q.queue_ntables,
q.queue_cur_table, q.queue_switch_step1, q.queue_switch_step2
into batch
from pgq.tick last, pgq.tick cur, pgq.subscription s, pgq.queue q
where cur.tick_id = s.sub_next_tick
and cur.tick_queue = s.sub_queue
and last.tick_id = s.sub_last_tick
and last.tick_queue = s.sub_queue
and s.sub_batch = x_batch_id
and q.queue_id = s.sub_queue;
if not found then
raise exception 'Cannot find data for batch %', x_batch_id;
end if;
-- if its definitely not in one or other, look into both
if batch.tx_max < batch.queue_switch_step1 then
use_prev := 1;
use_next := 0;
elsif batch.queue_switch_step2 is not null
and (batch.tx_min > batch.queue_switch_step2)
then
use_prev := 0;
use_next := 1;
else
use_prev := 1;
use_next := 1;
end if;
if use_prev then
nr := batch.queue_cur_table - 1;
if nr < 0 then
nr := batch.queue_ntables - 1;
end if;
tbl := batch.queue_data_pfx || '_' || nr::text;
return next tbl;
end if;
if use_next then
tbl := batch.queue_data_pfx || '_' || batch.queue_cur_table::text;
return next tbl;
end if;
return;
end;
$$ language plpgsql; -- no perms needed
create or replace function pgq.event_retry_raw(
x_queue text,
x_consumer text,
x_retry_after timestamptz,
x_ev_id bigint,
x_ev_time timestamptz,
x_ev_retry integer,
x_ev_type text,
x_ev_data text,
x_ev_extra1 text,
x_ev_extra2 text,
x_ev_extra3 text,
x_ev_extra4 text)
returns bigint as $$
-- ----------------------------------------------------------------------
-- Function: pgq.event_retry_raw(12)
--
-- Allows full control over what goes to retry queue.
--
-- Parameters:
-- x_queue - name of the queue
-- x_consumer - name of the consumer
-- x_retry_after - when the event should be processed again
-- x_ev_id - event id
-- x_ev_time - creation time
-- x_ev_retry - retry count
-- x_ev_type - user data
-- x_ev_data - user data
-- x_ev_extra1 - user data
-- x_ev_extra2 - user data
-- x_ev_extra3 - user data
-- x_ev_extra4 - user data
--
-- Returns:
-- Event ID.
-- ----------------------------------------------------------------------
declare
q record;
id bigint;
begin
select sub_id, queue_event_seq, sub_queue into q
from pgq.consumer, pgq.queue, pgq.subscription
where queue_name = x_queue
and co_name = x_consumer
and sub_consumer = co_id
and sub_queue = queue_id;
if not found then
raise exception 'consumer not registered';
end if;
id := x_ev_id;
if id is null then
id := nextval(q.queue_event_seq);
end if;
insert into pgq.retry_queue (ev_retry_after, ev_queue,
ev_id, ev_time, ev_owner, ev_retry,
ev_type, ev_data, ev_extra1, ev_extra2, ev_extra3, ev_extra4)
values (x_retry_after, q.sub_queue,
id, x_ev_time, q.sub_id, x_ev_retry,
x_ev_type, x_ev_data, x_ev_extra1, x_ev_extra2,
x_ev_extra3, x_ev_extra4);
return id;
end;
$$ language plpgsql security definer;
create or replace function pgq.find_tick_helper(
in i_queue_id int4,
in i_prev_tick_id int8,
in i_prev_tick_time timestamptz,
in i_prev_tick_seq int8,
in i_min_count int8,
in i_min_interval interval,
out next_tick_id int8,
out next_tick_time timestamptz,
out next_tick_seq int8)
as $$
-- ----------------------------------------------------------------------
-- Function: pgq.find_tick_helper(6)
--
-- Helper function for pgq.next_batch_custom() to do extended tick search.
-- ----------------------------------------------------------------------
declare
sure boolean;
can_set boolean;
t record;
cnt int8;
ival interval;
begin
-- first, fetch last tick of the queue
select tick_id, tick_time, tick_event_seq into t
from pgq.tick
where tick_queue = i_queue_id
and tick_id > i_prev_tick_id
order by tick_queue desc, tick_id desc
limit 1;
if not found then
return;
end if;
-- check whether batch would end up within reasonable limits
sure := true;
can_set := false;
if i_min_count is not null then
cnt = t.tick_event_seq - i_prev_tick_seq;
if cnt >= i_min_count then
can_set := true;
end if;
if cnt > i_min_count * 2 then
sure := false;
end if;
end if;
if i_min_interval is not null then
ival = t.tick_time - i_prev_tick_time;
if ival >= i_min_interval then
can_set := true;
end if;
if ival > i_min_interval * 2 then
sure := false;
end if;
end if;
-- if last tick too far away, do large scan
if not sure then
select tick_id, tick_time, tick_event_seq into t
from pgq.tick
where tick_queue = i_queue_id
and tick_id > i_prev_tick_id
and ((i_min_count is not null and (tick_event_seq - i_prev_tick_seq) >= i_min_count)
or
(i_min_interval is not null and (tick_time - i_prev_tick_time) >= i_min_interval))
order by tick_queue asc, tick_id asc
limit 1;
can_set := true;
end if;
if can_set then
next_tick_id := t.tick_id;
next_tick_time := t.tick_time;
next_tick_seq := t.tick_event_seq;
end if;
return;
end;
$$ language plpgsql stable;
-- \i functions/pgq.insert_event_raw.sql
-- ----------------------------------------------------------------------
-- Function: pgq.insert_event_raw(11)
--
-- Actual event insertion. Used also by retry queue maintenance.
--
-- Parameters:
-- queue_name - Name of the queue
-- ev_id - Event ID. If NULL, will be taken from seq.
-- ev_time - Event creation time.
-- ev_owner - Subscription ID when retry event. If NULL, the event is for everybody.
-- ev_retry - Retry count. NULL for first-time events.
-- ev_type - user data
-- ev_data - user data
-- ev_extra1 - user data
-- ev_extra2 - user data
-- ev_extra3 - user data
-- ev_extra4 - user data
--
-- Returns:
-- Event ID.
-- ----------------------------------------------------------------------
CREATE OR REPLACE FUNCTION pgq.insert_event_raw(
queue_name text, ev_id bigint, ev_time timestamptz,
ev_owner integer, ev_retry integer, ev_type text, ev_data text,
ev_extra1 text, ev_extra2 text, ev_extra3 text, ev_extra4 text)
RETURNS int8 AS '$libdir/pgq_lowlevel', 'pgq_insert_event_raw' LANGUAGE C;
-- Group: Ticker
create or replace function pgq.ticker(i_queue_name text, i_tick_id bigint, i_orig_timestamp timestamptz, i_event_seq bigint)
returns bigint as $$
-- ----------------------------------------------------------------------
-- Function: pgq.ticker(3)
--
-- External ticker: Insert a tick with a particular tick_id and timestamp.
--
-- Parameters:
-- i_queue_name - Name of the queue
-- i_tick_id - Id of new tick.
--
-- Returns:
-- Tick id.
-- ----------------------------------------------------------------------
begin
insert into pgq.tick (tick_queue, tick_id, tick_time, tick_event_seq)
select queue_id, i_tick_id, i_orig_timestamp, i_event_seq
from pgq.queue
where queue_name = i_queue_name
and queue_external_ticker
and not queue_ticker_paused;
if not found then
raise exception 'queue not found or ticker disabled: %', i_queue_name;
end if;
-- make sure seqs stay current
perform pgq.seq_setval(queue_tick_seq, i_tick_id),
pgq.seq_setval(queue_event_seq, i_event_seq)
from pgq.queue
where queue_name = i_queue_name;
return i_tick_id;
end;
$$ language plpgsql security definer; -- unsure about access
create or replace function pgq.ticker(i_queue_name text)
returns bigint as $$
-- ----------------------------------------------------------------------
-- Function: pgq.ticker(1)
--
-- Check if tick is needed for the queue and insert it.
--
-- For pgqadm usage.
--
-- Parameters:
-- i_queue_name - Name of the queue
--
-- Returns:
-- Tick id or NULL if no tick was done.
-- ----------------------------------------------------------------------
declare
res bigint;
q record;
state record;
last2 record;
begin
select queue_id, queue_tick_seq, queue_external_ticker,
queue_ticker_max_count, queue_ticker_max_lag,
queue_ticker_idle_period, queue_event_seq,
pgq.seq_getval(queue_event_seq) as event_seq,
queue_ticker_paused
into q
from pgq.queue where queue_name = i_queue_name;
if not found then
raise exception 'no such queue';
end if;
if q.queue_external_ticker then
raise exception 'This queue has external tick source.';
end if;
if q.queue_ticker_paused then
raise exception 'Ticker has been paused for this queue';
end if;
-- load state from last tick
select now() - tick_time as lag,
q.event_seq - tick_event_seq as new_events,
tick_id, tick_time, tick_event_seq,
txid_snapshot_xmax(tick_snapshot) as sxmax,
txid_snapshot_xmin(tick_snapshot) as sxmin
into state
from pgq.tick
where tick_queue = q.queue_id
order by tick_queue desc, tick_id desc
limit 1;
if found then
if state.sxmin > txid_current() then
raise exception 'Invalid PgQ state: old xmin=%, old xmax=%, cur txid=%',
state.sxmin, state.sxmax, txid_current();
end if;
if state.new_events < 0 then
raise warning 'Negative new_events? old=% cur=%', state.tick_event_seq, q.event_seq;
end if;
if state.sxmax > txid_current() then
raise warning 'Dubious PgQ state: old xmax=%, cur txid=%', state.sxmax, txid_current();
end if;
if state.new_events > 0 then
-- there are new events, should we wait a bit?
if state.new_events < q.queue_ticker_max_count
and state.lag < q.queue_ticker_max_lag
then
return NULL;
end if;
else
-- no new events, should we apply idle period?
-- check previous event from the last one.
select state.tick_time - tick_time as lag
into last2
from pgq.tick
where tick_queue = q.queue_id
and tick_id < state.tick_id
order by tick_queue desc, tick_id desc
limit 1;
if found then
-- gradually decrease the tick frequency
if (state.lag < q.queue_ticker_max_lag / 2)
or
(state.lag < last2.lag * 2
and state.lag < q.queue_ticker_idle_period)
then
return NULL;
end if;
end if;
end if;
end if;
insert into pgq.tick (tick_queue, tick_id, tick_event_seq)
values (q.queue_id, nextval(q.queue_tick_seq), q.event_seq);
return currval(q.queue_tick_seq);
end;
$$ language plpgsql security definer; -- unsure about access
create or replace function pgq.ticker() returns bigint as $$
-- ----------------------------------------------------------------------
-- Function: pgq.ticker(0)
--
-- Creates ticks for all unpaused queues which dont have external ticker.
--
-- Returns:
-- Number of queues that were processed.
-- ----------------------------------------------------------------------
declare
res bigint;
q record;
begin
res := 0;
for q in
select queue_name from pgq.queue
where not queue_external_ticker
and not queue_ticker_paused
order by queue_name
loop
if pgq.ticker(q.queue_name) > 0 then
res := res + 1;
end if;
end loop;
return res;
end;
$$ language plpgsql security definer;
-- Group: Periodic maintenence
create or replace function pgq.maint_retry_events()
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.maint_retry_events(0)
--
-- Moves retry events back to main queue.
--
-- It moves small amount at a time. It should be called
-- until it returns 0
--
-- Returns:
-- Number of events processed.
-- ----------------------------------------------------------------------
declare
cnt integer;
rec record;
begin
cnt := 0;
-- allow only single event mover at a time, without affecting inserts
lock table pgq.retry_queue in share update exclusive mode;
for rec in
select queue_name,
ev_id, ev_time, ev_owner, ev_retry, ev_type, ev_data,
ev_extra1, ev_extra2, ev_extra3, ev_extra4
from pgq.retry_queue, pgq.queue
where ev_retry_after <= current_timestamp
and queue_id = ev_queue
order by ev_retry_after
limit 10
loop
cnt := cnt + 1;
perform pgq.insert_event_raw(rec.queue_name,
rec.ev_id, rec.ev_time, rec.ev_owner, rec.ev_retry,
rec.ev_type, rec.ev_data, rec.ev_extra1, rec.ev_extra2,
rec.ev_extra3, rec.ev_extra4);
delete from pgq.retry_queue
where ev_owner = rec.ev_owner
and ev_id = rec.ev_id;
end loop;
return cnt;
end;
$$ language plpgsql; -- need admin access
create or replace function pgq.maint_rotate_tables_step1(i_queue_name text)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.maint_rotate_tables_step1(1)
--
-- Rotate tables for one queue.
--
-- Parameters:
-- i_queue_name - Name of the queue
--
-- Returns:
-- 0
-- ----------------------------------------------------------------------
declare
badcnt integer;
cf record;
nr integer;
tbl text;
lowest_tick_id int8;
lowest_xmin int8;
begin
-- check if needed and load record
select * from pgq.queue into cf
where queue_name = i_queue_name
and queue_rotation_period is not null
and queue_switch_step2 is not null
and queue_switch_time + queue_rotation_period < current_timestamp
for update;
if not found then
return 0;
end if;
-- if DB is in invalid state, stop
if txid_current() < cf.queue_switch_step1 then
raise exception 'queue % maint failure: step1=%, current=%',
i_queue_name, cf.queue_switch_step1, txid_current();
end if;
-- find lowest tick for that queue
select min(sub_last_tick) into lowest_tick_id
from pgq.subscription
where sub_queue = cf.queue_id;
-- if some consumer exists
if lowest_tick_id is not null then
-- is the slowest one still on previous table?
select txid_snapshot_xmin(tick_snapshot) into lowest_xmin
from pgq.tick
where tick_queue = cf.queue_id
and tick_id = lowest_tick_id;
if not found then
raise exception 'queue % maint failure: tick % not found', i_queue_name, lowest_tick_id;
end if;
if lowest_xmin <= cf.queue_switch_step2 then
return 0; -- skip rotation then
end if;
end if;
-- nobody on previous table, we can rotate
-- calc next table number and name
nr := cf.queue_cur_table + 1;
if nr = cf.queue_ntables then
nr := 0;
end if;
tbl := cf.queue_data_pfx || '_' || nr::text;
-- there may be long lock on the table from pg_dump,
-- detect it and skip rotate then
begin
execute 'lock table ' || pgq.quote_fqname(tbl) || ' nowait';
execute 'truncate ' || pgq.quote_fqname(tbl);
exception
when lock_not_available then
-- cannot truncate, skipping rotate
return 0;
end;
-- remember the moment
update pgq.queue
set queue_cur_table = nr,
queue_switch_time = current_timestamp,
queue_switch_step1 = txid_current(),
queue_switch_step2 = NULL
where queue_id = cf.queue_id;
-- Clean ticks by using step2 txid from previous rotation.
-- That should keep all ticks for all batches that are completely
-- in old table. This keeps them for longer than needed, but:
-- 1. we want the pgq.tick table to be big, to avoid Postgres
-- accitentally switching to seqscans on that.
-- 2. that way we guarantee to consumers that they an be moved
-- back on the queue at least for one rotation_period.
-- (may help in disaster recovery)
delete from pgq.tick
where tick_queue = cf.queue_id
and txid_snapshot_xmin(tick_snapshot) < cf.queue_switch_step2;
return 0;
end;
$$ language plpgsql; -- need admin access
create or replace function pgq.maint_rotate_tables_step2()
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.maint_rotate_tables_step2(0)
--
-- Stores the txid when the rotation was visible. It should be
-- called in separate transaction than pgq.maint_rotate_tables_step1()
-- ----------------------------------------------------------------------
begin
update pgq.queue
set queue_switch_step2 = txid_current()
where queue_switch_step2 is null;
return 0;
end;
$$ language plpgsql; -- need admin access
create or replace function pgq.maint_tables_to_vacuum()
returns setof text as $$
-- ----------------------------------------------------------------------
-- Function: pgq.maint_tables_to_vacuum(0)
--
-- Returns list of tablenames that need frequent vacuuming.
--
-- The goal is to avoid hardcoding them into maintenance process.
--
-- Returns:
-- List of table names.
-- ----------------------------------------------------------------------
declare
scm text;
tbl text;
fqname text;
begin
-- assume autovacuum handles them fine
if current_setting('autovacuum') = 'on' then
return;
end if;
for scm, tbl in values
('pgq', 'subscription'),
('pgq', 'consumer'),
('pgq', 'queue'),
('pgq', 'tick'),
('pgq', 'retry_queue'),
('pgq_ext', 'completed_tick'),
('pgq_ext', 'completed_batch'),
('pgq_ext', 'completed_event'),
('pgq_ext', 'partial_batch'),
--('pgq_node', 'node_location'),
--('pgq_node', 'node_info'),
('pgq_node', 'local_state'),
--('pgq_node', 'subscriber_info'),
--('londiste', 'table_info'),
('londiste', 'seq_info'),
--('londiste', 'applied_execute'),
--('londiste', 'pending_fkeys'),
('txid', 'epoch'),
('londiste', 'completed')
loop
select n.nspname || '.' || t.relname into fqname
from pg_class t, pg_namespace n
where n.oid = t.relnamespace
and n.nspname = scm
and t.relname = tbl;
if found then
return next fqname;
end if;
end loop;
return;
end;
$$ language plpgsql;
create or replace function pgq.maint_operations(out func_name text, out func_arg text)
returns setof record as $$
-- ----------------------------------------------------------------------
-- Function: pgq.maint_operations(0)
--
-- Returns list of functions to call for maintenance.
--
-- The goal is to avoid hardcoding them into maintenance process.
--
-- Function signature:
-- Function should take either 1 or 0 arguments and return 1 if it wants
-- to be called immediately again, 0 if not.
--
-- Returns:
-- func_name - Function to call
-- func_arg - Optional argument to function (queue name)
-- ----------------------------------------------------------------------
declare
ops text[];
nrot int4;
begin
-- rotate step 1
nrot := 0;
func_name := 'pgq.maint_rotate_tables_step1';
for func_arg in
select queue_name from pgq.queue
where queue_rotation_period is not null
and queue_switch_step2 is not null
and queue_switch_time + queue_rotation_period < current_timestamp
order by 1
loop
nrot := nrot + 1;
return next;
end loop;
-- rotate step 2
if nrot = 0 then
select count(1) from pgq.queue
where queue_rotation_period is not null
and queue_switch_step2 is null
into nrot;
end if;
if nrot > 0 then
func_name := 'pgq.maint_rotate_tables_step2';
func_arg := NULL;
return next;
end if;
-- check if extra field exists
perform 1 from pg_attribute
where attrelid = 'pgq.queue'::regclass
and attname = 'queue_extra_maint';
if found then
-- add extra ops
for func_arg, ops in
select q.queue_name, queue_extra_maint from pgq.queue q
where queue_extra_maint is not null
order by 1
loop
for i in array_lower(ops, 1) .. array_upper(ops, 1)
loop
func_name = ops[i];
return next;
end loop;
end loop;
end if;
-- vacuum tables
func_name := 'vacuum';
for func_arg in
select * from pgq.maint_tables_to_vacuum()
loop
return next;
end loop;
--
-- pgq_node & londiste
--
-- although they belong to queue_extra_maint, they are
-- common enough so its more effective to handle them here.
--
perform 1 from pg_proc p, pg_namespace n
where p.pronamespace = n.oid
and n.nspname = 'pgq_node'
and p.proname = 'maint_watermark';
if found then
func_name := 'pgq_node.maint_watermark';
for func_arg in
select n.queue_name
from pgq_node.node_info n
where n.node_type = 'root'
loop
return next;
end loop;
end if;
perform 1 from pg_proc p, pg_namespace n
where p.pronamespace = n.oid
and n.nspname = 'londiste'
and p.proname = 'root_check_seqs';
if found then
func_name := 'londiste.root_check_seqs';
for func_arg in
select distinct s.queue_name
from londiste.seq_info s, pgq_node.node_info n
where s.local
and n.node_type = 'root'
and n.queue_name = s.queue_name
loop
return next;
end loop;
end if;
perform 1 from pg_proc p, pg_namespace n
where p.pronamespace = n.oid
and n.nspname = 'londiste'
and p.proname = 'periodic_maintenance';
if found then
func_name := 'londiste.periodic_maintenance';
func_arg := NULL;
return next;
end if;
return;
end;
$$ language plpgsql;
-- Group: Random utility functions
create or replace function pgq.grant_perms(x_queue_name text)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.grant_perms(1)
--
-- Make event tables readable by public.
--
-- Parameters:
-- x_queue_name - Name of the queue.
--
-- Returns:
-- nothing
-- ----------------------------------------------------------------------
declare
q record;
i integer;
pos integer;
tbl_perms text;
seq_perms text;
dst_schema text;
dst_table text;
part_table text;
begin
select * from pgq.queue into q
where queue_name = x_queue_name;
if not found then
raise exception 'Queue not found';
end if;
-- split data table name to components
pos := position('.' in q.queue_data_pfx);
if pos > 0 then
dst_schema := substring(q.queue_data_pfx for pos - 1);
dst_table := substring(q.queue_data_pfx from pos + 1);
else
dst_schema := 'public';
dst_table := q.queue_data_pfx;
end if;
-- tick seq, normal users don't need to modify it
execute 'grant select on ' || pgq.quote_fqname(q.queue_tick_seq) || ' to public';
-- event seq
execute 'grant select on ' || pgq.quote_fqname(q.queue_event_seq) || ' to public';
execute 'grant usage on ' || pgq.quote_fqname(q.queue_event_seq) || ' to pgq_admin';
-- set grants on parent table
perform pgq._grant_perms_from('pgq', 'event_template', dst_schema, dst_table);
-- set grants on real event tables
for i in 0 .. q.queue_ntables - 1 loop
part_table := dst_table || '_' || i::text;
perform pgq._grant_perms_from('pgq', 'event_template', dst_schema, part_table);
end loop;
return 1;
end;
$$ language plpgsql security definer;
create or replace function pgq._grant_perms_from(src_schema text, src_table text, dst_schema text, dst_table text)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.grant_perms_from(1)
--
-- Copy grants from one table to another.
-- Workaround for missing GRANTS option for CREATE TABLE LIKE.
-- ----------------------------------------------------------------------
declare
fq_table text;
sql text;
g record;
q_grantee text;
begin
fq_table := quote_ident(dst_schema) || '.' || quote_ident(dst_table);
for g in
select grantor, grantee, privilege_type, is_grantable
from information_schema.table_privileges
where table_schema = src_schema
and table_name = src_table
loop
if g.grantee = 'PUBLIC' then
q_grantee = 'public';
else
q_grantee = quote_ident(g.grantee);
end if;
sql := 'grant ' || g.privilege_type || ' on ' || fq_table
|| ' to ' || q_grantee;
if g.is_grantable = 'YES' then
sql := sql || ' with grant option';
end if;
execute sql;
end loop;
return 1;
end;
$$ language plpgsql strict;
create or replace function pgq.tune_storage(i_queue_name text)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.tune_storage(1)
--
-- Tunes storage settings for queue data tables
-- ----------------------------------------------------------------------
declare
tbl text;
tbloid oid;
q record;
i int4;
sql text;
pgver int4;
begin
pgver := current_setting('server_version_num');
select * into q
from pgq.queue where queue_name = i_queue_name;
if not found then
return 0;
end if;
for i in 0 .. (q.queue_ntables - 1) loop
tbl := q.queue_data_pfx || '_' || i::text;
-- set fillfactor
sql := 'alter table ' || tbl || ' set (fillfactor = 100';
-- autovacuum for 8.4+
if pgver >= 80400 then
sql := sql || ', autovacuum_enabled=off, toast.autovacuum_enabled =off';
end if;
sql := sql || ')';
execute sql;
-- autovacuum for 8.3
if pgver < 80400 then
tbloid := tbl::regclass::oid;
delete from pg_catalog.pg_autovacuum where vacrelid = tbloid;
insert into pg_catalog.pg_autovacuum values (tbloid, false, -1,-1,-1,-1,-1,-1,-1,-1);
end if;
end loop;
return 1;
end;
$$ language plpgsql strict;
create or replace function pgq.force_tick(i_queue_name text)
returns bigint as $$
-- ----------------------------------------------------------------------
-- Function: pgq.force_tick(2)
--
-- Simulate lots of events happening to force ticker to tick.
--
-- Should be called in loop, with some delay until last tick
-- changes or too much time is passed.
--
-- Such function is needed because paraller calls of pgq.ticker() are
-- dangerous, and cannot be protected with locks as snapshot
-- is taken before locking.
--
-- Parameters:
-- i_queue_name - Name of the queue
--
-- Returns:
-- Currently last tick id.
-- ----------------------------------------------------------------------
declare
q record;
t record;
begin
-- bump seq and get queue id
select queue_id,
setval(queue_event_seq, nextval(queue_event_seq)
+ queue_ticker_max_count * 2 + 1000) as tmp
into q from pgq.queue
where queue_name = i_queue_name
and not queue_external_ticker
and not queue_ticker_paused;
--if not found then
-- raise notice 'queue not found or ticks not allowed';
--end if;
-- return last tick id
select tick_id into t
from pgq.tick, pgq.queue
where tick_queue = queue_id and queue_name = i_queue_name
order by tick_queue desc, tick_id desc limit 1;
return t.tick_id;
end;
$$ language plpgsql security definer;
create or replace function pgq.seq_getval(i_seq_name text)
returns bigint as $$
-- ----------------------------------------------------------------------
-- Function: pgq.seq_getval(1)
--
-- Read current last_val from seq, without affecting it.
--
-- Parameters:
-- i_seq_name - Name of the sequence
--
-- Returns:
-- last value.
-- ----------------------------------------------------------------------
declare
res int8;
fqname text;
pos integer;
s text;
n text;
begin
pos := position('.' in i_seq_name);
if pos > 0 then
s := substring(i_seq_name for pos - 1);
n := substring(i_seq_name from pos + 1);
else
s := 'public';
n := i_seq_name;
end if;
fqname := quote_ident(s) || '.' || quote_ident(n);
execute 'select last_value from ' || fqname into res;
return res;
end;
$$ language plpgsql strict;
create or replace function pgq.seq_setval(i_seq_name text, i_new_value int8)
returns bigint as $$
-- ----------------------------------------------------------------------
-- Function: pgq.seq_setval(2)
--
-- Like setval() but does not allow going back.
--
-- Parameters:
-- i_seq_name - Name of the sequence
-- i_new_value - new value
--
-- Returns:
-- current last value.
-- ----------------------------------------------------------------------
declare
res int8;
fqname text;
begin
fqname := pgq.quote_fqname(i_seq_name);
res := pgq.seq_getval(i_seq_name);
if res < i_new_value then
perform setval(fqname, i_new_value);
return i_new_value;
end if;
return res;
end;
$$ language plpgsql strict;
create or replace function pgq.quote_fqname(i_name text)
returns text as $$
-- ----------------------------------------------------------------------
-- Function: pgq.quote_fqname(1)
--
-- Quete fully-qualified object name for SQL.
--
-- First dot is taken as schema separator.
--
-- If schema is missing, 'public' is assumed.
--
-- Parameters:
-- i_name - fully qualified object name.
--
-- Returns:
-- Quoted name.
-- ----------------------------------------------------------------------
declare
res text;
pos integer;
s text;
n text;
begin
pos := position('.' in i_name);
if pos > 0 then
s := substring(i_name for pos - 1);
n := substring(i_name from pos + 1);
else
s := 'public';
n := i_name;
end if;
return quote_ident(s) || '.' || quote_ident(n);
end;
$$ language plpgsql strict immutable;
-- ----------------------------------------------------------------------
-- Section: Public Functions
--
-- The queue is used by a client in the following steps
--
-- 1. Register the client (a queue consumer)
--
-- pgq.register_consumer(queue_name, consumer_id)
--
-- 2. run a loop createing, consuming and closing batches
--
-- 2a. pgq.get_batch_events(batch_id int8) - returns an int8 batch handle
--
-- 2b. pgq.get_batch_events(batch_id int8) - returns a set of events for current batch
--
-- the event structure is :(ev_id int8, ev_time timestamptz, ev_txid int8, ev_retry
-- int4, ev_type text, ev_data text, ev_extra1, ev_extra2, ev_extra3, ev_extra4)
--
-- 2c. if any of the events need to be tagged as failed, use a the function
--
-- pgq.event_failed(batch_id int8, event_id int8, reason text)
--
-- 2d. if you want the event to be re-inserted in the main queue afrer N seconds, use
--
-- pgq.event_retry(batch_id int8, event_id int8, retry_seconds int4)
--
-- 2e. To finish processing and release the batch, use
--
-- pgq.finish_batch(batch_id int8)
--
-- Until this is not done, the consumer will get same batch again.
--
-- After calling finish_batch consumer cannot do any operations with events
-- of that batch. All operations must be done before.
--
-- -- ----------------------------------------------------------------------
-- Group: Queue creation
create or replace function pgq.create_queue(i_queue_name text)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.create_queue(1)
--
-- Creates new queue with given name.
--
-- Returns:
-- 0 - queue already exists
-- 1 - queue created
-- Calls:
-- pgq.grant_perms(i_queue_name);
-- pgq.ticker(i_queue_name);
-- pgq.tune_storage(i_queue_name);
-- Tables directly manipulated:
-- insert - pgq.queue
-- create - pgq.event_N () inherits (pgq.event_template)
-- create - pgq.event_N_0 .. pgq.event_N_M () inherits (pgq.event_N)
-- ----------------------------------------------------------------------
declare
tblpfx text;
tblname text;
idxpfx text;
idxname text;
sql text;
id integer;
tick_seq text;
ev_seq text;
n_tables integer;
begin
if i_queue_name is null then
raise exception 'Invalid NULL value';
end if;
-- check if exists
perform 1 from pgq.queue where queue_name = i_queue_name;
if found then
return 0;
end if;
-- insert event
id := nextval('pgq.queue_queue_id_seq');
tblpfx := 'pgq.event_' || id::text;
idxpfx := 'event_' || id::text;
tick_seq := 'pgq.event_' || id::text || '_tick_seq';
ev_seq := 'pgq.event_' || id::text || '_id_seq';
insert into pgq.queue (queue_id, queue_name,
queue_data_pfx, queue_event_seq, queue_tick_seq)
values (id, i_queue_name, tblpfx, ev_seq, tick_seq);
select queue_ntables into n_tables from pgq.queue
where queue_id = id;
-- create seqs
execute 'CREATE SEQUENCE ' || pgq.quote_fqname(tick_seq);
execute 'CREATE SEQUENCE ' || pgq.quote_fqname(ev_seq);
-- create data tables
execute 'CREATE TABLE ' || pgq.quote_fqname(tblpfx) || ' () '
|| ' INHERITS (pgq.event_template)';
for i in 0 .. (n_tables - 1) loop
tblname := tblpfx || '_' || i::text;
idxname := idxpfx || '_' || i::text || '_txid_idx';
execute 'CREATE TABLE ' || pgq.quote_fqname(tblname) || ' () '
|| ' INHERITS (' || pgq.quote_fqname(tblpfx) || ')';
execute 'ALTER TABLE ' || pgq.quote_fqname(tblname) || ' ALTER COLUMN ev_id '
|| ' SET DEFAULT nextval(' || quote_literal(ev_seq) || ')';
execute 'create index ' || quote_ident(idxname) || ' on '
|| pgq.quote_fqname(tblname) || ' (ev_txid)';
end loop;
perform pgq.grant_perms(i_queue_name);
perform pgq.ticker(i_queue_name);
perform pgq.tune_storage(i_queue_name);
return 1;
end;
$$ language plpgsql security definer;
create or replace function pgq.drop_queue(x_queue_name text, x_force bool)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.drop_queue(2)
--
-- Drop queue and all associated tables.
--
-- Parameters:
-- x_queue_name - queue name
-- x_force - ignore (drop) existing consumers
-- Returns:
-- 1 - success
-- Calls:
-- pgq.unregister_consumer(queue_name, consumer_name)
-- perform pgq.ticker(i_queue_name);
-- perform pgq.tune_storage(i_queue_name);
-- Tables directly manipulated:
-- delete - pgq.queue
-- drop - pgq.event_N (), pgq.event_N_0 .. pgq.event_N_M
-- ----------------------------------------------------------------------
declare
tblname text;
q record;
num integer;
begin
-- check if exists
select * into q from pgq.queue
where queue_name = x_queue_name
for update;
if not found then
raise exception 'No such event queue';
end if;
if x_force then
perform pgq.unregister_consumer(queue_name, consumer_name)
from pgq.get_consumer_info(x_queue_name);
else
-- check if no consumers
select count(*) into num from pgq.subscription
where sub_queue = q.queue_id;
if num > 0 then
raise exception 'cannot drop queue, consumers still attached';
end if;
end if;
-- drop data tables
for i in 0 .. (q.queue_ntables - 1) loop
tblname := q.queue_data_pfx || '_' || i::text;
execute 'DROP TABLE ' || pgq.quote_fqname(tblname);
end loop;
execute 'DROP TABLE ' || pgq.quote_fqname(q.queue_data_pfx);
-- delete ticks
delete from pgq.tick where tick_queue = q.queue_id;
-- drop seqs
-- FIXME: any checks needed here?
execute 'DROP SEQUENCE ' || pgq.quote_fqname(q.queue_tick_seq);
execute 'DROP SEQUENCE ' || pgq.quote_fqname(q.queue_event_seq);
-- delete event
delete from pgq.queue
where queue_name = x_queue_name;
return 1;
end;
$$ language plpgsql security definer;
create or replace function pgq.drop_queue(x_queue_name text)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.drop_queue(1)
--
-- Drop queue and all associated tables.
-- No consumers must be listening on the queue.
--
-- ----------------------------------------------------------------------
begin
return pgq.drop_queue(x_queue_name, false);
end;
$$ language plpgsql strict;
create or replace function pgq.set_queue_config(
x_queue_name text,
x_param_name text,
x_param_value text)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.set_queue_config(3)
--
--
-- Set configuration for specified queue.
--
-- Parameters:
-- x_queue_name - Name of the queue to configure.
-- x_param_name - Configuration parameter name.
-- x_param_value - Configuration parameter value.
--
-- Returns:
-- 0 if event was already in queue, 1 otherwise.
-- Calls:
-- None
-- Tables directly manipulated:
-- update - pgq.queue
-- ----------------------------------------------------------------------
declare
v_param_name text;
begin
-- discard NULL input
if x_queue_name is null or x_param_name is null then
raise exception 'Invalid NULL value';
end if;
-- check if queue exists
perform 1 from pgq.queue where queue_name = x_queue_name;
if not found then
raise exception 'No such event queue';
end if;
-- check if valid parameter name
v_param_name := 'queue_' || x_param_name;
if v_param_name not in (
'queue_ticker_max_count',
'queue_ticker_max_lag',
'queue_ticker_idle_period',
'queue_ticker_paused',
'queue_rotation_period',
'queue_external_ticker')
then
raise exception 'cannot change parameter "%s"', x_param_name;
end if;
execute 'update pgq.queue set '
|| v_param_name || ' = ' || quote_literal(x_param_value)
|| ' where queue_name = ' || quote_literal(x_queue_name);
return 1;
end;
$$ language plpgsql security definer;
-- Group: Event publishing
create or replace function pgq.insert_event(queue_name text, ev_type text, ev_data text)
returns bigint as $$
-- ----------------------------------------------------------------------
-- Function: pgq.insert_event(3)
--
-- Insert a event into queue.
--
-- Parameters:
-- queue_name - Name of the queue
-- ev_type - User-specified type for the event
-- ev_data - User data for the event
--
-- Returns:
-- Event ID
-- Calls:
-- pgq.insert_event(7)
-- ----------------------------------------------------------------------
begin
return pgq.insert_event(queue_name, ev_type, ev_data, null, null, null, null);
end;
$$ language plpgsql;
create or replace function pgq.insert_event(
queue_name text, ev_type text, ev_data text,
ev_extra1 text, ev_extra2 text, ev_extra3 text, ev_extra4 text)
returns bigint as $$
-- ----------------------------------------------------------------------
-- Function: pgq.insert_event(7)
--
-- Insert a event into queue with all the extra fields.
--
-- Parameters:
-- queue_name - Name of the queue
-- ev_type - User-specified type for the event
-- ev_data - User data for the event
-- ev_extra1 - Extra data field for the event
-- ev_extra2 - Extra data field for the event
-- ev_extra3 - Extra data field for the event
-- ev_extra4 - Extra data field for the event
--
-- Returns:
-- Event ID
-- Calls:
-- pgq.insert_event_raw(11)
-- Tables directly manipulated:
-- insert - pgq.insert_event_raw(11), a C function, inserts into current event_N_M table
-- ----------------------------------------------------------------------
begin
return pgq.insert_event_raw(queue_name, null, now(), null, null,
ev_type, ev_data, ev_extra1, ev_extra2, ev_extra3, ev_extra4);
end;
$$ language plpgsql security definer;
create or replace function pgq.current_event_table(x_queue_name text)
returns text as $$
-- ----------------------------------------------------------------------
-- Function: pgq.current_event_table(1)
--
-- Return active event table for particular queue.
-- Event can be added to it without going via functions,
-- e.g. by COPY.
--
-- If queue is disabled and GUC session_replication_role <> 'replica'
-- then raises exception.
--
-- or expressed in a different way - an even table of a disabled queue
-- is returned only on replica
--
-- Note:
-- The result is valid only during current transaction.
--
-- Permissions:
-- Actual insertion requires superuser access.
--
-- Parameters:
-- x_queue_name - Queue name.
-- ----------------------------------------------------------------------
declare
res text;
disabled boolean;
begin
select queue_data_pfx || '_' || queue_cur_table::text,
queue_disable_insert
into res, disabled
from pgq.queue where queue_name = x_queue_name;
if not found then
raise exception 'Event queue not found';
end if;
if disabled then
if current_setting('session_replication_role') <> 'replica' then
raise exception 'Writing to queue disabled';
end if;
end if;
return res;
end;
$$ language plpgsql; -- no perms needed
-- Group: Subscribing to queue
create or replace function pgq.register_consumer(
x_queue_name text,
x_consumer_id text)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.register_consumer(2)
--
-- Subscribe consumer on a queue.
--
-- From this moment forward, consumer will see all events in the queue.
--
-- Parameters:
-- x_queue_name - Name of queue
-- x_consumer_name - Name of consumer
--
-- Returns:
-- 0 - if already registered
-- 1 - if new registration
-- Calls:
-- pgq.register_consumer_at(3)
-- Tables directly manipulated:
-- None
-- ----------------------------------------------------------------------
begin
return pgq.register_consumer_at(x_queue_name, x_consumer_id, NULL);
end;
$$ language plpgsql security definer;
create or replace function pgq.register_consumer_at(
x_queue_name text,
x_consumer_name text,
x_tick_pos bigint)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.register_consumer_at(3)
--
-- Extended registration, allows to specify tick_id.
--
-- Note:
-- For usage in special situations.
--
-- Parameters:
-- x_queue_name - Name of a queue
-- x_consumer_name - Name of consumer
-- x_tick_pos - Tick ID
--
-- Returns:
-- 0/1 whether consumer has already registered.
-- Calls:
-- None
-- Tables directly manipulated:
-- update/insert - pgq.subscription
-- ----------------------------------------------------------------------
declare
tmp text;
last_tick bigint;
x_queue_id integer;
x_consumer_id integer;
queue integer;
sub record;
begin
select queue_id into x_queue_id from pgq.queue
where queue_name = x_queue_name;
if not found then
raise exception 'Event queue not created yet';
end if;
-- get consumer and create if new
select co_id into x_consumer_id from pgq.consumer
where co_name = x_consumer_name;
if not found then
insert into pgq.consumer (co_name) values (x_consumer_name);
x_consumer_id := currval('pgq.consumer_co_id_seq');
end if;
-- if particular tick was requested, check if it exists
if x_tick_pos is not null then
perform 1 from pgq.tick
where tick_queue = x_queue_id
and tick_id = x_tick_pos;
if not found then
raise exception 'cannot reposition, tick not found: %', x_tick_pos;
end if;
end if;
-- check if already registered
select sub_last_tick, sub_batch into sub
from pgq.subscription
where sub_consumer = x_consumer_id
and sub_queue = x_queue_id;
if found then
if x_tick_pos is not null then
-- if requested, update tick pos and drop partial batch
update pgq.subscription
set sub_last_tick = x_tick_pos,
sub_batch = null,
sub_next_tick = null,
sub_active = now()
where sub_consumer = x_consumer_id
and sub_queue = x_queue_id;
end if;
-- already registered
return 0;
end if;
-- new registration
if x_tick_pos is null then
-- start from current tick
select tick_id into last_tick from pgq.tick
where tick_queue = x_queue_id
order by tick_queue desc, tick_id desc
limit 1;
if not found then
raise exception 'No ticks for this queue. Please run ticker on database.';
end if;
else
last_tick := x_tick_pos;
end if;
-- register
insert into pgq.subscription (sub_queue, sub_consumer, sub_last_tick)
values (x_queue_id, x_consumer_id, last_tick);
return 1;
end;
$$ language plpgsql security definer;
create or replace function pgq.unregister_consumer(
x_queue_name text,
x_consumer_name text)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.unregister_consumer(2)
--
-- Unsubscriber consumer from the queue. Also consumer's
-- retry events are deleted.
--
-- Parameters:
-- x_queue_name - Name of the queue
-- x_consumer_name - Name of the consumer
--
-- Returns:
-- number of (sub)consumers unregistered
-- Calls:
-- None
-- Tables directly manipulated:
-- delete - pgq.retry_queue
-- delete - pgq.subscription
-- ----------------------------------------------------------------------
declare
x_sub_id integer;
_sub_id_cnt integer;
_consumer_id integer;
_is_subconsumer boolean;
begin
select s.sub_id, c.co_id,
-- subconsumers can only have both null or both not null - main consumer for subconsumers has only one not null
(s.sub_last_tick IS NULL AND s.sub_next_tick IS NULL) OR (s.sub_last_tick IS NOT NULL AND s.sub_next_tick IS NOT NULL)
into x_sub_id, _consumer_id, _is_subconsumer
from pgq.subscription s, pgq.consumer c, pgq.queue q
where s.sub_queue = q.queue_id
and s.sub_consumer = c.co_id
and q.queue_name = x_queue_name
and c.co_name = x_consumer_name
for update of s;
if not found then
return 0;
end if;
-- consumer + subconsumer count
select count(*) into _sub_id_cnt
from pgq.subscription
where sub_id = x_sub_id;
-- delete only one subconsumer
if _sub_id_cnt > 1 and _is_subconsumer then
delete from pgq.subscription
where sub_id = x_sub_id
and sub_consumer = _consumer_id;
return 1;
else
-- delete main consumer (including possible subconsumers)
-- retry events
delete from pgq.retry_queue
where ev_owner = x_sub_id;
-- this will drop subconsumers too
delete from pgq.subscription
where sub_id = x_sub_id;
return _sub_id_cnt;
end if;
end;
$$ language plpgsql security definer;
-- Group: Batch processing
create or replace function pgq.next_batch_info(
in i_queue_name text,
in i_consumer_name text,
out batch_id int8,
out cur_tick_id int8,
out prev_tick_id int8,
out cur_tick_time timestamptz,
out prev_tick_time timestamptz,
out cur_tick_event_seq int8,
out prev_tick_event_seq int8)
as $$
-- ----------------------------------------------------------------------
-- Function: pgq.next_batch_info(2)
--
-- Makes next block of events active.
--
-- If it returns NULL, there is no events available in queue.
-- Consumer should sleep then.
--
-- The values from event_id sequence may give hint how big the
-- batch may be. But they are inexact, they do not give exact size.
-- Client *MUST NOT* use them to detect whether the batch contains any
-- events at all - the values are unfit for that purpose.
--
-- Parameters:
-- i_queue_name - Name of the queue
-- i_consumer_name - Name of the consumer
--
-- Returns:
-- batch_id - Batch ID or NULL if there are no more events available.
-- cur_tick_id - End tick id.
-- cur_tick_time - End tick time.
-- cur_tick_event_seq - Value from event id sequence at the time tick was issued.
-- prev_tick_id - Start tick id.
-- prev_tick_time - Start tick time.
-- prev_tick_event_seq - value from event id sequence at the time tick was issued.
-- Calls:
-- pgq.next_batch_custom(5)
-- Tables directly manipulated:
-- None
-- ----------------------------------------------------------------------
begin
select f.batch_id, f.cur_tick_id, f.prev_tick_id,
f.cur_tick_time, f.prev_tick_time,
f.cur_tick_event_seq, f.prev_tick_event_seq
into batch_id, cur_tick_id, prev_tick_id, cur_tick_time, prev_tick_time,
cur_tick_event_seq, prev_tick_event_seq
from pgq.next_batch_custom(i_queue_name, i_consumer_name, NULL, NULL, NULL) f;
return;
end;
$$ language plpgsql;
create or replace function pgq.next_batch(
in i_queue_name text,
in i_consumer_name text)
returns int8 as $$
-- ----------------------------------------------------------------------
-- Function: pgq.next_batch(2)
--
-- Old function that returns just batch_id.
--
-- Parameters:
-- i_queue_name - Name of the queue
-- i_consumer_name - Name of the consumer
--
-- Returns:
-- Batch ID or NULL if there are no more events available.
-- ----------------------------------------------------------------------
declare
res int8;
begin
select batch_id into res
from pgq.next_batch_info(i_queue_name, i_consumer_name);
return res;
end;
$$ language plpgsql;
create or replace function pgq.next_batch_custom(
in i_queue_name text,
in i_consumer_name text,
in i_min_lag interval,
in i_min_count int4,
in i_min_interval interval,
out batch_id int8,
out cur_tick_id int8,
out prev_tick_id int8,
out cur_tick_time timestamptz,
out prev_tick_time timestamptz,
out cur_tick_event_seq int8,
out prev_tick_event_seq int8)
as $$
-- ----------------------------------------------------------------------
-- Function: pgq.next_batch_custom(5)
--
-- Makes next block of events active. Block size can be tuned
-- with i_min_count, i_min_interval parameters. Events age can
-- be tuned with i_min_lag.
--
-- If it returns NULL, there is no events available in queue.
-- Consumer should sleep then.
--
-- The values from event_id sequence may give hint how big the
-- batch may be. But they are inexact, they do not give exact size.
-- Client *MUST NOT* use them to detect whether the batch contains any
-- events at all - the values are unfit for that purpose.
--
-- Note:
-- i_min_lag together with i_min_interval/i_min_count is inefficient.
--
-- Parameters:
-- i_queue_name - Name of the queue
-- i_consumer_name - Name of the consumer
-- i_min_lag - Consumer wants events older than that
-- i_min_count - Consumer wants batch to contain at least this many events
-- i_min_interval - Consumer wants batch to cover at least this much time
--
-- Returns:
-- batch_id - Batch ID or NULL if there are no more events available.
-- cur_tick_id - End tick id.
-- cur_tick_time - End tick time.
-- cur_tick_event_seq - Value from event id sequence at the time tick was issued.
-- prev_tick_id - Start tick id.
-- prev_tick_time - Start tick time.
-- prev_tick_event_seq - value from event id sequence at the time tick was issued.
-- Calls:
-- pgq.insert_event_raw(11)
-- Tables directly manipulated:
-- update - pgq.subscription
-- ----------------------------------------------------------------------
declare
errmsg text;
queue_id integer;
sub_id integer;
cons_id integer;
begin
select s.sub_queue, s.sub_consumer, s.sub_id, s.sub_batch,
t1.tick_id, t1.tick_time, t1.tick_event_seq,
t2.tick_id, t2.tick_time, t2.tick_event_seq
into queue_id, cons_id, sub_id, batch_id,
prev_tick_id, prev_tick_time, prev_tick_event_seq,
cur_tick_id, cur_tick_time, cur_tick_event_seq
from pgq.consumer c,
pgq.queue q,
pgq.subscription s
left join pgq.tick t1
on (t1.tick_queue = s.sub_queue
and t1.tick_id = s.sub_last_tick)
left join pgq.tick t2
on (t2.tick_queue = s.sub_queue
and t2.tick_id = s.sub_next_tick)
where q.queue_name = i_queue_name
and c.co_name = i_consumer_name
and s.sub_queue = q.queue_id
and s.sub_consumer = c.co_id;
if not found then
errmsg := 'Not subscriber to queue: '
|| coalesce(i_queue_name, 'NULL')
|| '/'
|| coalesce(i_consumer_name, 'NULL');
raise exception '%', errmsg;
end if;
-- sanity check
if prev_tick_id is null then
raise exception 'PgQ corruption: Consumer % on queue % does not see tick %', i_consumer_name, i_queue_name, prev_tick_id;
end if;
-- has already active batch
if batch_id is not null then
return;
end if;
if i_min_interval is null and i_min_count is null then
-- find next tick
select tick_id, tick_time, tick_event_seq
into cur_tick_id, cur_tick_time, cur_tick_event_seq
from pgq.tick
where tick_id > prev_tick_id
and tick_queue = queue_id
order by tick_queue asc, tick_id asc
limit 1;
else
-- find custom tick
select next_tick_id, next_tick_time, next_tick_seq
into cur_tick_id, cur_tick_time, cur_tick_event_seq
from pgq.find_tick_helper(queue_id, prev_tick_id,
prev_tick_time, prev_tick_event_seq,
i_min_count, i_min_interval);
end if;
if i_min_lag is not null then
-- enforce min lag
if now() - cur_tick_time < i_min_lag then
cur_tick_id := NULL;
cur_tick_time := NULL;
cur_tick_event_seq := NULL;
end if;
end if;
if cur_tick_id is null then
-- nothing to do
prev_tick_id := null;
prev_tick_time := null;
prev_tick_event_seq := null;
return;
end if;
-- get next batch
batch_id := nextval('pgq.batch_id_seq');
update pgq.subscription
set sub_batch = batch_id,
sub_next_tick = cur_tick_id,
sub_active = now()
where sub_queue = queue_id
and sub_consumer = cons_id;
return;
end;
$$ language plpgsql security definer;
create or replace function pgq.get_batch_events(
in x_batch_id bigint,
out ev_id bigint,
out ev_time timestamptz,
out ev_txid bigint,
out ev_retry int4,
out ev_type text,
out ev_data text,
out ev_extra1 text,
out ev_extra2 text,
out ev_extra3 text,
out ev_extra4 text)
returns setof record as $$
-- ----------------------------------------------------------------------
-- Function: pgq.get_batch_events(1)
--
-- Get all events in batch.
--
-- Parameters:
-- x_batch_id - ID of active batch.
--
-- Returns:
-- List of events.
-- ----------------------------------------------------------------------
declare
sql text;
begin
sql := pgq.batch_event_sql(x_batch_id);
for ev_id, ev_time, ev_txid, ev_retry, ev_type, ev_data,
ev_extra1, ev_extra2, ev_extra3, ev_extra4
in execute sql
loop
return next;
end loop;
return;
end;
$$ language plpgsql; -- no perms needed
create or replace function pgq.get_batch_cursor(
in i_batch_id bigint,
in i_cursor_name text,
in i_quick_limit int4,
in i_extra_where text,
out ev_id bigint,
out ev_time timestamptz,
out ev_txid bigint,
out ev_retry int4,
out ev_type text,
out ev_data text,
out ev_extra1 text,
out ev_extra2 text,
out ev_extra3 text,
out ev_extra4 text)
returns setof record as $$
-- ----------------------------------------------------------------------
-- Function: pgq.get_batch_cursor(4)
--
-- Get events in batch using a cursor.
--
-- Parameters:
-- i_batch_id - ID of active batch.
-- i_cursor_name - Name for new cursor
-- i_quick_limit - Number of events to return immediately
-- i_extra_where - optional where clause to filter events
--
-- Returns:
-- List of events.
-- Calls:
-- pgq.batch_event_sql(i_batch_id) - internal function which generates SQL optimised specially for getting events in this batch
-- ----------------------------------------------------------------------
declare
_cname text;
_sql text;
begin
if i_batch_id is null or i_cursor_name is null or i_quick_limit is null then
return;
end if;
_cname := quote_ident(i_cursor_name);
_sql := pgq.batch_event_sql(i_batch_id);
-- apply extra where
if i_extra_where is not null then
_sql := replace(_sql, ' order by 1', '');
_sql := 'select * from (' || _sql
|| ') _evs where ' || i_extra_where
|| ' order by 1';
end if;
-- create cursor
execute 'declare ' || _cname || ' no scroll cursor for ' || _sql;
-- if no events wanted, don't bother with execute
if i_quick_limit <= 0 then
return;
end if;
-- return first block of events
for ev_id, ev_time, ev_txid, ev_retry, ev_type, ev_data,
ev_extra1, ev_extra2, ev_extra3, ev_extra4
in execute 'fetch ' || i_quick_limit::text || ' from ' || _cname
loop
return next;
end loop;
return;
end;
$$ language plpgsql; -- no perms needed
create or replace function pgq.get_batch_cursor(
in i_batch_id bigint,
in i_cursor_name text,
in i_quick_limit int4,
out ev_id bigint,
out ev_time timestamptz,
out ev_txid bigint,
out ev_retry int4,
out ev_type text,
out ev_data text,
out ev_extra1 text,
out ev_extra2 text,
out ev_extra3 text,
out ev_extra4 text)
returns setof record as $$
-- ----------------------------------------------------------------------
-- Function: pgq.get_batch_cursor(3)
--
-- Get events in batch using a cursor.
--
-- Parameters:
-- i_batch_id - ID of active batch.
-- i_cursor_name - Name for new cursor
-- i_quick_limit - Number of events to return immediately
--
-- Returns:
-- List of events.
-- Calls:
-- pgq.get_batch_cursor(4)
-- ----------------------------------------------------------------------
begin
for ev_id, ev_time, ev_txid, ev_retry, ev_type, ev_data,
ev_extra1, ev_extra2, ev_extra3, ev_extra4
in
select * from pgq.get_batch_cursor(i_batch_id,
i_cursor_name, i_quick_limit, null)
loop
return next;
end loop;
return;
end;
$$ language plpgsql strict; -- no perms needed
create or replace function pgq.event_retry(
x_batch_id bigint,
x_event_id bigint,
x_retry_time timestamptz)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.event_retry(3a)
--
-- Put the event into retry queue, to be processed again later.
--
-- Parameters:
-- x_batch_id - ID of active batch.
-- x_event_id - event id
-- x_retry_time - Time when the event should be put back into queue
--
-- Returns:
-- 1 - success
-- 0 - event already in retry queue
-- Calls:
-- None
-- Tables directly manipulated:
-- insert - pgq.retry_queue
-- ----------------------------------------------------------------------
begin
insert into pgq.retry_queue (ev_retry_after, ev_queue,
ev_id, ev_time, ev_txid, ev_owner, ev_retry, ev_type, ev_data,
ev_extra1, ev_extra2, ev_extra3, ev_extra4)
select x_retry_time, sub_queue,
ev_id, ev_time, NULL, sub_id, coalesce(ev_retry, 0) + 1,
ev_type, ev_data, ev_extra1, ev_extra2, ev_extra3, ev_extra4
from pgq.get_batch_events(x_batch_id),
pgq.subscription
where sub_batch = x_batch_id
and ev_id = x_event_id;
if not found then
raise exception 'event not found';
end if;
return 1;
-- dont worry if the event is already in queue
exception
when unique_violation then
return 0;
end;
$$ language plpgsql security definer;
create or replace function pgq.event_retry(
x_batch_id bigint,
x_event_id bigint,
x_retry_seconds integer)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.event_retry(3b)
--
-- Put the event into retry queue, to be processed later again.
--
-- Parameters:
-- x_batch_id - ID of active batch.
-- x_event_id - event id
-- x_retry_seconds - Time when the event should be put back into queue
--
-- Returns:
-- 1 - success
-- 0 - event already in retry queue
-- Calls:
-- pgq.event_retry(3a)
-- Tables directly manipulated:
-- None
-- ----------------------------------------------------------------------
declare
new_retry timestamptz;
begin
new_retry := current_timestamp + ((x_retry_seconds::text || ' seconds')::interval);
return pgq.event_retry(x_batch_id, x_event_id, new_retry);
end;
$$ language plpgsql security definer;
create or replace function pgq.batch_retry(
i_batch_id bigint,
i_retry_seconds integer)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.batch_retry(2)
--
-- Put whole batch into retry queue, to be processed again later.
--
-- Parameters:
-- i_batch_id - ID of active batch.
-- i_retry_time - Time when the event should be put back into queue
--
-- Returns:
-- number of events inserted
-- Calls:
-- None
-- Tables directly manipulated:
-- pgq.retry_queue
-- ----------------------------------------------------------------------
declare
_retry timestamptz;
_cnt integer;
_s record;
begin
_retry := current_timestamp + ((i_retry_seconds::text || ' seconds')::interval);
select * into _s from pgq.subscription where sub_batch = i_batch_id;
if not found then
raise exception 'batch_retry: batch % not found', i_batch_id;
end if;
insert into pgq.retry_queue (ev_retry_after, ev_queue,
ev_id, ev_time, ev_txid, ev_owner, ev_retry,
ev_type, ev_data, ev_extra1, ev_extra2,
ev_extra3, ev_extra4)
select distinct _retry, _s.sub_queue,
b.ev_id, b.ev_time, NULL::int8, _s.sub_id, coalesce(b.ev_retry, 0) + 1,
b.ev_type, b.ev_data, b.ev_extra1, b.ev_extra2,
b.ev_extra3, b.ev_extra4
from pgq.get_batch_events(i_batch_id) b
left join pgq.retry_queue rq
on (rq.ev_id = b.ev_id
and rq.ev_owner = _s.sub_id
and rq.ev_queue = _s.sub_queue)
where rq.ev_id is null;
GET DIAGNOSTICS _cnt = ROW_COUNT;
return _cnt;
end;
$$ language plpgsql security definer;
create or replace function pgq.finish_batch(
x_batch_id bigint)
returns integer as $$
-- ----------------------------------------------------------------------
-- Function: pgq.finish_batch(1)
--
-- Closes a batch. No more operations can be done with events
-- of this batch.
--
-- Parameters:
-- x_batch_id - id of batch.
--
-- Returns:
-- 1 if batch was found, 0 otherwise.
-- Calls:
-- None
-- Tables directly manipulated:
-- update - pgq.subscription
-- ----------------------------------------------------------------------
begin
update pgq.subscription
set sub_active = now(),
sub_last_tick = sub_next_tick,
sub_next_tick = null,
sub_batch = null
where sub_batch = x_batch_id;
if not found then
raise warning 'finish_batch: batch % not found', x_batch_id;
return 0;
end if;
return 1;
end;
$$ language plpgsql security definer;
-- Group: General info functions
drop function if exists pgq.get_queue_info();
drop function if exists pgq.get_queue_info(text);
create or replace function pgq.get_queue_info(
out queue_name text,
out queue_ntables integer,
out queue_cur_table integer,
out queue_rotation_period interval,
out queue_switch_time timestamptz,
out queue_external_ticker boolean,
out queue_ticker_paused boolean,
out queue_ticker_max_count integer,
out queue_ticker_max_lag interval,
out queue_ticker_idle_period interval,
out ticker_lag interval,
out ev_per_sec float8,
out ev_new bigint,
out last_tick_id bigint)
returns setof record as $$
-- ----------------------------------------------------------------------
-- Function: pgq.get_queue_info(0)
--
-- Get info about all queues.
--
-- Returns:
-- List of pgq.ret_queue_info records.
-- queue_name - queue name
-- queue_ntables - number of tables in this queue
-- queue_cur_table - ???
-- queue_rotation_period - how often the event_N_M tables in this queue are rotated
-- queue_switch_time - ??? when was this queue last rotated
-- queue_external_ticker - ???
-- queue_ticker_paused - ??? is ticker paused in this queue
-- queue_ticker_max_count - max number of events before a tick is issued
-- queue_ticker_max_lag - maks time without a tick
-- queue_ticker_idle_period - how often the ticker should check this queue
-- ticker_lag - time from last tick
-- ev_per_sec - how many events per second this queue serves
-- ev_new - ???
-- last_tick_id - last tick id for this queue
--
-- ----------------------------------------------------------------------
begin
for queue_name, queue_ntables, queue_cur_table, queue_rotation_period,
queue_switch_time, queue_external_ticker, queue_ticker_paused,
queue_ticker_max_count, queue_ticker_max_lag, queue_ticker_idle_period,
ticker_lag, ev_per_sec, ev_new, last_tick_id
in select
f.queue_name, f.queue_ntables, f.queue_cur_table, f.queue_rotation_period,
f.queue_switch_time, f.queue_external_ticker, f.queue_ticker_paused,
f.queue_ticker_max_count, f.queue_ticker_max_lag, f.queue_ticker_idle_period,
f.ticker_lag, f.ev_per_sec, f.ev_new, f.last_tick_id
from pgq.get_queue_info(null) f
loop
return next;
end loop;
return;
end;
$$ language plpgsql;
create or replace function pgq.get_queue_info(
in i_queue_name text,
out queue_name text,
out queue_ntables integer,
out queue_cur_table integer,
out queue_rotation_period interval,
out queue_switch_time timestamptz,
out queue_external_ticker boolean,
out queue_ticker_paused boolean,
out queue_ticker_max_count integer,
out queue_ticker_max_lag interval,
out queue_ticker_idle_period interval,
out ticker_lag interval,
out ev_per_sec float8,
out ev_new bigint,
out last_tick_id bigint)
returns setof record as $$
-- ----------------------------------------------------------------------
-- Function: pgq.get_queue_info(1)
--
-- Get info about particular queue.
--
-- Returns:
-- One pgq.ret_queue_info record.
-- contente same as forpgq.get_queue_info()
-- ----------------------------------------------------------------------
declare
_ticker_lag interval;
_top_tick_id bigint;
_ht_tick_id bigint;
_top_tick_time timestamptz;
_top_tick_event_seq bigint;
_ht_tick_time timestamptz;
_ht_tick_event_seq bigint;
_queue_id integer;
_queue_event_seq text;
begin
for queue_name, queue_ntables, queue_cur_table, queue_rotation_period,
queue_switch_time, queue_external_ticker, queue_ticker_paused,
queue_ticker_max_count, queue_ticker_max_lag, queue_ticker_idle_period,
_queue_id, _queue_event_seq
in select
q.queue_name, q.queue_ntables, q.queue_cur_table,
q.queue_rotation_period, q.queue_switch_time,
q.queue_external_ticker, q.queue_ticker_paused,
q.queue_ticker_max_count, q.queue_ticker_max_lag,
q.queue_ticker_idle_period,
q.queue_id, q.queue_event_seq
from pgq.queue q
where (i_queue_name is null or q.queue_name = i_queue_name)
order by q.queue_name
loop
-- most recent tick
select (current_timestamp - t.tick_time),
tick_id, t.tick_time, t.tick_event_seq
into ticker_lag, _top_tick_id, _top_tick_time, _top_tick_event_seq
from pgq.tick t
where t.tick_queue = _queue_id
order by t.tick_queue desc, t.tick_id desc
limit 1;
-- slightly older tick
select ht.tick_id, ht.tick_time, ht.tick_event_seq
into _ht_tick_id, _ht_tick_time, _ht_tick_event_seq
from pgq.tick ht
where ht.tick_queue = _queue_id
and ht.tick_id >= _top_tick_id - 20
order by ht.tick_queue asc, ht.tick_id asc
limit 1;
if _ht_tick_time < _top_tick_time then
ev_per_sec = (_top_tick_event_seq - _ht_tick_event_seq) / extract(epoch from (_top_tick_time - _ht_tick_time));
else
ev_per_sec = null;
end if;
ev_new = pgq.seq_getval(_queue_event_seq) - _top_tick_event_seq;
last_tick_id = _top_tick_id;
return next;
end loop;
return;
end;
$$ language plpgsql;
create or replace function pgq.get_consumer_info(
out queue_name text,
out consumer_name text,
out lag interval,
out last_seen interval,
out last_tick bigint,
out current_batch bigint,
out next_tick bigint,
out pending_events bigint)
returns setof record as $$
-- ----------------------------------------------------------------------
-- Function: pgq.get_consumer_info(0)
--
-- Returns info about all consumers on all queues.
--
-- Returns:
-- See pgq.get_consumer_info(2)
-- ----------------------------------------------------------------------
begin
for queue_name, consumer_name, lag, last_seen,
last_tick, current_batch, next_tick, pending_events
in
select f.queue_name, f.consumer_name, f.lag, f.last_seen,
f.last_tick, f.current_batch, f.next_tick, f.pending_events
from pgq.get_consumer_info(null, null) f
loop
return next;
end loop;
return;
end;
$$ language plpgsql security definer;
create or replace function pgq.get_consumer_info(
in i_queue_name text,
out queue_name text,
out consumer_name text,
out lag interval,
out last_seen interval,
out last_tick bigint,
out current_batch bigint,
out next_tick bigint,
out pending_events bigint)
returns setof record as $$
-- ----------------------------------------------------------------------
-- Function: pgq.get_consumer_info(1)
--
-- Returns info about all consumers on single queue.
--
-- Returns:
-- See pgq.get_consumer_info(2)
-- ----------------------------------------------------------------------
begin
for queue_name, consumer_name, lag, last_seen,
last_tick, current_batch, next_tick, pending_events
in
select f.queue_name, f.consumer_name, f.lag, f.last_seen,
f.last_tick, f.current_batch, f.next_tick, f.pending_events
from pgq.get_consumer_info(i_queue_name, null) f
loop
return next;
end loop;
return;
end;
$$ language plpgsql security definer;
create or replace function pgq.get_consumer_info(
in i_queue_name text,
in i_consumer_name text,
out queue_name text,
out consumer_name text,
out lag interval,
out last_seen interval,
out last_tick bigint,
out current_batch bigint,
out next_tick bigint,
out pending_events bigint)
returns setof record as $$
-- ----------------------------------------------------------------------
-- Function: pgq.get_consumer_info(2)
--
-- Get info about particular consumer on particular queue.
--
-- Parameters:
-- i_queue_name - name of a queue. (null = all)
-- i_consumer_name - name of a consumer (null = all)
--
-- Returns:
-- queue_name - Queue name
-- consumer_name - Consumer name
-- lag - How old are events the consumer is processing
-- last_seen - When the consumer seen by pgq
-- last_tick - Tick ID of last processed tick
-- current_batch - Current batch ID, if one is active or NULL
-- next_tick - If batch is active, then its final tick.
-- ----------------------------------------------------------------------
declare
_pending_events bigint;
_queue_id bigint;
begin
for queue_name, consumer_name, lag, last_seen,
last_tick, current_batch, next_tick, _pending_events, _queue_id
in
select q.queue_name, c.co_name,
current_timestamp - t.tick_time,
current_timestamp - s.sub_active,
s.sub_last_tick, s.sub_batch, s.sub_next_tick,
t.tick_event_seq, q.queue_id
from pgq.queue q,
pgq.consumer c,
pgq.subscription s
left join pgq.tick t
on (t.tick_queue = s.sub_queue and t.tick_id = s.sub_last_tick)
where q.queue_id = s.sub_queue
and c.co_id = s.sub_consumer
and (i_queue_name is null or q.queue_name = i_queue_name)
and (i_consumer_name is null or c.co_name = i_consumer_name)
order by 1,2
loop
select t.tick_event_seq - _pending_events
into pending_events
from pgq.tick t
where t.tick_queue = _queue_id
order by t.tick_queue desc, t.tick_id desc
limit 1;
return next;
end loop;
return;
end;
$$ language plpgsql security definer;
create or replace function pgq.version()
returns text as $$
-- ----------------------------------------------------------------------
-- Function: pgq.version(0)
--
-- Returns version string for pgq. ATM it is based on SkyTools
-- version and only bumped when database code changes.
-- ----------------------------------------------------------------------
begin
return '3.2';
end;
$$ language plpgsql;
create or replace function pgq.get_batch_info(
in x_batch_id bigint,
out queue_name text,
out consumer_name text,
out batch_start timestamptz,
out batch_end timestamptz,
out prev_tick_id bigint,
out tick_id bigint,
out lag interval,
out seq_start bigint,
out seq_end bigint)
as $$
-- ----------------------------------------------------------------------
-- Function: pgq.get_batch_info(1)
--
-- Returns detailed info about a batch.
--
-- Parameters:
-- x_batch_id - id of a active batch.
--
-- Returns: ??? pls check
-- queue_name - which queue this batch came from
-- consumer_name - batch processed by
-- batch_start - start time of batch
-- batch_end - end time of batch
-- prev_tick_id - start tick for this batch
-- tick_id - end tick for this batch
-- lag - now() - tick_id.time
-- seq_start - start event id for batch
-- seq_end - end event id for batch
-- ----------------------------------------------------------------------
begin
select q.queue_name, c.co_name,
prev.tick_time, cur.tick_time,
s.sub_last_tick, s.sub_next_tick,
current_timestamp - cur.tick_time,
prev.tick_event_seq, cur.tick_event_seq
into queue_name, consumer_name, batch_start, batch_end,
prev_tick_id, tick_id, lag, seq_start, seq_end
from pgq.subscription s, pgq.tick cur, pgq.tick prev,
pgq.queue q, pgq.consumer c
where s.sub_batch = x_batch_id
and prev.tick_id = s.sub_last_tick
and prev.tick_queue = s.sub_queue
and cur.tick_id = s.sub_next_tick
and cur.tick_queue = s.sub_queue
and q.queue_id = s.sub_queue
and c.co_id = s.sub_consumer;
return;
end;
$$ language plpgsql security definer;
-- Section: Public Triggers
-- Group: Trigger Functions
-- \i triggers/pgq.logutriga.sql
-- ----------------------------------------------------------------------
-- Function: pgq.sqltriga()
--
-- Trigger that generates queue events containing partial SQL.
-- It autodetects table structure.
--
-- Purpose:
-- Replication events, that only need changed column values.
--
-- Parameters:
-- arg1 - queue name
-- argX - any number of optional arg, in any order
--
-- Optinal arguments:
-- SKIP - The actual operation should be skipped (BEFORE trigger)
-- ignore=col1[,col2] - don't look at the specified arguments
-- pkey=col1[,col2] - Set pkey fields for the table, PK autodetection will be skipped
-- backup - Put urlencoded contents of old row to ev_extra2
-- colname=EXPR - Override field value with SQL expression. Can reference table
-- columns. colname can be: ev_type, ev_data, ev_extra1 .. ev_extra4
-- when=EXPR - If EXPR returns false, don't insert event.
--
-- Queue event fields:
-- ev_type - I/U/D
-- ev_data - partial SQL statement
-- ev_extra1 - table name
-- ev_extra2 - optional urlencoded backup
--
-- ----------------------------------------------------------------------
CREATE OR REPLACE FUNCTION pgq.sqltriga() RETURNS trigger
AS '$libdir/pgq_triggers', 'pgq_sqltriga' LANGUAGE C;
-- ----------------------------------------------------------------------
-- Function: pgq.logutriga()
--
-- Trigger function that puts row data in urlencoded form into queue.
--
-- Purpose:
-- Used as producer for several PgQ standard consumers (cube_dispatcher,
-- queue_mover, table_dispatcher). Basically for cases where the
-- consumer wants to parse the event and look at the actual column values.
--
-- Trigger parameters:
-- arg1 - queue name
-- argX - any number of optional arg, in any order
--
-- Optinal arguments:
-- SKIP - The actual operation should be skipped (BEFORE trigger)
-- ignore=col1[,col2] - don't look at the specified arguments
-- pkey=col1[,col2] - Set pkey fields for the table, autodetection will be skipped
-- backup - Put urlencoded contents of old row to ev_extra2
-- colname=EXPR - Override field value with SQL expression. Can reference table
-- columns. colname can be: ev_type, ev_data, ev_extra1 .. ev_extra4
-- when=EXPR - If EXPR returns false, don't insert event.
--
-- Queue event fields:
-- ev_type - I/U/D ':' pkey_column_list
-- ev_data - column values urlencoded
-- ev_extra1 - table name
-- ev_extra2 - optional urlencoded backup
--
-- Regular listen trigger example:
-- > CREATE TRIGGER triga_nimi AFTER INSERT OR UPDATE ON customer
-- > FOR EACH ROW EXECUTE PROCEDURE pgq.logutriga('qname');
--
-- Redirect trigger example:
-- > CREATE TRIGGER triga_nimi BEFORE INSERT OR UPDATE ON customer
-- > FOR EACH ROW EXECUTE PROCEDURE pgq.logutriga('qname', 'SKIP');
-- ----------------------------------------------------------------------
CREATE OR REPLACE FUNCTION pgq.logutriga() RETURNS TRIGGER
AS '$libdir/pgq_triggers', 'pgq_logutriga' LANGUAGE C;
---- disable obsolete trigger
-- ----------------------------------------------------------------------
-- Function - pgq.logtriga()
--
-- (Obsolete) Non-automatic SQL trigger. It puts row data in partial SQL form into
-- queue. It does not auto-detect table structure, it needs to be passed
-- as trigger arg.
--
-- Purpose:
-- Used by Londiste to generate replication events. The "partial SQL"
-- format is more compact than the urlencoded format but cannot be
-- parsed, only applied. Which is fine for Londiste.
--
-- Parameters:
-- arg1 - queue name
-- arg2 - column type spec string where each column corresponds to one char (k/v/i).
-- if spec string is shorter than column list, rest of columns default to 'i'.
--
-- Column types:
-- k - pkey column
-- v - normal data column
-- i - ignore column
--
-- Queue event fields:
-- ev_type - I/U/D
-- ev_data - partial SQL statement
-- ev_extra1 - table name
--
-- ----------------------------------------------------------------------
-- CREATE OR REPLACE FUNCTION pgq.logtriga() RETURNS trigger
-- AS '$libdir/pgq_triggers', 'pgq_logtriga' LANGUAGE C;
grant usage on schema pgq to public;
-- old default grants
grant select on table pgq.consumer to public;
grant select on table pgq.queue to public;
grant select on table pgq.tick to public;
grant select on table pgq.queue to public;
grant select on table pgq.subscription to public;
grant select on table pgq.event_template to public;
grant select on table pgq.retry_queue to public;
|