1-- 2-- Test Statistics Collector 3-- 4-- Must be run after tenk2 has been created (by create_table), 5-- populated (by create_misc) and indexed (by create_index). 6-- 7 8-- conditio sine qua non 9SHOW track_counts; -- must be on 10 11-- ensure that both seqscan and indexscan plans are allowed 12SET enable_seqscan TO on; 13SET enable_indexscan TO on; 14-- for the moment, we don't want index-only scans here 15SET enable_indexonlyscan TO off; 16 17-- save counters 18CREATE TABLE prevstats AS 19SELECT t.seq_scan, t.seq_tup_read, t.idx_scan, t.idx_tup_fetch, 20 (b.heap_blks_read + b.heap_blks_hit) AS heap_blks, 21 (b.idx_blks_read + b.idx_blks_hit) AS idx_blks, 22 pg_stat_get_snapshot_timestamp() as snap_ts 23 FROM pg_catalog.pg_stat_user_tables AS t, 24 pg_catalog.pg_statio_user_tables AS b 25 WHERE t.relname='tenk2' AND b.relname='tenk2'; 26 27-- function to wait for counters to advance 28create function wait_for_stats() returns void as $$ 29declare 30 start_time timestamptz := clock_timestamp(); 31 updated1 bool; 32 updated2 bool; 33 updated3 bool; 34 updated4 bool; 35begin 36 -- we don't want to wait forever; loop will exit after 30 seconds 37 for i in 1 .. 300 loop 38 39 -- With parallel query, the seqscan and indexscan on tenk2 might be done 40 -- in parallel worker processes, which will send their stats counters 41 -- asynchronously to what our own session does. So we must check for 42 -- those counts to be registered separately from the update counts. 43 44 -- check to see if seqscan has been sensed 45 SELECT (st.seq_scan >= pr.seq_scan + 1) INTO updated1 46 FROM pg_stat_user_tables AS st, pg_class AS cl, prevstats AS pr 47 WHERE st.relname='tenk2' AND cl.relname='tenk2'; 48 49 -- check to see if indexscan has been sensed 50 SELECT (st.idx_scan >= pr.idx_scan + 1) INTO updated2 51 FROM pg_stat_user_tables AS st, pg_class AS cl, prevstats AS pr 52 WHERE st.relname='tenk2' AND cl.relname='tenk2'; 53 54 -- check to see if all updates have been sensed 55 SELECT (n_tup_ins > 0) INTO updated3 56 FROM pg_stat_user_tables WHERE relname='trunc_stats_test4'; 57 58 -- We must also check explicitly that pg_stat_get_snapshot_timestamp has 59 -- advanced, because that comes from the global stats file which might 60 -- be older than the per-DB stats file we got the other values from. 61 SELECT (pr.snap_ts < pg_stat_get_snapshot_timestamp()) INTO updated4 62 FROM prevstats AS pr; 63 64 exit when updated1 and updated2 and updated3 and updated4; 65 66 -- wait a little 67 perform pg_sleep_for('100 milliseconds'); 68 69 -- reset stats snapshot so we can test again 70 perform pg_stat_clear_snapshot(); 71 72 end loop; 73 74 -- report time waited in postmaster log (where it won't change test output) 75 raise log 'wait_for_stats delayed % seconds', 76 extract(epoch from clock_timestamp() - start_time); 77end 78$$ language plpgsql; 79 80-- test effects of TRUNCATE on n_live_tup/n_dead_tup counters 81CREATE TABLE trunc_stats_test(id serial); 82CREATE TABLE trunc_stats_test1(id serial, stuff text); 83CREATE TABLE trunc_stats_test2(id serial); 84CREATE TABLE trunc_stats_test3(id serial, stuff text); 85CREATE TABLE trunc_stats_test4(id serial); 86 87-- check that n_live_tup is reset to 0 after truncate 88INSERT INTO trunc_stats_test DEFAULT VALUES; 89INSERT INTO trunc_stats_test DEFAULT VALUES; 90INSERT INTO trunc_stats_test DEFAULT VALUES; 91TRUNCATE trunc_stats_test; 92 93-- test involving a truncate in a transaction; 4 ins but only 1 live 94INSERT INTO trunc_stats_test1 DEFAULT VALUES; 95INSERT INTO trunc_stats_test1 DEFAULT VALUES; 96INSERT INTO trunc_stats_test1 DEFAULT VALUES; 97UPDATE trunc_stats_test1 SET id = id + 10 WHERE id IN (1, 2); 98DELETE FROM trunc_stats_test1 WHERE id = 3; 99 100BEGIN; 101UPDATE trunc_stats_test1 SET id = id + 100; 102TRUNCATE trunc_stats_test1; 103INSERT INTO trunc_stats_test1 DEFAULT VALUES; 104COMMIT; 105 106-- use a savepoint: 1 insert, 1 live 107BEGIN; 108INSERT INTO trunc_stats_test2 DEFAULT VALUES; 109INSERT INTO trunc_stats_test2 DEFAULT VALUES; 110SAVEPOINT p1; 111INSERT INTO trunc_stats_test2 DEFAULT VALUES; 112TRUNCATE trunc_stats_test2; 113INSERT INTO trunc_stats_test2 DEFAULT VALUES; 114RELEASE SAVEPOINT p1; 115COMMIT; 116 117-- rollback a savepoint: this should count 4 inserts and have 2 118-- live tuples after commit (and 2 dead ones due to aborted subxact) 119BEGIN; 120INSERT INTO trunc_stats_test3 DEFAULT VALUES; 121INSERT INTO trunc_stats_test3 DEFAULT VALUES; 122SAVEPOINT p1; 123INSERT INTO trunc_stats_test3 DEFAULT VALUES; 124INSERT INTO trunc_stats_test3 DEFAULT VALUES; 125TRUNCATE trunc_stats_test3; 126INSERT INTO trunc_stats_test3 DEFAULT VALUES; 127ROLLBACK TO SAVEPOINT p1; 128COMMIT; 129 130-- rollback a truncate: this should count 2 inserts and produce 2 dead tuples 131BEGIN; 132INSERT INTO trunc_stats_test4 DEFAULT VALUES; 133INSERT INTO trunc_stats_test4 DEFAULT VALUES; 134TRUNCATE trunc_stats_test4; 135INSERT INTO trunc_stats_test4 DEFAULT VALUES; 136ROLLBACK; 137 138-- do a seqscan 139SELECT count(*) FROM tenk2; 140-- do an indexscan 141-- make sure it is not a bitmap scan, which might skip fetching heap tuples 142SET enable_bitmapscan TO off; 143SELECT count(*) FROM tenk2 WHERE unique1 = 1; 144RESET enable_bitmapscan; 145 146-- We can't just call wait_for_stats() at this point, because we only 147-- transmit stats when the session goes idle, and we probably didn't 148-- transmit the last couple of counts yet thanks to the rate-limiting logic 149-- in pgstat_report_stat(). But instead of waiting for the rate limiter's 150-- timeout to elapse, let's just start a new session. The old one will 151-- then send its stats before dying. 152\c - 153 154-- wait for stats collector to update 155SELECT wait_for_stats(); 156 157-- check effects 158SELECT relname, n_tup_ins, n_tup_upd, n_tup_del, n_live_tup, n_dead_tup 159 FROM pg_stat_user_tables 160 WHERE relname like 'trunc_stats_test%' order by relname; 161 162SELECT st.seq_scan >= pr.seq_scan + 1, 163 st.seq_tup_read >= pr.seq_tup_read + cl.reltuples, 164 st.idx_scan >= pr.idx_scan + 1, 165 st.idx_tup_fetch >= pr.idx_tup_fetch + 1 166 FROM pg_stat_user_tables AS st, pg_class AS cl, prevstats AS pr 167 WHERE st.relname='tenk2' AND cl.relname='tenk2'; 168 169SELECT st.heap_blks_read + st.heap_blks_hit >= pr.heap_blks + cl.relpages, 170 st.idx_blks_read + st.idx_blks_hit >= pr.idx_blks + 1 171 FROM pg_statio_user_tables AS st, pg_class AS cl, prevstats AS pr 172 WHERE st.relname='tenk2' AND cl.relname='tenk2'; 173 174SELECT pr.snap_ts < pg_stat_get_snapshot_timestamp() as snapshot_newer 175FROM prevstats AS pr; 176 177DROP TABLE trunc_stats_test, trunc_stats_test1, trunc_stats_test2, trunc_stats_test3, trunc_stats_test4; 178DROP TABLE prevstats; 179-- End of Stats Test 180