Skip to content

More queries #52

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Open
wants to merge 3 commits into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
25 changes: 25 additions & 0 deletions sql/d1_duplicate_fks.sql
Original file line number Diff line number Diff line change
@@ -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(*)>1
ORDER BY child_table, child_column ;


16 changes: 16 additions & 0 deletions sql/d2_duplicate_idxs.sql
Original file line number Diff line number Diff line change
@@ -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;

9 changes: 9 additions & 0 deletions sql/e2_empty_tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
--Empty tables
SELECT
schemaname,
relname as empty_table
FROM
pg_stat_user_tables
WHERE
n_live_tup = 0;

12 changes: 12 additions & 0 deletions sql/m1_missing_pks.sql
Original file line number Diff line number Diff line change
@@ -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)
;
6 changes: 6 additions & 0 deletions sql/n1_noidx_nopk.sql
Original file line number Diff line number Diff line change
@@ -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');

59 changes: 59 additions & 0 deletions sql/re_complete_report.sql
Original file line number Diff line number Diff line change
@@ -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

7 changes: 7 additions & 0 deletions sql/sc_pg_stat_statements_most_called.sql
Original file line number Diff line number Diff line change
@@ -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;

7 changes: 7 additions & 0 deletions sql/si_pg_stat_statements_io.sql
Original file line number Diff line number Diff line change
@@ -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;

7 changes: 7 additions & 0 deletions sql/sj_pg_stat_statements_jitter.sql
Original file line number Diff line number Diff line change
@@ -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;

7 changes: 7 additions & 0 deletions sql/sm_pg_stat_statements_time_total.sql
Original file line number Diff line number Diff line change
@@ -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;

7 changes: 7 additions & 0 deletions sql/so_pg_stat_statements_time1call.sql
Original file line number Diff line number Diff line change
@@ -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;

7 changes: 7 additions & 0 deletions sql/sr_pg_stat_statements_most_memory.sql
Original file line number Diff line number Diff line change
@@ -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;

18 changes: 18 additions & 0 deletions sql/ss_pg_stat_statements_full_report.sql
Original file line number Diff line number Diff line change
@@ -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

7 changes: 7 additions & 0 deletions sql/st_pg_stat_statements_temp_files.sql
Original file line number Diff line number Diff line change
@@ -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;

11 changes: 11 additions & 0 deletions sql/t2_single_columns.sql
Original file line number Diff line number Diff line change
@@ -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 ;

12 changes: 12 additions & 0 deletions sql/u1_unlogged_tables.sql
Original file line number Diff line number Diff line change
@@ -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';

17 changes: 17 additions & 0 deletions sql/u2_useless_unique_fk.sql
Original file line number Diff line number Diff line change
@@ -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;

22 changes: 22 additions & 0 deletions sql/u3_useless_columns.sql
Original file line number Diff line number Diff line change
@@ -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
;

6 changes: 6 additions & 0 deletions sql/u4_unused_tables.sql
Original file line number Diff line number Diff line change
@@ -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

37 changes: 37 additions & 0 deletions sql/w1_wraparound_alert.sql
Original file line number Diff line number Diff line change
@@ -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
;

Loading