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
|
-- General setup
\set SHOW_CONTEXT never
-- Check the relations that aren't dumped
-- we ignore *_src_tmp are those should never be dumped
WITH ext AS (
SELECT c.oid, c.relname
FROM pg_depend d
JOIN pg_extension e ON d.refclassid = 'pg_extension'::regclass
AND e.oid = d.refobjid
AND e.extname = 'powa'
JOIN pg_class c ON d.classid = 'pg_class'::regclass
AND c.oid = d.objid
WHERE c.relkind != 'v'
),
dmp AS (
SELECT unnest(extconfig) AS oid
FROM pg_extension
WHERE extname = 'powa'
)
SELECT ext.relname
FROM ext
LEFT JOIN dmp USING (oid)
WHERE dmp.oid IS NULL
AND ext.relname NOT LIKE '%src_tmp'
ORDER BY ext.relname::text COLLATE "C";
-- Check that no *_src_tmp table are dumped
WITH ext AS (
SELECT c.oid, c.relname
FROM pg_depend d
JOIN pg_extension e ON d.refclassid = 'pg_extension'::regclass
AND e.oid = d.refobjid
AND e.extname = 'powa'
JOIN pg_class c ON d.classid = 'pg_class'::regclass
AND c.oid = d.objid
WHERE c.relkind != 'v'
),
dmp AS (
SELECT unnest(extconfig) AS oid
FROM pg_extension
WHERE extname = 'powa'
)
SELECT ext.relname
FROM ext
LEFT JOIN dmp USING (oid)
WHERE dmp.oid IS NOT NULL
AND ext.relname LIKE '%src_tmp'
ORDER BY ext.relname::text COLLATE "C";
-- Check for object that aren't in the "PoWA" schema
WITH ext AS (
SELECT pg_describe_object(classid, objid, objsubid) AS descr
FROM pg_depend d
JOIN pg_extension e ON d.refclassid = 'pg_extension'::regclass
AND e.oid = d.refobjid
AND e.extname = 'powa'
)
SELECT descr
FROM ext
WHERE descr NOT LIKE '%"PoWA"%'
ORDER BY descr COLLATE "C";
-- check (mins|maxs)_in_range columns not marked as STORAGE MAIN
WITH ext AS (
SELECT c.oid, c.relname
FROM pg_depend d
JOIN pg_extension e ON d.refclassid = 'pg_extension'::regclass
AND e.oid = d.refobjid
AND e.extname = 'powa'
JOIN pg_class c ON d.classid = 'pg_class'::regclass
AND c.oid = d.objid
WHERE c.relkind != 'v'
)
SELECT ext.relname, a.attname
FROM ext
JOIN pg_attribute a ON a.attrelid = ext.oid
WHERE a.attname ~ '^(mins|maxs)_in_range$'
AND a.attstorage != 'm'
ORDER BY ext.relname::text COLLATE "C", a.attname::text COLLATE "C";
-- Aggregate data every 5 snapshots
SET powa.coalesce = 5;
-- test C SRFs
SELECT COUNT(*) = 0
FROM pg_database,
LATERAL "PoWA".powa_stat_user_functions(oid) f
WHERE datname = current_database();
-- on pg15+ the function is a no-op, and this function will be deprecated soon
-- anyway
SELECT COUNT(*) >= 0
FROM pg_database,
LATERAL "PoWA".powa_stat_all_rel(oid)
WHERE datname = current_database();
-- Test snapshot
SELECT 1, COUNT(*) = 0 FROM "PoWA".powa_user_functions_history_current;
SELECT 1, COUNT(*) = 0 FROM "PoWA".powa_all_tables_history_current;
SELECT 1, COUNT(*) = 0 FROM "PoWA".powa_statements_history_current;
SELECT 1, COUNT(*) = 0 FROM "PoWA".powa_statements_history_current_db;
SELECT 1, COUNT(*) = 0 FROM "PoWA".powa_user_functions_history;
SELECT 1, COUNT(*) = 0 FROM "PoWA".powa_all_tables_history;
SELECT 1, COUNT(*) = 0 FROM "PoWA".powa_statements_history;
SELECT 1, COUNT(*) = 0 FROM "PoWA".powa_statements_history;
SELECT 1, count(*) = 0 FROM "PoWA".powa_stat_get_activity(0, '-infinity', 'infinity');
SELECT "PoWA".powa_take_snapshot();
SELECT 2, COUNT(*) >= 0 FROM "PoWA".powa_user_functions_history_current;
SELECT 2, COUNT(*) >= 0 FROM "PoWA".powa_all_tables_history_current;
SELECT 2, COUNT(*) > 0 FROM "PoWA".powa_statements_history_current;
SELECT 2, COUNT(*) > 0 FROM "PoWA".powa_statements_history_current_db;
SELECT 2, COUNT(*) >= 0 FROM "PoWA".powa_user_functions_history;
SELECT 2, COUNT(*) = 0 FROM "PoWA".powa_all_tables_history;
SELECT 2, COUNT(*) = 0 FROM "PoWA".powa_statements_history;
SELECT 2, COUNT(*) = 0 FROM "PoWA".powa_statements_history;
SELECT 2, count(*) > 0 FROM "PoWA".powa_stat_get_activity(0, '-infinity', 'infinity');
SELECT 2, count(*) = 0 FROM "PoWA".powa_stat_get_activity(42, '-infinity', 'infinity');
SELECT "PoWA".powa_take_snapshot();
SELECT "PoWA".powa_take_snapshot();
SELECT "PoWA".powa_take_snapshot();
-- This snapshot will trigger the aggregate
SELECT "PoWA".powa_take_snapshot();
SELECT 3, COUNT(*) >= 0 FROM "PoWA".powa_user_functions_history_current;
SELECT 3, COUNT(*) >= 0 FROM "PoWA".powa_all_tables_history_current;
SELECT 3, COUNT(*) > 0 FROM "PoWA".powa_statements_history_current;
SELECT 3, COUNT(*) > 0 FROM "PoWA".powa_statements_history_current_db;
SELECT 3, COUNT(*) >= 0 FROM "PoWA".powa_user_functions_history;
SELECT 3, COUNT(*) >= 0 FROM "PoWA".powa_all_tables_history;
SELECT 3, COUNT(*) > 0 FROM "PoWA".powa_statements_history;
SELECT 3, COUNT(*) > 0 FROM "PoWA".powa_statements_history;
SELECT 3, count(*) > 4 FROM "PoWA".powa_stat_get_activity(0, '-infinity', 'infinity');
SELECT 3, count(*) = 0 FROM "PoWA".powa_stat_get_activity(42, '-infinity', 'infinity');
-- Test reset function
SELECT * from "PoWA".powa_reset(0);
SELECT 4, COUNT(*) = 0 FROM "PoWA".powa_user_functions_history_current;
SELECT 4, COUNT(*) = 0 FROM "PoWA".powa_all_tables_history_current;
SELECT 4, COUNT(*) = 0 FROM "PoWA".powa_statements_history_current;
SELECT 4, COUNT(*) = 0 FROM "PoWA".powa_statements_history_current_db;
SELECT 4, COUNT(*) = 0 FROM "PoWA".powa_user_functions_history;
SELECT 4, COUNT(*) = 0 FROM "PoWA".powa_all_tables_history;
SELECT 4, COUNT(*) = 0 FROM "PoWA".powa_statements_history;
SELECT 4, COUNT(*) = 0 FROM "PoWA".powa_statements_history;
SELECT 4, count(*) = 0 FROM "PoWA".powa_stat_get_activity(0, '-infinity', 'infinity');
-- Test toast_tuple_target: we shouldn't have any table belonging to powa archivist
-- that has a column mins_in_range (it means it's a coalesced table) and isn't set
-- for aggressive toasting
WITH ext AS (
SELECT c.oid, c.relname, c.reloptions
FROM pg_depend d
JOIN pg_extension e ON d.refclassid = 'pg_extension'::regclass
AND e.oid = d.refobjid
AND e.extname = 'powa'
JOIN pg_class c ON d.classid = 'pg_class'::regclass
AND c.oid = d.objid
WHERE c.relkind != 'v'
)
SELECT ext.relname
FROM ext
WHERE EXISTS
(SELECT 1 FROM pg_attribute a
WHERE a.attrelid = ext.oid
AND a.attname = 'mins_in_range'
)
AND 'toast_tuple_target=128' <> ALL(coalesce(ext.reloptions,'{}'))
AND current_setting('server_version_num')::int >= 110000
ORDER BY ext.relname::text COLLATE "C";
|