Skip to content

Commit

Permalink
adding reviewed queries
Browse files Browse the repository at this point in the history
  • Loading branch information
Diego committed Jun 9, 2023
1 parent ca7e80c commit 04f7952
Show file tree
Hide file tree
Showing 15 changed files with 59 additions and 31 deletions.
File renamed without changes.
File renamed without changes.
3 changes: 3 additions & 0 deletions sql/AutoVacuum/candidates-for-vacuum-freeze.md
Original file line number Diff line number Diff line change
Expand Up @@ -18,3 +18,6 @@ On `percent_towards_emergency_autovacuum` in 100%, autovacuum will run in aggres
but also, will force a block read to disk.

The sizes are useful for estimate how long the execution will take, but this is also relative to the concurrency, indexes and other factors.

The default value is too conservative, (10%) probably you can set autovacuum_freeze_max_age for this table in a higer value (~25%).
https://postgresqlco.nf/doc/en/param/autovacuum_freeze_max_age/13/
8 changes: 4 additions & 4 deletions sql/BackgroundWriter/10_secs_bgwriter.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
-- 10 second iteration for calculate bgwriter activity
WITH tara AS (
SELECT
with tara as (
select
checkpoints_timed ,
checkpoints_req ,
checkpoint_write_time ,
Expand All @@ -13,7 +13,7 @@ WITH tara AS (
buffers_alloc
from pg_stat_bgwriter, pg_sleep(10)
)
SELECT
select
pgb.checkpoints_timed - tara.checkpoints_timed,
pgb.checkpoints_req - tara.checkpoints_req,
pgb.checkpoint_write_time - tara.checkpoint_write_time,
Expand All @@ -24,5 +24,5 @@ SELECT
pgb.buffers_backend - tara.buffers_backend,
pgb.buffers_backend_fsync - tara.buffers_backend_fsync,
pgb.buffers_alloc - tara.buffers_alloc
FROM pg_stat_bgwriter pgb,tara
from pg_stat_bgwriter pgb,tara
;
9 changes: 9 additions & 0 deletions sql/Cache/cache_effectivity_by_table.sql
Original file line number Diff line number Diff line change
@@ -1,2 +1,11 @@
-- Shows the cache effectivity on each table (1 row per table)
-- "_hits" and "_reads" includes "regular" blocks, indexes blocks, toast and tidx blocks

select
schemaname, relname,
heap_blks_read as heap_read,
heap_blks_hit as heap_hit,
heap_blks_hit / (heap_blks_hit + heap_blks_read::float) as ratio
from
pg_statio_user_tables
where (heap_blks_hit + heap_blks_read) > 0;
4 changes: 2 additions & 2 deletions sql/DatabaseCapacity/size_growth_interval.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,11 +4,11 @@
WITH timeset AS (
select pg_database_size(datname) num,
pg_size_pretty(pg_database_size(datname)) size
from pg_database where datname = 'db'
from pg_database where datname = current_database()
UNION ALL
select pg_database_size(datname) num,
pg_size_pretty(pg_database_size(datname)) size
from pg_database, pg_sleep(10) where datname = 'db'
from pg_database, pg_sleep(10) where datname = current_database()
)
SELECT pg_size_pretty((num - lag(num,1)
OVER (ORDER BY num))/10) transfer_per_second,
Expand Down
29 changes: 16 additions & 13 deletions sql/Indexes/unused_indexes.sql
Original file line number Diff line number Diff line change
@@ -1,13 +1,16 @@
SELECT s.schemaname,
s.relname AS tablename,
s.indexrelname AS indexname,
pg_relation_size(s.indexrelid) AS index_size
FROM pg_catalog.pg_stat_user_indexes s
JOIN pg_catalog.pg_index i ON s.indexrelid = i.indexrelid
WHERE s.idx_scan = 0 -- has never been scanned
AND 0 <>ALL (i.indkey) -- no index column is an expression
AND NOT i.indisunique -- is not a UNIQUE index
AND NOT EXISTS -- does not enforce a constraint
(SELECT 1 FROM pg_catalog.pg_constraint c
WHERE c.conindid = s.indexrelid)
ORDER BY pg_relation_size(s.indexrelid) DESC;
select s.schemaname,
s.relname as tablename,
s.indexrelname as indexname,
pg_relation_size(s.indexrelid) as index_size,
pg_size_pretty(pg_relation_size(s.indexrelid)) as index_size_human
from pg_catalog.pg_stat_user_indexes s
join pg_catalog.pg_index i on s.indexrelid = i.indexrelid
where --s.idx_scan = 0 -- has never been scanned
s.idx_scan < 50 -- almost never used
and pg_relation_size(relid) > 5 * 8192 -- skip empty objects
and 0 <>all (i.indkey) -- no index column is an expression
and not i.indisunique -- is not a unique index
and not exists -- does not enforce a constraint
(select 1 from pg_catalog.pg_constraint c
where c.conindid = s.indexrelid)
order by pg_relation_size(s.indexrelid) desc;
5 changes: 4 additions & 1 deletion sql/Indexes/worst_index_hits.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,5 +16,8 @@ WITH worst_index_hit_ratio AS (
GROUP BY indexrelname, relid
ORDER BY hit_ratio ASC
)
SELECT * FROM worst_index_hit_ratio WHERE idx_read = 0 and idx_hit = 0; -- < 0.9;
SELECT * FROM worst_index_hit_ratio
WHERE
-- idx_read = 0 and idx_hit = 0; -- < 0.9;
hit_ratio < 0.8;

6 changes: 6 additions & 0 deletions sql/MultiXact/get_oldest_by_active_conn.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
-- This query returns a list of active session holding multixact slots and their ages
-- The age here is not tied to a time constraint, but rather to the transaction
-- amount distance from the relminmxid and now.
SELECT pid, datname, usename, state, txid_current(), backend_xmin,
txid_current()::text::int - backend_xmin::text::int difference
, statement_timestamp() - query_start elapsed , pg_blocking_pids(pid) as blocked_by, query::varchar(150) query FROM pg_stat_activity WHERE backend_xmin IS NOT NULL ORDER BY age(backend_xmin) ;
2 changes: 1 addition & 1 deletion sql/MultiXact/get_oldest_multixact.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,4 +5,4 @@ SELECT relnamespace::regnamespace, relname, relkind, relminmxid,
(select next_multixact_id::text::bigint FROM pg_control_checkpoint()) - relminmxid::TEXT::BIGINT AS age
FROM pg_class
WHERE relminmxid::TEXT::BIGINT <> 0
ORDER BY relminmxid::TEXT::BIGINT ASC;
ORDER BY relminmxid::TEXT::BIGINT ASC;
2 changes: 1 addition & 1 deletion sql/PgStatStatements/large_result_sets.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,7 +3,7 @@ SELECT
substring(query,0,100),
calls,
rows/calls as rowspercall,
mean_time,
mean_exec_time,
shared_blks_hit,
shared_blks_read
FROM pg_stat_statements
Expand Down
4 changes: 2 additions & 2 deletions sql/PgStatStatements/most_frequent_queries.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,8 +2,8 @@
SELECT queryid,
query,
calls,
total_time/1000 as time_secs,
(total_time/1000)/calls as per_call,
total_exec_time/1000 as time_secs,
(total_exec_time/1000)/calls as per_call,
CASE
WHEN (shared_blks_hit > 0 AND shared_blks_read > 0) THEN round(shared_blks_hit / (shared_blks_hit + shared_blks_read))
ELSE 0 END as hit_ratio,
Expand Down
6 changes: 3 additions & 3 deletions sql/PgStatStatements/slowest_queries.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,8 +2,8 @@
SELECT queryid,
query,
calls,
total_time/1000 as time_secs,
(total_time/1000)/calls as per_call,
total_exec_time/1000 as time_secs,
(total_exec_time/1000)/calls as per_call,
CASE
WHEN (shared_blks_hit > 0 AND shared_blks_read > 0) THEN round(shared_blks_hit / (shared_blks_hit + shared_blks_read))
ELSE 0 END as hit_ratio,
Expand All @@ -14,5 +14,5 @@ SELECT queryid,
WHEN (shared_blks_written > 0) THEN round(shared_blks_written / calls )
ELSE 0 END as blk_wrtn_per_call
FROM pg_stat_statements
ORDER BY total_time/calls DESC
ORDER BY total_exec_time/calls DESC
LIMIT 10;
8 changes: 4 additions & 4 deletions sql/PgStatStatements/unstable_queries.sql
Original file line number Diff line number Diff line change
@@ -1,14 +1,14 @@
-- Unstable queries, with larges deltas.

SELECT queryid, calls,mean_time, max_time, query,
SELECT queryid, calls,mean_exec_time, max_exec_time, query,
rows, shared_blks_read,

blk_read_time+blk_write_time,temp_blks_written+temp_blks_read,stddev_time
blk_read_time+blk_write_time,temp_blks_written+temp_blks_read,stddev_exec_time
from pg_Stat_statements

ORDER BY
mean_time DESC,
stddev_time DESC
mean_exec_time DESC,
stddev_exec_time DESC

LIMIT 10;

4 changes: 4 additions & 0 deletions sql/Settings/generic.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,5 @@
-- Get a better output of pg_settings
/*
SELECT name, category,
setting,
short_desc::text , extra_desc::text,
Expand All @@ -9,3 +10,6 @@ WHERE
category ~ '^Replication'
-- category ~ 'eplication'
ORDER BY context;
*/
SELECT *
FROM pg_settings;

0 comments on commit 04f7952

Please sign in to comment.