Browse Source

change column name

change_column_names
Test User 4 years ago
parent
commit
5b961695d2
  1. 3
      sql/check_strange_fk.sql
  2. 55
      sql/check_uniq_indexes.sql
  3. 10
      sql/dirty_to_read_stat.sql
  4. 5
      sql/index_bloat.sql
  5. 4
      sql/index_candidates_from_ssd.sql
  6. 4
      sql/index_candidates_to_ssd.sql
  7. 9
      sql/index_disk_activity.sql
  8. 5
      sql/indexes_with_nulls.sql
  9. 7
      sql/low_used_indexes.sql
  10. 20
      sql/query_stat_counts.sql
  11. 28
      sql/query_stat_cpu_time.sql
  12. 30
      sql/query_stat_io_time.sql
  13. 30
      sql/query_stat_time.sql
  14. 4
      sql/redundant_indexes.sql
  15. 3
      sql/seq_scan_tables.sql
  16. 7
      sql/table_bloat.sql
  17. 7
      sql/table_bloat_approx.sql
  18. 8
      sql/table_candidates_from_ssd.sql
  19. 10
      sql/table_candidates_to_ssd.sql
  20. 6
      sql/table_index_write_activity.sql
  21. 6
      sql/table_write_activity.sql

3
sql/check_strange_fk.sql

@ -1,3 +1,2 @@ @@ -1,3 +1,2 @@
select pc1.oid::regclass||'.'||pa1.attname, pt1.typname, pc2.relname||'.'||pa2.attname, pt2.typname from pg_constraint pco join pg_class pc1 on pc1.oid=conrelid join pg_class pc2 on pc2.oid=confrelid join pg_attribute pa1 on pa1.attnum=conkey[1] and pa1.attrelid=conrelid join pg_attribute pa2 on pa2.attnum=confkey[1] and pa2.attrelid=confrelid join pg_type pt1 on pt1.oid=pa1.atttypid join pg_type pt2 on pt2.oid=pa2.atttypid where pa1.atttypid<>pa2.atttypid and contype='f' order by 1,2;
select pc1.oid::regclass||'.'||pa1.attname as "table_column1", pt1.typname, pc2.relname||'.'||pa2.attname as "table_column2", pt2.typname from pg_constraint pco join pg_class pc1 on pc1.oid=conrelid join pg_class pc2 on pc2.oid=confrelid join pg_attribute pa1 on pa1.attnum=conkey[1] and pa1.attrelid=conrelid join pg_attribute pa2 on pa2.attnum=confkey[1] and pa2.attrelid=confrelid join pg_type pt1 on pt1.oid=pa1.atttypid join pg_type pt2 on pt2.oid=pa2.atttypid where pa1.atttypid<>pa2.atttypid and contype='f' order by 1,2;

55
sql/check_uniq_indexes.sql

@ -1,32 +1,31 @@ @@ -1,32 +1,31 @@
SELECT
n.nspname ||'.'||c.relname AS table
FROM pg_catalog.pg_class c
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE
c.relkind = 'r'::"char"
AND
n.nspname NOT LIKE 'pg_%' AND n.nspname<>'_slony' AND n.nspname<>'information_schema'
AND
NOT EXISTS (
SELECT
n.nspname AS schema,
c.relname AS relname
FROM pg_catalog.pg_class c
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
pg_catalog.pg_index.indexrelid
FROM pg_catalog.pg_index
WHERE
c.relkind = 'r'::"char"
AND
n.nspname NOT LIKE 'pg_%' AND n.nspname<>'_slony' AND n.nspname<>'information_schema'
AND
NOT EXISTS (
SELECT
pg_catalog.pg_index.indexrelid
FROM pg_catalog.pg_index
WHERE
pg_catalog.pg_index.indrelid=c.oid
pg_catalog.pg_index.indrelid=c.oid
AND
pg_catalog.pg_index.indisunique='t'
AND
NOT EXISTS (
SELECT
i_attr.attname
FROM pg_catalog.pg_attribute t_attr
JOIN pg_catalog.pg_attribute i_attr ON i_attr.attname=t_attr.attname AND i_attr.attrelid = pg_catalog.pg_index.indexrelid
WHERE
t_attr.attrelid = c.oid
AND
pg_catalog.pg_index.indisunique='t'
AND
NOT EXISTS (
SELECT
i_attr.attname
FROM pg_catalog.pg_attribute t_attr
JOIN pg_catalog.pg_attribute i_attr ON i_attr.attname=t_attr.attname AND i_attr.attrelid = pg_catalog.pg_index.indexrelid
WHERE
t_attr.attrelid = c.oid
AND
t_attr.attnotnull <> 't'
)
)
ORDER BY 1,2
t_attr.attnotnull <> 't'
)
)
ORDER BY 1,2

10
sql/dirty_to_read_stat.sql

@ -1,10 +1,9 @@ @@ -1,10 +1,9 @@
WITH
buffer_data AS (
SELECT
relfilenode,
sum(case when isdirty then 1 else 0 end) as dirty_pages,
round(100.0 * sum(case when isdirty then 1 else 0 end) / count(*), 1) as "%_dirty",
round(100.0 * sum(case when isdirty then 1 else 0 end) / count(*), 1) as "dirty_%",
count(*) as cached_pages
FROM public.pg_buffercache GROUP BY 1
)
@ -14,10 +13,10 @@ SELECT @@ -14,10 +13,10 @@ SELECT
c.relkind,
t.spcname AS tblsp,
pg_size_pretty(pg_relation_size(c.oid)) AS relsize,
round(buffer_data.cached_pages::numeric*100*8192/pg_relation_size(c.oid), 1) as "%_cached",
round(buffer_data.cached_pages::numeric*100*8192/pg_relation_size(c.oid), 1) as "cached_%",
pg_size_pretty(8192*(pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid))) AS disk_read,
pg_size_pretty(buffer_data.dirty_pages*8192) as dirty_size,
buffer_data."%_dirty",
buffer_data."dirty_%",
round((pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid))::numeric/buffer_data.dirty_pages, 1) as read_to_dirty_ratio
FROM pg_class c
LEFT JOIN buffer_data ON buffer_data.relfilenode = c.relfilenode
@ -25,5 +24,4 @@ LEFT JOIN pg_namespace n ON n.oid = c.relnamespace @@ -25,5 +24,4 @@ LEFT JOIN pg_namespace n ON n.oid = c.relnamespace
LEFT JOIN pg_tablespace t ON t.oid=c.reltablespace
WHERE
dirty_pages>0
ORDER BY dirty_pages desc LIMIT 60;
ORDER BY dirty_pages desc LIMIT 60;

5
sql/index_bloat.sql

@ -3,13 +3,12 @@ @@ -3,13 +3,12 @@
with indexes as (
select * from pg_stat_user_indexes
)
select schemaname,
table_name,
select schemaname||'.'||table_name as table,
pg_size_pretty(table_size) as table_size,
index_name,
pg_size_pretty(index_size) as index_size,
idx_scan as index_scans,
round((free_space*100/index_size)::numeric, 1) as waste_percent,
round((free_space*100/index_size)::numeric, 1) as "waste_%",
pg_size_pretty(free_space) as waste
from (
select schemaname, p.relname as table_name, indexrelname as index_name,

4
sql/index_candidates_from_ssd.sql

@ -1,7 +1,6 @@ @@ -1,7 +1,6 @@
SELECT * FROM (
SELECT
(n.nspname||'.'||c.relname)::varchar(30) AS "table",
(n.nspname||'.'||c.relname)::varchar(40) AS "table",
i.relname AS "index",
t.spcname AS tblsp,
pg_size_pretty(pg_relation_size(i.oid)) AS size,
@ -22,4 +21,3 @@ WHERE c.relkind = 'r' @@ -22,4 +21,3 @@ WHERE c.relkind = 'r'
WHERE d_w_rat<25
AND tblsp='ssd'
ORDER BY disk DESC NULLS LAST;

4
sql/index_candidates_to_ssd.sql

@ -1,7 +1,6 @@ @@ -1,7 +1,6 @@
SELECT * FROM (
SELECT
(n.nspname||'.'||c.relname)::varchar(30) AS "table",
(n.nspname||'.'||c.relname)::varchar(40) AS "table",
i.relname AS "index",
t.spcname AS tblsp,
pg_size_pretty(pg_relation_size(i.oid)) AS size,
@ -23,4 +22,3 @@ WHERE d_w_rat>10 @@ -23,4 +22,3 @@ WHERE d_w_rat>10
AND (tblsp is NULL OR tblsp<>'ssd')
AND disk>1000
ORDER BY disk DESC NULLS LAST;

9
sql/index_disk_activity.sql

@ -3,12 +3,12 @@ buffer_data AS ( @@ -3,12 +3,12 @@ buffer_data AS (
SELECT
relfilenode,
pg_size_pretty(sum(case when isdirty then 1 else 0 end) * 8192) as dirty,
round(100.0 * sum(case when isdirty then 1 else 0 end) / count(*), 1) as "%_dirty"
round(100.0 * sum(case when isdirty then 1 else 0 end) / count(*), 1) as "dirty_%"
FROM public.pg_buffercache GROUP BY 1
)
SELECT
(n.nspname||'.'||c.relname)::varchar(30) AS "table",
(n.nspname||'.'||c.relname)::varchar(40) AS "table",
i.relname AS "index",
coalesce(t.spcname, (select spcname from pg_tablespace where oid=(select dattablespace from pg_database where datname=current_database()))) AS tblsp,
pg_size_pretty(pg_relation_size(i.oid)) AS size,
@ -19,7 +19,7 @@ SELECT @@ -19,7 +19,7 @@ SELECT
pg_stat_get_numscans(i.oid) AS idx_scan,
-- pg_stat_get_tuples_returned(i.oid) AS idx_tup_read,
buffer_data.dirty,
buffer_data."%_dirty"
buffer_data."dirty_%"
FROM pg_class c
JOIN pg_index x ON c.oid = x.indrelid
JOIN pg_class i ON i.oid = x.indexrelid
@ -31,6 +31,3 @@ WHERE c.relkind = 'r' @@ -31,6 +31,3 @@ WHERE c.relkind = 'r'
AND (t.spcname IS DISTINCT FROM 'pg_global') and (n.nspname IS DISTINCT FROM 'pg_catalog')
AND pg_stat_get_blocks_fetched(i.oid) - pg_stat_get_blocks_hit(i.oid)>100
ORDER BY disk DESC NULLS LAST, idx_scan DESC LIMIT 50;

5
sql/indexes_with_nulls.sql

@ -1,5 +1,3 @@ @@ -1,5 +1,3 @@
select
pg_index.indrelid::regclass as table,
pg_index.indexrelid::regclass as index,
@ -11,7 +9,6 @@ from pg_index @@ -11,7 +9,6 @@ from pg_index
join pg_attribute ON pg_attribute.attrelid=pg_index.indrelid AND pg_attribute.attnum=ANY(pg_index.indkey)
join pg_statistic ON pg_statistic.starelid=pg_index.indrelid AND pg_statistic.staattnum=pg_attribute.attnum
where pg_statistic.stanullfrac>0.5 AND pg_relation_size(pg_index.indexrelid)>10*8192
order by pg_relation_size(pg_index.indexrelid) desc,1,2,3
;
order by pg_relation_size(pg_index.indexrelid) desc,1,2,3;

7
sql/low_used_indexes.sql

@ -1,6 +1,5 @@ @@ -1,6 +1,5 @@
SELECT pg_stat_user_indexes.schemaname || '.' || pg_stat_user_indexes.relname tablemane
, pg_stat_user_indexes.indexrelname
SELECT pg_stat_user_indexes.schemaname || '.' || pg_stat_user_indexes.relname as table
, pg_stat_user_indexes.indexrelname as index
, pg_stat_user_indexes.idx_scan
, psut.write_activity
, psut.seq_scan
@ -25,4 +24,4 @@ SELECT pg_stat_user_indexes.schemaname || '.' || pg_stat_user_indexes.relname ta @@ -25,4 +24,4 @@ SELECT pg_stat_user_indexes.schemaname || '.' || pg_stat_user_indexes.relname ta
where pg_index.indisunique is false
and pg_stat_user_indexes.idx_scan::float / (psut.write_activity + 1)::float < 0.01
and psut.write_activity > case when pg_is_in_recovery () then -1 else 10000 end
order by 4 desc, 1, 2
order by 4 desc, 1, 2;

20
sql/query_stat_counts.sql

@ -1,14 +1,13 @@ @@ -1,14 +1,13 @@
with s AS
(SELECT sum(total_time) AS t,sum(calls) AS s,sum(rows) as r FROM pg_stat_statements WHERE dbid=(SELECT oid from pg_database where datname=current_database()))
SELECT
(100*total_time/(SELECT t FROM s))::numeric(20,2) AS time_percent,
(100*total_time/(SELECT t FROM s))::numeric(20,2) AS "time_%",
total_time::numeric(20,2) as total_time,
(total_time*1000/calls)::numeric(10,3) AS avg_time,
calls,
(100*calls/(SELECT s FROM s))::numeric(20,2) AS calls_percent,
(100*calls/(SELECT s FROM s))::numeric(20,2) AS "calls_%",
rows,
(100*rows/(SELECT r from s))::numeric(20,2) AS row_percent,
(100*rows/(SELECT r from s))::numeric(20,2) AS "row_%",
query
FROM pg_stat_statements
WHERE
@ -18,18 +17,17 @@ AND dbid=(SELECT oid from pg_database where datname=current_database()) @@ -18,18 +17,17 @@ AND dbid=(SELECT oid from pg_database where datname=current_database())
UNION all
SELECT
(100*sum(total_time)/(SELECT t FROM s))::numeric(20,2) AS time_percent,
(100*sum(total_time)/(SELECT t FROM s))::numeric(20,2),
sum(total_time)::numeric(20,2),
(sum(total_time)*1000/sum(calls))::numeric(10,3) AS avg_time,
(sum(total_time)*1000/sum(calls))::numeric(10,3),
sum(calls),
(100*sum(calls)/(SELECT s FROM s))::numeric(20,2) AS calls_percent,
(100*sum(calls)/(SELECT s FROM s))::numeric(20,2),
sum(rows),
(100*sum(rows)/(SELECT r from s))::numeric(20,2) AS row_percent,
'other' AS query
(100*sum(rows)/(SELECT r from s))::numeric(20,2),
'other'
FROM pg_stat_statements
WHERE
calls/(SELECT s FROM s)<0.01
AND dbid=(SELECT oid from pg_database where datname=current_database())
ORDER BY 4 DESC;
ORDER BY 4 DESC;

28
sql/query_stat_cpu_time.sql

@ -1,4 +1,3 @@ @@ -1,4 +1,3 @@
with s AS
(SELECT sum(total_time) AS t,sum(blk_read_time+blk_write_time) as iot, sum(total_time-blk_read_time-blk_write_time) as cput, sum(calls) AS s,sum(rows) as r FROM pg_stat_statements WHERE dbid=(SELECT oid from pg_database where datname=current_database()))
,
@ -10,16 +9,16 @@ group by query @@ -10,16 +9,16 @@ group by query
)
SELECT
(100*total_time/(SELECT t FROM s))::numeric(20,2) AS time_percent,
(100*(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2) AS iotime_percent,
(100*(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2) AS cputime_percent,
(100*total_time/(SELECT t FROM s))::numeric(20,2) AS "time_%",
(100*(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2) AS "iotime_%",
(100*(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2) AS "cputime_%",
total_time::numeric(20,2) as total_time,
(total_time*1000/calls)::numeric(20,2) AS avg_time,
((blk_read_time+blk_write_time)*1000/calls)::numeric(20,2) AS avg_io_time,
calls,
(100*calls/(SELECT s FROM s))::numeric(20,2) AS calls_percent,
(100*calls/(SELECT s FROM s))::numeric(20,2) AS "calls_%",
rows,
(100*rows/(SELECT r from s))::numeric(20,2) AS row_percent,
(100*rows/(SELECT r from s))::numeric(20,2) AS "row_%",
query
FROM _pg_stat_statements
WHERE
@ -28,20 +27,19 @@ WHERE @@ -28,20 +27,19 @@ WHERE
UNION all
SELECT
(100*sum(total_time)/(SELECT t FROM s))::numeric(20,2) AS time_percent,
(100*sum(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2) AS iotime_percent,
(100*sum(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2) AS cputime_percent,
(100*sum(total_time)/(SELECT t FROM s))::numeric(20,2),
(100*sum(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2),
(100*sum(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2),
sum(total_time)::numeric(20,2),
(sum(total_time)*1000/sum(calls))::numeric(10,3) AS avg_time,
(sum(blk_read_time+blk_write_time)*1000/sum(calls))::numeric(10,3) AS avg_io_time,
(sum(total_time)*1000/sum(calls))::numeric(10,3),
(sum(blk_read_time+blk_write_time)*1000/sum(calls))::numeric(10,3),
sum(calls),
(100*sum(calls)/(SELECT s FROM s))::numeric(20,2) AS calls_percent,
(100*sum(calls)/(SELECT s FROM s))::numeric(20,2),
sum(rows),
(100*sum(rows)/(SELECT r from s))::numeric(20,2) AS row_percent,
(100*sum(rows)/(SELECT r from s))::numeric(20,2),
'other' AS query
FROM _pg_stat_statements
WHERE
(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s)<0.02
ORDER BY 3 DESC;
ORDER BY 3 DESC;

30
sql/query_stat_io_time.sql

@ -1,4 +1,3 @@ @@ -1,4 +1,3 @@
with s AS
(SELECT sum(total_time) AS t,sum(blk_read_time+blk_write_time) as iot, sum(total_time-blk_read_time-blk_write_time) as cput, sum(calls) AS s,sum(rows) as r FROM pg_stat_statements WHERE dbid=(SELECT oid from pg_database where datname=current_database()))
,
@ -10,16 +9,16 @@ group by query @@ -10,16 +9,16 @@ group by query
)
SELECT
(100*total_time/(SELECT t FROM s))::numeric(20,2) AS time_percent,
(100*(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2) AS iotime_percent,
(100*(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2) AS cputime_percent,
(100*total_time/(SELECT t FROM s))::numeric(20,2) AS "time_%",
(100*(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2) AS "iotime_%",
(100*(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2) AS "cputime_%",
total_time::numeric(20,2) as total_time,
(total_time*1000/calls)::numeric(20,2) AS avg_time,
((blk_read_time+blk_write_time)*1000/calls)::numeric(20,2) AS avg_io_time,
calls,
(100*calls/(SELECT s FROM s))::numeric(20,2) AS calls_percent,
(100*calls/(SELECT s FROM s))::numeric(20,2) AS "calls_%",
rows,
(100*rows/(SELECT r from s))::numeric(20,2) AS row_percent,
(100*rows/(SELECT r from s))::numeric(20,2) AS "row_%",
query
FROM _pg_stat_statements
WHERE
@ -28,20 +27,19 @@ WHERE @@ -28,20 +27,19 @@ WHERE
UNION all
SELECT
(100*sum(total_time)/(SELECT t FROM s))::numeric(20,2) AS time_percent,
(100*sum(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2) AS iotime_percent,
(100*sum(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2) AS cputime_percent,
(100*sum(total_time)/(SELECT t FROM s))::numeric(20,2),
(100*sum(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2),
(100*sum(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2),
sum(total_time)::numeric(20,2),
(sum(total_time)*1000/sum(calls))::numeric(10,3) AS avg_time,
(sum(blk_read_time+blk_write_time)*1000/sum(calls))::numeric(10,3) AS avg_io_time,
(sum(total_time)*1000/sum(calls))::numeric(10,3),
(sum(blk_read_time+blk_write_time)*1000/sum(calls))::numeric(10,3),
sum(calls),
(100*sum(calls)/(SELECT s FROM s))::numeric(20,2) AS calls_percent,
(100*sum(calls)/(SELECT s FROM s))::numeric(20,2),
sum(rows),
(100*sum(rows)/(SELECT r from s))::numeric(20,2) AS row_percent,
'other' AS query
(100*sum(rows)/(SELECT r from s))::numeric(20,2),
'other'
FROM _pg_stat_statements
WHERE
(blk_read_time+blk_write_time)/(SELECT iot FROM s)<0.02
ORDER BY 2 DESC;
ORDER BY 2 DESC;

30
sql/query_stat_time.sql

@ -1,4 +1,3 @@ @@ -1,4 +1,3 @@
with s AS
(SELECT sum(total_time) AS t,sum(blk_read_time+blk_write_time) as iot, sum(total_time-blk_read_time-blk_write_time) as cput, sum(calls) AS s,sum(rows) as r FROM pg_stat_statements WHERE dbid=(SELECT oid from pg_database where datname=current_database()))
,
@ -10,16 +9,16 @@ group by query @@ -10,16 +9,16 @@ group by query
)
SELECT
(100*total_time/(SELECT t FROM s))::numeric(20,2) AS time_percent,
(100*(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2) AS iotime_percent,
(100*(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2) AS cputime_percent,
(100*total_time/(SELECT t FROM s))::numeric(20,2) AS "time_%",
(100*(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2) AS "iotime_%",
(100*(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2) AS "cputime_%",
total_time::numeric(20,2) as total_time,
(total_time*1000/calls)::numeric(20,2) AS avg_time,
((blk_read_time+blk_write_time)*1000/calls)::numeric(20,2) AS avg_io_time,
calls,
(100*calls/(SELECT s FROM s))::numeric(20,2) AS calls_percent,
(100*calls/(SELECT s FROM s))::numeric(20,2) AS "calls_%",
rows,
(100*rows/(SELECT r from s))::numeric(20,2) AS row_percent,
(100*rows/(SELECT r from s))::numeric(20,2) AS "row_%",
query
FROM _pg_stat_statements
WHERE
@ -28,20 +27,19 @@ WHERE @@ -28,20 +27,19 @@ WHERE
UNION all
SELECT
(100*sum(total_time)/(SELECT t FROM s))::numeric(20,2) AS time_percent,
(100*sum(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2) AS iotime_percent,
(100*sum(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2) AS cputime_percent,
(100*sum(total_time)/(SELECT t FROM s))::numeric(20,2),
(100*sum(blk_read_time+blk_write_time)/(SELECT iot FROM s))::numeric(20,2),
(100*sum(total_time-blk_read_time-blk_write_time)/(SELECT cput FROM s))::numeric(20,2),
sum(total_time)::numeric(20,2),
(sum(total_time)*1000/sum(calls))::numeric(10,3) AS avg_time,
(sum(blk_read_time+blk_write_time)*1000/sum(calls))::numeric(10,3) AS avg_io_time,
(sum(total_time)*1000/sum(calls))::numeric(10,3),
(sum(blk_read_time+blk_write_time)*1000/sum(calls))::numeric(10,3),
sum(calls),
(100*sum(calls)/(SELECT s FROM s))::numeric(20,2) AS calls_percent,
(100*sum(calls)/(SELECT s FROM s))::numeric(20,2),
sum(rows),
(100*sum(rows)/(SELECT r from s))::numeric(20,2) AS row_percent,
'other' AS query
(100*sum(rows)/(SELECT r from s))::numeric(20,2),
'other'
FROM _pg_stat_statements
WHERE
(total_time)/(SELECT t FROM s)<0.02
ORDER BY 1 DESC;
ORDER BY 1 DESC;

4
sql/redundant_indexes.sql

@ -1,11 +1,9 @@ @@ -1,11 +1,9 @@
WITH
index_data AS
(SELECT *,string_to_array(indkey::text,' ') as key_array,array_length(string_to_array(indkey::text,' '),1) as nkeys from pg_index)
SELECT
i1.indrelid::regclass::text,
i1.indrelid::regclass::text as table,
pg_get_indexdef(i1.indexrelid) main_index,
pg_get_indexdef(i2.indexrelid) redundant_index,
pg_size_pretty(pg_relation_size(i2.indexrelid)) redundant_index_size

3
sql/seq_scan_tables.sql

@ -1,6 +1,5 @@ @@ -1,6 +1,5 @@
SELECT
schemaname||'.'||relname,
schemaname||'.'||relname as table,
n_live_tup,
seq_scan,
seq_tup_read,

7
sql/table_bloat.sql

@ -1,12 +1,11 @@ @@ -1,12 +1,11 @@
--pgstattuple extension required
--WARNING: without table name/mask query will read all available tables which could cause I/O spikes
select nspname,
relname,
select nspname||'.'||relname as table,
pg_size_pretty(relation_size + toast_relation_size) as total_size,
pg_size_pretty(toast_relation_size) as toast_size,
round(((relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size, 1))::numeric, 1) table_waste_percent,
round(((relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size, 1))::numeric, 1) "table_waste_%",
pg_size_pretty((relation_size - (relation_size - free_space)*100/fillfactor)::bigint) table_waste,
round(((toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size + toast_relation_size, 1))::numeric, 1) total_waste_percent,
round(((toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size + toast_relation_size, 1))::numeric, 1) "total_waste_%",
pg_size_pretty((toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor)::bigint) total_waste
from (
select nspname, relname,

7
sql/table_bloat_approx.sql

@ -1,13 +1,12 @@ @@ -1,13 +1,12 @@
--faster version of table_bloat.sql which returns approximate results and doesn't read whole table (but reads toast tables)
--pgstattuple v1.3+ extension required (available since postgresql 9.5)
--WARNING: without table name/mask query will read all available tables which could cause I/O spikes
select nspname,
relname,
select nspname||'.'||relname as table,
pg_size_pretty(relation_size + toast_relation_size) as total_size,
pg_size_pretty(toast_relation_size) as toast_size,
round(((relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size, 1))::numeric, 1) table_waste_percent,
round(((relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size, 1))::numeric, 1) "table_waste_%",
pg_size_pretty((relation_size - (relation_size - free_space)*100/fillfactor)::bigint) table_waste,
round(((toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size + toast_relation_size, 1))::numeric, 1) total_waste_percent,
round(((toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor)*100/greatest(relation_size + toast_relation_size, 1))::numeric, 1) "total_waste_%",
pg_size_pretty((toast_free_space + relation_size - (relation_size - free_space)*100/fillfactor)::bigint) total_waste
from (
select nspname, relname,

8
sql/table_candidates_from_ssd.sql

@ -1,5 +1,3 @@ @@ -1,5 +1,3 @@
select * from (WITH totals_counts AS
(
SELECT
@ -9,16 +7,16 @@ select * from (WITH totals_counts AS @@ -9,16 +7,16 @@ select * from (WITH totals_counts AS
WHERE c.relkind='r'
)
SELECT
(n.nspname||'.'||c.relname)::varchar(30),
(n.nspname||'.'||c.relname)::varchar(40) as table,
t.spcname AS tblsp,
pg_size_pretty(pg_relation_size(c.oid)+(CASE WHEN c.reltoastrelid=0 THEN 0 ELSE pg_total_relation_size(c.reltoastrelid) END)) AS size,
((pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid))::numeric(20,2)/GREATEST(1, (pg_stat_get_tuples_inserted(c.oid)+pg_stat_get_tuples_inserted(c.reltoastrelid)+2*(pg_stat_get_tuples_updated(c.oid)+pg_stat_get_tuples_updated(c.reltoastrelid))+pg_stat_get_tuples_deleted(c.oid)+pg_stat_get_tuples_deleted(c.reltoastrelid)))::numeric(20,2))::numeric(20,2) AS ratio,
pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid) AS disk,
((100*(pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid)))/(SELECT disk FROM totals_counts))::numeric(5,2) AS "disk%",
((100*(pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid)))/(SELECT disk FROM totals_counts))::numeric(5,2) AS "disk_%",
((SELECT SUM(pg_stat_get_tuples_fetched(i.indexrelid))::bigint FROM pg_index i WHERE i.indrelid=c.oid) + pg_stat_get_tuples_fetched(c.oid))/GREATEST(1, (pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid))) AS rt_d_rat,
((SELECT SUM(pg_stat_get_tuples_fetched(i.indexrelid))::bigint FROM pg_index i WHERE i.indrelid=c.oid) + pg_stat_get_tuples_fetched(c.oid)) AS r_tuples,
pg_stat_get_tuples_inserted(c.oid)+pg_stat_get_tuples_inserted(c.reltoastrelid)+2*(pg_stat_get_tuples_updated(c.oid)+pg_stat_get_tuples_updated(c.reltoastrelid))+pg_stat_get_tuples_deleted(c.oid)+pg_stat_get_tuples_deleted(c.reltoastrelid) AS write,
((100*(pg_stat_get_tuples_inserted(c.oid)+pg_stat_get_tuples_inserted(c.reltoastrelid)+2*(pg_stat_get_tuples_updated(c.oid)+pg_stat_get_tuples_updated(c.reltoastrelid))+pg_stat_get_tuples_deleted(c.oid)+pg_stat_get_tuples_deleted(c.reltoastrelid)))/(SELECT write FROM totals_counts))::numeric(5,2) AS "write%",
((100*(pg_stat_get_tuples_inserted(c.oid)+pg_stat_get_tuples_inserted(c.reltoastrelid)+2*(pg_stat_get_tuples_updated(c.oid)+pg_stat_get_tuples_updated(c.reltoastrelid))+pg_stat_get_tuples_deleted(c.oid)+pg_stat_get_tuples_deleted(c.reltoastrelid)))/(SELECT write FROM totals_counts))::numeric(5,2) AS "write_%",
pg_stat_get_tuples_inserted(c.oid)+pg_stat_get_tuples_inserted(c.reltoastrelid) AS n_tup_ins,
pg_stat_get_tuples_updated(c.oid)+pg_stat_get_tuples_updated(c.reltoastrelid) AS n_tup_upd,
pg_stat_get_tuples_deleted(c.oid)+pg_stat_get_tuples_deleted(c.reltoastrelid) AS n_tup_del

10
sql/table_candidates_to_ssd.sql

@ -1,6 +1,4 @@ @@ -1,6 +1,4 @@
select * from (WITH totals_counts AS
select * from (WITH totals_counts AS
(
SELECT
sum(pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid)) as disk,
@ -9,16 +7,16 @@ @@ -9,16 +7,16 @@
WHERE c.relkind='r'
)
SELECT
(n.nspname||'.'||c.relname)::varchar(30),
(n.nspname||'.'||c.relname)::varchar(40) as table,
t.spcname AS tblsp,
pg_size_pretty(pg_relation_size(c.oid)+(CASE WHEN c.reltoastrelid=0 THEN 0 ELSE pg_total_relation_size(c.reltoastrelid) END)) AS size,
(pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid))/GREATEST(1, (pg_stat_get_tuples_inserted(c.oid)+pg_stat_get_tuples_inserted(c.reltoastrelid)+2*(pg_stat_get_tuples_updated(c.oid)+pg_stat_get_tuples_updated(c.reltoastrelid))+pg_stat_get_tuples_deleted(c.oid)+pg_stat_get_tuples_deleted(c.reltoastrelid))) AS ratio,
pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid) AS disk,
((100*(pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid)))/(SELECT disk FROM totals_counts))::numeric(5,2) AS "disk%",
((100*(pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid)))/(SELECT disk FROM totals_counts))::numeric(5,2) AS "disk_%",
((SELECT SUM(pg_stat_get_tuples_fetched(i.indexrelid))::bigint FROM pg_index i WHERE i.indrelid=c.oid) + pg_stat_get_tuples_fetched(c.oid))/GREATEST(1, (pg_stat_get_blocks_fetched(c.oid)-pg_stat_get_blocks_hit(c.oid)+pg_stat_get_blocks_fetched(c.reltoastrelid)-pg_stat_get_blocks_hit(c.reltoastrelid))) AS rt_d_rat,
((SELECT SUM(pg_stat_get_tuples_fetched(i.indexrelid))::bigint FROM pg_index i WHERE i.indrelid=c.oid) + pg_stat_get_tuples_fetched(c.oid)) AS r_tuples,
pg_stat_get_tuples_inserted(c.oid)+pg_stat_get_tuples_inserted(c.reltoastrelid)+2*(pg_stat_get_tuples_updated(c.oid)+pg_stat_get_tuples_updated(c.reltoastrelid))+pg_stat_get_tuples_deleted(c.oid)+pg_stat_get_tuples_deleted(c.reltoastrelid) AS write,
((100*(pg_stat_get_tuples_inserted(c.oid)+pg_stat_get_tuples_inserted(c.reltoastrelid)+2*(pg_stat_get_tuples_updated(c.oid)+pg_stat_get_tuples_updated(c.reltoastrelid))+pg_stat_get_tuples_deleted(c.oid)+pg_stat_get_tuples_deleted(c.reltoastrelid)))/(SELECT write FROM totals_counts))::numeric(5,2) AS "write%",
((100*(pg_stat_get_tuples_inserted(c.oid)+pg_stat_get_tuples_inserted(c.reltoastrelid)+2*(pg_stat_get_tuples_updated(c.oid)+pg_stat_get_tuples_updated(c.reltoastrelid))+pg_stat_get_tuples_deleted(c.oid)+pg_stat_get_tuples_deleted(c.reltoastrelid)))/(SELECT write FROM totals_counts))::numeric(5,2) AS "write_%",
pg_stat_get_tuples_inserted(c.oid)+pg_stat_get_tuples_inserted(c.reltoastrelid) AS n_tup_ins,
pg_stat_get_tuples_updated(c.oid)+pg_stat_get_tuples_updated(c.reltoastrelid) AS n_tup_upd,
pg_stat_get_tuples_deleted(c.oid)+pg_stat_get_tuples_deleted(c.reltoastrelid) AS n_tup_del

6
sql/table_index_write_activity.sql

@ -1,7 +1,7 @@ @@ -1,7 +1,7 @@
SELECT
pg_stat_user_tables.schemaname||'.'||pg_stat_user_tables.relname,
pg_size_pretty(pg_relation_size(relid)),
pg_stat_user_tables.schemaname||'.'||pg_stat_user_tables.relname as table,
pg_size_pretty(pg_relation_size(relid)) as size,
t.spcname AS tblsp,
coalesce(t.spcname, (select spcname from pg_tablespace where oid=(select dattablespace from pg_database where datname=current_database()))) AS tblsp,
seq_scan,
@ -10,7 +10,7 @@ n_tup_ins, @@ -10,7 +10,7 @@ n_tup_ins,
n_tup_upd,
n_tup_del,
coalesce(n_tup_ins,0)+coalesce(n_tup_upd,0)-coalesce(n_tup_hot_upd,0)+coalesce(n_tup_del,0) as total,
(coalesce(n_tup_hot_upd,0)::float*100/(case when n_tup_upd>0 then n_tup_upd else 1 end)::float)::numeric(10,2) as hot_rate,
(coalesce(n_tup_hot_upd,0)::float*100/(case when n_tup_upd>0 then n_tup_upd else 1 end)::float)::numeric(10,2) as "HOT_rate",
(select v[1] FROM regexp_matches(reloptions::text,E'fillfactor=(\\d+)') as r(v) limit 1) as fillfactor
from pg_stat_user_tables
JOIN pg_class c ON c.oid=relid

6
sql/table_write_activity.sql

@ -1,7 +1,7 @@ @@ -1,7 +1,7 @@
SELECT
pg_stat_all_tables.schemaname||'.'||pg_stat_all_tables.relname,
pg_size_pretty(pg_relation_size(relid)),
pg_stat_all_tables.schemaname||'.'||pg_stat_all_tables.relname as table,
pg_size_pretty(pg_relation_size(relid)) as size,
coalesce(t.spcname, (select spcname from pg_tablespace where oid=(select dattablespace from pg_database where datname=current_database()))) AS tblsp,
seq_scan,
idx_scan,
@ -9,7 +9,7 @@ n_tup_ins, @@ -9,7 +9,7 @@ n_tup_ins,
n_tup_upd,
n_tup_del,
coalesce(n_tup_ins,0)+2*coalesce(n_tup_upd,0)-coalesce(n_tup_hot_upd,0)+coalesce(n_tup_del,0) as total,
(coalesce(n_tup_hot_upd,0)::float*100/(case when n_tup_upd>0 then n_tup_upd else 1 end)::float)::numeric(10,2) as hot_rate,
(coalesce(n_tup_hot_upd,0)::float*100/(case when n_tup_upd>0 then n_tup_upd else 1 end)::float)::numeric(10,2) as "HOT_rate",
(select v[1] FROM regexp_matches(reloptions::text,E'fillfactor=(\\d+)') as r(v) limit 1) as fillfactor
from pg_stat_all_tables
JOIN pg_class c ON c.oid=relid

Loading…
Cancel
Save