From fd3f1fb60d3913def0ee1bb0229cba8e6e63ee57 Mon Sep 17 00:00:00 2001 From: emerichunter Date: Fri, 13 Aug 2021 11:18:45 +0200 Subject: [PATCH 1/3] update start.psql --- start.psql | 120 +++++++++++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 120 insertions(+) diff --git a/start.psql b/start.psql index c83b396..ff59138 100644 --- a/start.psql +++ b/start.psql @@ -10,19 +10,39 @@ \echo ' b3 – Tables Bloat, more precise (requires pgstattuple extension; expensive)' \echo ' b4 – B-tree Indexes Bloat, more precise (requires pgstattuple extension; expensive)' \echo ' b5 – Tables and Columns Without Stats (so bloat cannot be estimated)' +\echo ' d1 – Duplicate foreign keys' +\echo ' d2 – Duplicate indexes' \echo ' e1 – List of extensions installed in the current DB' +\echo ' e2 – Empty tables' \echo ' i1 – Unused/Rarely Used Indexes' \echo ' i2 – List of redundant indexes' \echo ' i3 – FKs with Missing/Bad Indexes' \echo ' i4 – List of invalid indexes' \echo ' i5 – Unused/Redundant Indexes Do & Undo Migration DDL' \echo ' l1 – Locks: analysis of "locking trees"' +\echo ' m1 – Table(s) missing pk' +\echo ' n1 – Tables with neither pk nor any index ' \echo ' p1 – [EXPERIMENTAL] Alignment Padding. How many bytes can be saved if columns are ordered better?' +\echo ' re – Complete report of a to z omitting b3, b4, p1, v1, v2 and pg_stat_statements steps' \echo ' s1 – Slowest Queries, by Total Time (requires pg_stat_statements extension)' \echo ' s2 – Slowest Queries Report (requires pg_stat_statements)' +\echo ' sc – Top 5 SQL statements which consume the most time in total and have the most calls.' +\echo ' si – Top 5 SQL statements which consume the most I/O resources in total.' +\echo ' sj – Top 5 SQL statements with the most severe response jitter.' +\echo ' sm – Top 5 SQL statements which consume the most time in total.' +\echo ' so – Top 5 SQL statements which consume the most time in one call.' +\echo ' sr – Top 5 SQL statements which consume the most shared memory resources.' +\echo ' ss – Top5 Report with si, sm, so, sc, st, sj, sr (requires pg_stat_statements + track_io_timing=on)' +\echo ' st – Top 5 SQL statements which consume the most temporary space.' \echo ' t1 – Postgres parameters tuning' +\echo ' t2 – Tables with a single column (might need a more detailed column if PK, if nonPK relation why bother?)' +\echo ' u1 – Unlogged tables (not crash safe, not replicated, no PITR)' +\echo ' u2 – Useless unique constraints on FK or PK' +\echo ' u3 – Useless columns that have no more than 1 value ' +\echo ' u4 – Unused tables' \echo ' v1 – Vacuum: Current Activity' \echo ' v2 – Vacuum: VACUUM progress and autovacuum queue' +\echo ' w1 – Wrap-around approaching: when age is above 85% of freeze_max_age' \echo ' q – Quit' \echo \echo Type your choice and press : @@ -39,19 +59,39 @@ select :d_stp::text = 'b3' as d_step_is_b3, :d_stp::text = 'b4' as d_step_is_b4, :d_stp::text = 'b5' as d_step_is_b5, +:d_stp::text = 'd1' as d_step_is_d1, +:d_stp::text = 'd2' as d_step_is_d2, :d_stp::text = 'e1' as d_step_is_e1, +:d_stp::text = 'e2' as d_step_is_e2, :d_stp::text = 'i1' as d_step_is_i1, :d_stp::text = 'i2' as d_step_is_i2, :d_stp::text = 'i3' as d_step_is_i3, :d_stp::text = 'i4' as d_step_is_i4, :d_stp::text = 'i5' as d_step_is_i5, :d_stp::text = 'l1' as d_step_is_l1, +:d_stp::text = 'm1' as d_step_is_m1, +:d_stp::text = 'n1' as d_step_is_n1, :d_stp::text = 'p1' as d_step_is_p1, +:d_stp::text = 're' as d_step_is_re, :d_stp::text = 's1' as d_step_is_s1, :d_stp::text = 's2' as d_step_is_s2, +:d_stp::text = 'sc' as d_step_is_sc, +:d_stp::text = 'si' as d_step_is_si, +:d_stp::text = 'sj' as d_step_is_sj, +:d_stp::text = 'sm' as d_step_is_sm, +:d_stp::text = 'so' as d_step_is_so, +:d_stp::text = 'sr' as d_step_is_sr, +:d_stp::text = 'ss' as d_step_is_ss, +:d_stp::text = 'st' as d_step_is_st, :d_stp::text = 't1' as d_step_is_t1, +:d_stp::text = 't2' as d_step_is_t2, +:d_stp::text = 'u1' as d_step_is_u1, +:d_stp::text = 'u2' as d_step_is_u2, +:d_stp::text = 'u3' as d_step_is_u3, +:d_stp::text = 'u4' as d_step_is_u4, :d_stp::text = 'v1' as d_step_is_v1, :d_stp::text = 'v2' as d_step_is_v2, +:d_stp::text = 'w1' as d_step_is_w1, :d_stp::text = 'q' as d_step_is_q \gset \if :d_step_is_q \echo 'Bye!' @@ -96,10 +136,22 @@ select \ir ./sql/b5_tables_no_stats.sql \prompt 'Press to continue…' d_dummy \ir ./start.psql +\elif :d_step_is_d1 + \ir ./sql/d1_duplicate_fks.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_d2 + \ir ./sql/d2_duplicate_idxs.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql \elif :d_step_is_e1 \ir ./sql/e1_extensions.sql \prompt 'Press to continue…' d_dummy \ir ./start.psql +\elif :d_step_is_e2 + \ir ./sql/e2_empty_tables.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql \elif :d_step_is_i1 \ir ./sql/i1_rare_indexes.sql \prompt 'Press to continue…' d_dummy @@ -124,10 +176,22 @@ select \ir ./sql/l1_lock_trees.sql \prompt 'Press to continue…' d_dummy \ir ./start.psql +\elif :d_step_is_m1 + \ir ./sql/m1_missing_pks.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_n1 + \ir ./sql/n1_noidx_nopk.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql \elif :d_step_is_p1 \ir ./sql/p1_alignment_padding.sql \prompt 'Press to continue…' d_dummy \ir ./start.psql +\elif :d_step_is_re + \ir ./sql/re_complete_report.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql \elif :d_step_is_s1 \ir ./sql/s1_pg_stat_statements_top_total.sql \prompt 'Press to continue…' d_dummy @@ -136,10 +200,62 @@ select \ir ./sql/s2_pg_stat_statements_report.sql \prompt 'Press to continue…' d_dummy \ir ./start.psql +\elif :d_step_is_sc + \ir ./sql/sc_pg_stat_statements_most_called.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_si + \ir ./sql/si_pg_stat_statements_io.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_sj + \ir ./sql/sj_pg_stat_statements_jitter.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_sm + \ir ./sql/sm_pg_stat_statements_time_total.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_so + \ir ./sql/so_pg_stat_statements_time1call.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_sr + \ir ./sql/sr_pg_stat_statements_most_memory.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_ss + \ir ./sql/ss_pg_stat_statements_full_report.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_st + \ir ./sql/st_pg_stat_statements_temp_files.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql \elif :d_step_is_t1 \ir ./sql/t1_tuning.sql \prompt 'Press to continue…' d_dummy \ir ./start.psql +\elif :d_step_is_t2 + \ir ./sql/t2_single_columns.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_u1 + \ir ./sql/u1_unlogged_tables.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_u2 + \ir ./sql/u2_useless_unique_fk.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_u3 + \ir ./sql/u3_useless_columns.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql +\elif :d_step_is_u4 + \ir ./sql/u4_unused_tables.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql \elif :d_step_is_v1 \ir ./sql/v1_vacuum_activity.sql \prompt 'Press to continue…' d_dummy @@ -148,6 +264,10 @@ select \ir ./sql/v2_autovacuum_progress_and_queue.sql \prompt 'Press to continue…' d_dummy \ir ./start.psql +\elif :d_step_is_w1 + \ir ./sql/w1_wraparound_alert.sql + \prompt 'Press to continue…' d_dummy + \ir ./start.psql \else \echo \echo '\033[1;31mError:\033[0m Unknown option! Try again.' From 54a6e1e7753f96942428df39f7e98e12a4ca231a Mon Sep 17 00:00:00 2001 From: emerichunter Date: Fri, 13 Aug 2021 11:30:52 +0200 Subject: [PATCH 2/3] Lots of new queries Most are taken from maitenance_schema. But it's not always possible to create a foreign extension. - duplicate Indexes - duplicate FKs - unused tables - useless columns (same value in all the table: NULL, blank, or TRUE/FALSE/1/a timestamp...) - alert on wrap-around - unindexed foreign keys - empty tables - useless unique constraints on foreign keys - tables with no PK - tables of more than 500 tuples without index or PK - complete report in html format for easier reading pg_stat_statements new queries (Top 5 only for effectiveness and concise output fore readability) - queries creating the most IOs (needs track_io_timing=on) - most time consuming queries overall - most time consuming in one call - most severe response jitter (statistics issue) - most memory consuming - most temp files - most called query - complete report for all these queries in html format for readability The html format is for reporting. There might be a way to make dynamic. Like start.psql. Did not dive into it yet. --- sql/d1_duplicate_fks.sql | 25 ++++++++++ sql/d2_duplicate_idxs.sql | 16 ++++++ sql/e2_empty_tables.sql | 9 ++++ sql/m1_missing_pks.sql | 12 +++++ sql/n1_noidx_nopk.sql | 6 +++ sql/re_complete_report.sql | 59 +++++++++++++++++++++++ sql/sc_pg_stat_statements_most_called.sql | 7 +++ sql/si_pg_stat_statements_io.sql | 7 +++ sql/sj_pg_stat_statements_jitter.sql | 7 +++ sql/sm_pg_stat_statements_time_total.sql | 7 +++ sql/so_pg_stat_statements_time1call.sql | 7 +++ sql/sr_pg_stat_statements_most_memory.sql | 7 +++ sql/ss_pg_stat_statements_full_report.sql | 18 +++++++ sql/st_pg_stat_statements_temp_files.sql | 7 +++ sql/t2_single_columns.sql | 11 +++++ sql/u1_unlogged_tables.sql | 12 +++++ sql/u2_useless_unique_fk.sql | 17 +++++++ sql/u3_useless_columns.sql | 22 +++++++++ sql/u4_unused_tables.sql | 6 +++ sql/w1_wraparound_alert.sql | 37 ++++++++++++++ 20 files changed, 299 insertions(+) create mode 100644 sql/d1_duplicate_fks.sql create mode 100644 sql/d2_duplicate_idxs.sql create mode 100644 sql/e2_empty_tables.sql create mode 100644 sql/m1_missing_pks.sql create mode 100644 sql/n1_noidx_nopk.sql create mode 100644 sql/re_complete_report.sql create mode 100644 sql/sc_pg_stat_statements_most_called.sql create mode 100644 sql/si_pg_stat_statements_io.sql create mode 100644 sql/sj_pg_stat_statements_jitter.sql create mode 100644 sql/sm_pg_stat_statements_time_total.sql create mode 100644 sql/so_pg_stat_statements_time1call.sql create mode 100644 sql/sr_pg_stat_statements_most_memory.sql create mode 100644 sql/ss_pg_stat_statements_full_report.sql create mode 100644 sql/st_pg_stat_statements_temp_files.sql create mode 100644 sql/t2_single_columns.sql create mode 100644 sql/u1_unlogged_tables.sql create mode 100644 sql/u2_useless_unique_fk.sql create mode 100644 sql/u3_useless_columns.sql create mode 100644 sql/u4_unused_tables.sql create mode 100644 sql/w1_wraparound_alert.sql diff --git a/sql/d1_duplicate_fks.sql b/sql/d1_duplicate_fks.sql new file mode 100644 index 0000000..b93bf56 --- /dev/null +++ b/sql/d1_duplicate_fks.sql @@ -0,0 +1,25 @@ +--Duplicate foreign keys +SELECT + array_agg(pc.conname) as duplicated_constraints, + pclsc.relname as child_table, + pac.attname as child_column, + pclsp.relname as parent_table, + pap.attname as parent_column, + nspname as schema_name +FROM + ( + SELECT + connamespace,conname, unnest(conkey) as "conkey", unnest(confkey) + as "confkey" , conrelid, confrelid, contype + FROM + pg_constraint + ) pc + JOIN pg_namespace pn ON pc.connamespace = pn.oid + JOIN pg_class pclsc ON pc.conrelid = pclsc.oid + JOIN pg_class pclsp ON pc.confrelid = pclsp.oid + JOIN pg_attribute pac ON pc.conkey = pac.attnum and pac.attrelid = pclsc.oid + JOIN pg_attribute pap ON pc.confkey = pap.attnum and pap.attrelid = pclsp.oid +GROUP BY child_table, child_column, parent_table, parent_column, schema_name HAVING COUNT(*)>0 +ORDER BY child_table, child_column ; + + diff --git a/sql/d2_duplicate_idxs.sql b/sql/d2_duplicate_idxs.sql new file mode 100644 index 0000000..5dde184 --- /dev/null +++ b/sql/d2_duplicate_idxs.sql @@ -0,0 +1,16 @@ +--Duplicate indexes +SELECT c.relname as tbl_w_dup_idx, + pg_size_pretty(SUM(pg_relation_size(idx))::BIGINT) AS SIZE, + (array_agg(idx))[1] AS idx1, (array_agg(idx))[2] AS idx2, + (array_agg(idx))[3] AS idx3, (array_agg(idx))[4] AS idx4 +FROM ( + SELECT + indrelid, + indexrelid::regclass AS idx, + (indrelid::text ||E'\n'|| indclass::text ||E'\n'|| indkey::text ||E'\n'|| + COALESCE(indexprs::text,'')||E'\n' || COALESCE(indpred::text,'')) AS KEY + FROM pg_index) sub +JOIN pg_class c ON sub.indrelid=c.oid +GROUP BY KEY, c.relname HAVING COUNT(*)>1 +ORDER BY SUM(pg_relation_size(idx)) DESC; + diff --git a/sql/e2_empty_tables.sql b/sql/e2_empty_tables.sql new file mode 100644 index 0000000..4f19c82 --- /dev/null +++ b/sql/e2_empty_tables.sql @@ -0,0 +1,9 @@ +--Empty tables +SELECT + schemaname, + relname as empty_table +FROM + pg_stat_user_tables +WHERE + n_live_tup = 0; + diff --git a/sql/m1_missing_pks.sql b/sql/m1_missing_pks.sql new file mode 100644 index 0000000..9c90bd5 --- /dev/null +++ b/sql/m1_missing_pks.sql @@ -0,0 +1,12 @@ +--Table(s) missing pk +select + tbl.table_schema, + tbl.table_name as tblname_pk_missing +from information_schema.tables tbl +where table_type = 'BASE TABLE' + and table_schema not in ('pg_catalog', 'information_schema') + and not exists (select 1 + from information_schema.key_column_usage kcu + where kcu.table_name = tbl.table_name + and kcu.table_schema = tbl.table_schema) +; diff --git a/sql/n1_noidx_nopk.sql b/sql/n1_noidx_nopk.sql new file mode 100644 index 0000000..e7ff706 --- /dev/null +++ b/sql/n1_noidx_nopk.sql @@ -0,0 +1,6 @@ +--Tables with neither pk nor any index + SELECT relid, schemaname, relname as tbl_wo_idx, n_live_tup +from pg_stat_user_tables +where relname NOT IN (select relname from pg_stat_user_indexes ) +AND schemaname NOT IN ('information_schema','pg_catalog'); + diff --git a/sql/re_complete_report.sql b/sql/re_complete_report.sql new file mode 100644 index 0000000..6a71bd0 --- /dev/null +++ b/sql/re_complete_report.sql @@ -0,0 +1,59 @@ +--Complete report of a to z omitting b3, b4, p1, v1, v2 and pg_stat_statements steps +\H +\o full_report.html +\C 'NODE INFO' +\ir ./0_node.sql +\C 'DATABASES INFO' +\ir ./1_databases.sql +\C 'TABLES INFO' +\ir ./2_table_sizes.sql +\C 'PROFILES INFO' +\ir ./3_load_profiles.sql +\C 'ACTIVITY' +\ir ./a1_activity.sql +\C 'TABLE BLOAT' +\ir ./b1_table_estimation.sql +\C 'INDEX BLOAT' +\ir ./b2_btree_estimation.sql +\C 'TABLES WITH NO STATS' +\ir ./b5_tables_no_stats.sql +\C 'DUPLICATE FOREIGN KEYS' +\ir ./d1_duplicate_fks.sql +\C 'DUPLICATE INDEXES' +\ir ./d2_duplicate_idxs.sql +\C 'EXTENSIONS' +\ir ./e1_extensions.sql +\C 'EMPTY TABLES' +\ir ./e2_empty_tables.sql +\C 'RARE OR UNUSED INDEXES' +\ir ./i1_rare_indexes.sql +\C 'REDUNDANT INDEXES' +\ir ./i2_redundant_indexes.sql +\C 'UNINDEXED FKs' +\ir ./i3_non_indexed_fks.sql +\C 'INVALID INDEXES' +\ir ./i4_invalid_indexes.sql +\C 'INDEXES MIGRATION' +\ir ./i5_indexes_migration.sql +\C 'LOCKS' +\ir ./l1_lock_trees.sql +\C 'MISSING PRIMARY KEYS' +\ir ./m1_missing_pks.sql +\C 'TABLES WITH NO INDEX OR PK' +\ir ./n1_noidx_nopk.sql +-- \i s1_pg_stat_statements_top_total.sql +-- \i s2_pg_stat_statements_report.sql +-- \i t1_tuning.sql +\C 'TABLES WITH A SINGLE COLUMN' +\ir ./t2_single_columns.sql +\C 'UNLOGGED TABLES - not safe for transactions' +\ir ./u1_unlogged_tables.sql +\C 'USELESS UNIQUE OR FOREIGN KEY CONSTRAINTS' +\ir ./u2_useless_unique_fk.sql +\C 'USELESS COLUMNS' +\ir ./u3_useless_columns.sql +\C 'UNUSED TABLES' +\ir ./u4_unused_tables.sql +\C 'WRAPAROUND ALERT (more than 85% freeze_max_age)' +\ir ./w1_wraparound_alert.sql + diff --git a/sql/sc_pg_stat_statements_most_called.sql b/sql/sc_pg_stat_statements_most_called.sql new file mode 100644 index 0000000..86dd880 --- /dev/null +++ b/sql/sc_pg_stat_statements_most_called.sql @@ -0,0 +1,7 @@ +--Top 5 SQL statements which consume the most time in total and have the most calls. + + select userid::regrole, datname, query, total_time, calls + from pg_stat_statements pgss + join pg_database pgd ON pgd.oid = pgss.dbid + order by total_time desc,calls desc limit 5; + diff --git a/sql/si_pg_stat_statements_io.sql b/sql/si_pg_stat_statements_io.sql new file mode 100644 index 0000000..0b5cdeb --- /dev/null +++ b/sql/si_pg_stat_statements_io.sql @@ -0,0 +1,7 @@ +--Top 5 SQL statements which consume the most I/O resources in total. + + select userid::regrole, datname, (blk_read_time+blk_write_time) as total_ios, query + from pg_stat_statements pgss + join pg_database pgd ON pgd.oid = pgss.dbid + order by (blk_read_time+blk_write_time) desc limit 5; + diff --git a/sql/sj_pg_stat_statements_jitter.sql b/sql/sj_pg_stat_statements_jitter.sql new file mode 100644 index 0000000..0364d03 --- /dev/null +++ b/sql/sj_pg_stat_statements_jitter.sql @@ -0,0 +1,7 @@ +--Top 5 SQL statements with the most severe response jitter. + + select userid::regrole, datname, stddev_time as jitter, query + from pg_stat_statements pgss + join pg_database pgd ON pgd.oid = pgss.dbid + order by stddev_time desc limit 5; + diff --git a/sql/sm_pg_stat_statements_time_total.sql b/sql/sm_pg_stat_statements_time_total.sql new file mode 100644 index 0000000..0b83390 --- /dev/null +++ b/sql/sm_pg_stat_statements_time_total.sql @@ -0,0 +1,7 @@ +--Top 5 SQL statements which consume the most time in total. + + select userid::regrole, datname, total_time, query + from pg_stat_statements pgss + join pg_database pgd ON pgd.oid = pgss.dbid + order by total_time desc limit 5; + diff --git a/sql/so_pg_stat_statements_time1call.sql b/sql/so_pg_stat_statements_time1call.sql new file mode 100644 index 0000000..9ac4d95 --- /dev/null +++ b/sql/so_pg_stat_statements_time1call.sql @@ -0,0 +1,7 @@ +--Top 5 SQL statements which consume the most time in one call. + + select userid::regrole, datname, mean_time, query + from pg_stat_statements pgss + join pg_database pgd ON pgd.oid = pgss.dbid + order by mean_time desc limit 5; + diff --git a/sql/sr_pg_stat_statements_most_memory.sql b/sql/sr_pg_stat_statements_most_memory.sql new file mode 100644 index 0000000..0d07c37 --- /dev/null +++ b/sql/sr_pg_stat_statements_most_memory.sql @@ -0,0 +1,7 @@ +--Top 5 SQL statements which consume the most shared memory resources. + + select userid::regrole, datname, pg_size_pretty((shared_blks_hit+shared_blks_dirtied)*8) as memory_usage, query + from pg_stat_statements pgss + join pg_database pgd ON pgd.oid = pgss.dbid + order by (shared_blks_hit+shared_blks_dirtied) desc limit 5; + diff --git a/sql/ss_pg_stat_statements_full_report.sql b/sql/ss_pg_stat_statements_full_report.sql new file mode 100644 index 0000000..93aa036 --- /dev/null +++ b/sql/ss_pg_stat_statements_full_report.sql @@ -0,0 +1,18 @@ +--Top5 Report with si, sm, so, sc, st, sj, sr (requires pg_stat_statements + track_io_timing=on) +\H +\o full_report_pg_stat_statements.html +\C 'MOST CALLED QUERIES' +\ir ./sc_pg_stat_statements_most_called.sql +\C 'MOST IOs QUERIES' +\ir ./si_pg_stat_statements_io.sql +\C 'MOST JITTER QUERIES' +\ir ./sj_pg_stat_statements_jitter.sql +\C 'MOST TIME IN TOTAL QUERIES' +\ir ./sm_pg_stat_statements_time_total.sql +\C 'MOST TIME IN 1 CALL QUERIES' +\ir ./so_pg_stat_statements_time1call.sql +\C 'MOST SHARED BUFFERS QUERIES' +\ir ./sr_pg_stat_statements_most_memory.sql +\C 'MOST TEMP FILES QUERIES' +\ir ./st_pg_stat_statements_temp_files.sql + diff --git a/sql/st_pg_stat_statements_temp_files.sql b/sql/st_pg_stat_statements_temp_files.sql new file mode 100644 index 0000000..d792add --- /dev/null +++ b/sql/st_pg_stat_statements_temp_files.sql @@ -0,0 +1,7 @@ +--Top 5 SQL statements which consume the most temporary space. + + select userid::regrole, datname, temp_blks_written, pg_size_pretty(temp_blks_written*8) as temp_space_used, query + from pg_stat_statements pgss + join pg_database pgd ON pgd.oid = pgss.dbid + order by temp_blks_written desc limit 5; + diff --git a/sql/t2_single_columns.sql b/sql/t2_single_columns.sql new file mode 100644 index 0000000..fb7596a --- /dev/null +++ b/sql/t2_single_columns.sql @@ -0,0 +1,11 @@ +--Tables with a single column (might need a more detailed column if PK, if nonPK relation why bother?) +SELECT + table_catalog, + table_schema, + table_name as table_single_column, + count(column_name) +FROM information_schema.columns +WHERE table_schema NOT IN ('information_schema', 'maintenance_schema') +GROUP BY table_catalog,table_schema,table_name +HAVING COUNT (column_name)= 1 ; + diff --git a/sql/u1_unlogged_tables.sql b/sql/u1_unlogged_tables.sql new file mode 100644 index 0000000..b8be248 --- /dev/null +++ b/sql/u1_unlogged_tables.sql @@ -0,0 +1,12 @@ +--Unlogged tables (not crash safe, not replicated, no PITR) +SELECT + relname as unlogged_object, + CASE + WHEN relkind = 'r' THEN 'table' + WHEN relkind = 'i' THEN 'index' + WHEN relkind = 't' THEN 'toast table' + END relation_kind, +pg_size_pretty(relpages::bigint*8*1024) as relation_size +FROM pg_class +WHERE relpersistence = 'u'; + diff --git a/sql/u2_useless_unique_fk.sql b/sql/u2_useless_unique_fk.sql new file mode 100644 index 0000000..a5b9553 --- /dev/null +++ b/sql/u2_useless_unique_fk.sql @@ -0,0 +1,17 @@ +--Useless unique constraints on FK or PK +SELECT + pgc1.conrelid, pgcl.relname, pgc1.conname, pgc1.contype + FROM pg_constraint pgc1 +FULL JOIN + pg_constraint pgc2 + ON pgc1.conrelid = pgc2.conrelid +JOIN + pg_class pgcl + ON pgcl.oid=pgc1.conrelid + +WHERE pgc1.conkey = pgc2.conkey + AND pgc1.contype ='u' + +GROUP BY pgc1.conrelid, pgcl.relname, pgc1.conname, pgc1.contype +HAVING count(pgc1.conname) >1; + diff --git a/sql/u3_useless_columns.sql b/sql/u3_useless_columns.sql new file mode 100644 index 0000000..d689efb --- /dev/null +++ b/sql/u3_useless_columns.sql @@ -0,0 +1,22 @@ +--Useless columns that have no more than 1 value + +SELECT + nspname as schema_name, + relname as table_name, + attname as useless_column_name, + typname as data_type, + (stanullfrac*100)::INT AS null_percent, + CASE WHEN stadistinct >= 0 THEN stadistinct ELSE abs(stadistinct)*reltuples END AS "distinct", + CASE 1 WHEN stakind1 THEN array_to_string(stavalues1, ',', '*') WHEN stakind2 THEN array_to_string(stavalues2, ',', '*') END AS "values" +FROM pg_class c +JOIN pg_namespace ns ON (ns.oid=relnamespace) +JOIN pg_attribute ON (c.oid=attrelid) +JOIN pg_type t ON (t.oid=atttypid) +JOIN pg_statistic ON (c.oid=starelid AND staattnum=attnum) +WHERE nspname NOT LIKE E'pg\\_%' AND nspname != 'information_schema' + AND relkind='r' AND NOT attisdropped AND attstattarget != 0 + AND reltuples >= 100 -- ignore tables with fewer than 100 rows + AND stadistinct BETWEEN 0 AND 1 -- 0 to 1 distinct values +ORDER BY nspname, relname, attname +; + diff --git a/sql/u4_unused_tables.sql b/sql/u4_unused_tables.sql new file mode 100644 index 0000000..3438831 --- /dev/null +++ b/sql/u4_unused_tables.sql @@ -0,0 +1,6 @@ +--Unused tables + +SELECT schemaname, relname as unused_table +FROM pg_stat_user_tables +WHERE (idx_tup_fetch + seq_tup_read)= 0; -- tables where no tuple is read either from seqscan or idx + diff --git a/sql/w1_wraparound_alert.sql b/sql/w1_wraparound_alert.sql new file mode 100644 index 0000000..754540d --- /dev/null +++ b/sql/w1_wraparound_alert.sql @@ -0,0 +1,37 @@ +--Wrap-around approaching: when age is above 85% of freeze_max_age + + +-- from gsmith + +SELECT + nspname as schema_name, + CASE WHEN relkind='t' THEN toastname ELSE relname END AS relation_fxid_approach, + CASE WHEN relkind='t' THEN 'Toast' ELSE 'Table' END AS kind, + pg_size_pretty(pg_relation_size(oid)) as table_sz, + pg_size_pretty(pg_total_relation_size(oid)) as total_sz, + age(relfrozenxid), + last_vacuum +FROM +(SELECT + c.oid, + c.relkind, + N.nspname, + C.relname, + T.relname AS toastname, + C.relfrozenxid, + date_trunc('day',greatest(pg_stat_get_last_vacuum_time(C.oid),pg_stat_get_last_autovacuum_time(C.oid)))::date AS last_vacuum, + setting::integer as freeze_max_age + FROM pg_class C + LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace) + LEFT OUTER JOIN pg_class T ON (C.oid=T.reltoastrelid), + pg_settings + WHERE C.relkind IN ('r', 't') +-- We want toast items to appear in the wraparound list + AND N.nspname NOT IN ('pg_catalog', 'information_schema') AND + name='autovacuum_freeze_max_age' + AND pg_relation_size(c.oid)>0 +) AS av +WHERE age(relfrozenxid) > (0.85 * freeze_max_age) +ORDER BY age(relfrozenxid) DESC, pg_total_relation_size(oid) DESC +; + From 8fa4a1160e1797cf22f2c5bf21b929c94535d418 Mon Sep 17 00:00:00 2001 From: emerichunter Date: Tue, 17 Aug 2021 12:34:08 +0200 Subject: [PATCH 3/3] show only duplicates: easier to read --- sql/d1_duplicate_fks.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql/d1_duplicate_fks.sql b/sql/d1_duplicate_fks.sql index b93bf56..24a80f2 100644 --- a/sql/d1_duplicate_fks.sql +++ b/sql/d1_duplicate_fks.sql @@ -19,7 +19,7 @@ FROM JOIN pg_class pclsp ON pc.confrelid = pclsp.oid JOIN pg_attribute pac ON pc.conkey = pac.attnum and pac.attrelid = pclsc.oid JOIN pg_attribute pap ON pc.confkey = pap.attnum and pap.attrelid = pclsp.oid -GROUP BY child_table, child_column, parent_table, parent_column, schema_name HAVING COUNT(*)>0 +GROUP BY child_table, child_column, parent_table, parent_column, schema_name HAVING COUNT(*)>1 ORDER BY child_table, child_column ;