diff --git a/sql/IO/IO.md b/sql/IO/IO.md new file mode 100644 index 0000000..93d4bd9 --- /dev/null +++ b/sql/IO/IO.md @@ -0,0 +1,11 @@ +# IO analysis + +Taking advantage from the new view [pg_stat_io](https://www.postgresql.org/docs/devel/monitoring-stats.html#MONITORING-PG-STAT-IO-VIEW) released in PG16 , it is possible to see statitics about backend type and IO operations + +The queries for this porpose can be used to check the information about: + + +* Analyze the impact of vacuum in IO activity (high is bad,maybe >10% ?) +* Analyze the impact of client backend in fsync activity (high is bad,maybe >10% ?) + +TODO: analyze , top IO consumer, top evictions \ No newline at end of file diff --git a/sql/IO/client_backend_fsync_impact.sql b/sql/IO/client_backend_fsync_impact.sql new file mode 100644 index 0000000..89b109c --- /dev/null +++ b/sql/IO/client_backend_fsync_impact.sql @@ -0,0 +1,13 @@ +WITH cte_fsync_client_backend_io AS + (SELECT sum(fsyncs) fsync_client_backend_io + FROM pg_stat_io + WHERE backend_type = 'client backend' + ), + cte_fsync_total_io AS + (SELECT sum(fsyncs) fsync_total_io + FROM pg_stat_io) +SELECT round(( + (SELECT fsync_client_backend_io + FROM cte_fsync_client_backend_io) *100)/ + (SELECT fsync_total_io + FROM cte_fsync_total_io),2) as io_backend_fsync_activity_pct; diff --git a/sql/IO/vacuum_io_impact.sql b/sql/IO/vacuum_io_impact.sql new file mode 100644 index 0000000..d620381 --- /dev/null +++ b/sql/IO/vacuum_io_impact.sql @@ -0,0 +1,16 @@ +WITH cte_vacuum_io AS + (SELECT sum(READS)+sum(writes)+sum(extends) vacuum_io + FROM pg_stat_io + WHERE backend_type = 'autovacuum worker' + OR (context = 'vacuum' + AND (READS <> 0 + OR writes <> 0 + OR extends <> 0)) ), + cte_total_io AS + (SELECT sum(READS)+sum(writes)+sum(extends) total_io + FROM pg_stat_io) +SELECT round(( + (SELECT vacuum_io + FROM cte_vacuum_io) *100)/ + (SELECT total_io + FROM cte_total_io),2) as io_vacuum_activity_pct;