├── playground ├── grafana │ └── provisioning │ │ ├── dashboards │ │ ├── unofficial │ │ │ ├── README.md │ │ │ ├── lock-tree.json │ │ │ └── query-stat-total.json │ │ └── default.yaml │ │ └── datasources │ │ └── datasource.yml ├── postgres │ ├── Dockerfile │ ├── standby-entrypoint.sh │ └── primary-initdb.sh ├── victoriametrics │ └── vmagent.yaml ├── Makefile ├── scripts │ ├── active_temp_files.sql │ ├── locktree.sql │ └── query_stat_total.sql ├── pgscv │ └── pgscv.yaml └── docker-compose.yaml └── README.md /playground/grafana/provisioning/dashboards/unofficial/README.md: -------------------------------------------------------------------------------- 1 | Dashboards in this directory are unofficial and provided 'as-is' without any guarantees. 2 | -------------------------------------------------------------------------------- /playground/grafana/provisioning/dashboards/default.yaml: -------------------------------------------------------------------------------- 1 | apiVersion: 1 2 | 3 | providers: 4 | - name: Default 5 | folder: 'Unofficial' 6 | type: file 7 | options: 8 | path: /etc/grafana/provisioning/dashboards/unofficial 9 | foldersFromFilesStructure: true 10 | -------------------------------------------------------------------------------- /playground/postgres/Dockerfile: -------------------------------------------------------------------------------- 1 | FROM postgres:15-alpine 2 | 3 | RUN wget https://github.com/lesovsky/pgcenter/releases/download/v0.9.2/pgcenter_0.9.2_linux_amd64.tar.gz -o /dev/null -O - | \ 4 | tar xzf - -C /usr/bin pgcenter && \ 5 | mkdir /var/log/postgresql && \ 6 | chown postgres:postgres /var/log/postgresql 7 | -------------------------------------------------------------------------------- /playground/victoriametrics/vmagent.yaml: -------------------------------------------------------------------------------- 1 | global: 2 | scrape_interval: 15s 3 | 4 | scrape_configs: 5 | - job_name: postgres 6 | 7 | static_configs: 8 | - targets: [ pgscv:9890 ] 9 | 10 | #metric_relabel_debug: true 11 | metric_relabel_configs: 12 | # truncate query label of postgres_statements_query_info to 72 characters 13 | - action: replace 14 | source_labels: [ query ] 15 | regex: (.{1,72}).* 16 | target_label: query 17 | replacement: $1 -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # PostgreSQL Monitoring 2 | 3 | The "PostgreSQL Monitoring" book describes practical aspects of PostgreSQL internal statistics and how it can be used for 4 | monitoring purposes. 5 | 6 | This repository contains Docker-based playground, it helps to familiar with PostgreSQL statistics tools and monitoring 7 | techniques. 8 | 9 | Also, in case of any issues, bugs, features requests or discussions, you can let me know through the [issues]. 10 | 11 | [issues]:https://github.com/lesovsky/postgresql-monitoring-book/issues -------------------------------------------------------------------------------- /playground/postgres/standby-entrypoint.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | if [ ! -s "$PGDATA/PG_VERSION" ]; then 3 | echo "*:*:*:replica:replication" > ~/.pgpass 4 | chmod 0600 ~/.pgpass 5 | 6 | until pg_isready -h primary -p 5432 -U postgres 7 | do 8 | echo "Waiting for primary become ready..." 9 | sleep 2s 10 | done 11 | 12 | until su-exec postgres pg_basebackup -P -R -X stream -c fast -h primary -U replica -D ${PGDATA} 13 | do 14 | echo "Waiting for primary become ready for base backup..." 15 | sleep 3s 16 | done 17 | 18 | echo "primary_slot_name = 'standby'" >> ${PGDATA}/postgresql.auto.conf 19 | 20 | chmod 700 ${PGDATA} 21 | fi 22 | 23 | exec "$@" -------------------------------------------------------------------------------- /playground/grafana/provisioning/datasources/datasource.yml: -------------------------------------------------------------------------------- 1 | apiVersion: 1 2 | 3 | datasources: 4 | - name: victoriametrics 5 | type: prometheus 6 | access: proxy 7 | orgId: 1 8 | url: http://victoriametrics:8428 9 | basicAuth: false 10 | isDefault: true 11 | editable: true 12 | 13 | - name: primary 14 | type: postgres 15 | url: primary:5432 16 | user: postgres 17 | jsonData: 18 | database: postgres 19 | sslmode: 'disable' # disable/require/verify-ca/verify-full 20 | maxOpenConns: 100 # Grafana v5.4+ 21 | maxIdleConns: 100 # Grafana v5.4+ 22 | maxIdleConnsAuto: true # Grafana v9.5.1+ 23 | connMaxLifetime: 14400 # Grafana v5.4+ 24 | postgresVersion: 1500 # 903=9.3, 904=9.4, 905=9.5, 906=9.6, 1000=10 25 | timescaledb: false 26 | -------------------------------------------------------------------------------- /playground/Makefile: -------------------------------------------------------------------------------- 1 | SHELL = /bin/bash 2 | 3 | all: help 4 | 5 | # define target variable depending on target suffix 6 | primary/%: TARGET = primary 7 | standby/%: TARGET = standby 8 | app1/%: TARGET = app1 9 | app2/%: TARGET = app2 10 | app3/%: TARGET = app3 11 | app4/%: TARGET = app4 12 | 13 | help: ## Display this help screen 14 | @echo "Makefile available targets:" 15 | @grep -h -E '^[a-zA-Z_/%-]+:.*?## .*$$' $(MAKEFILE_LIST) | awk 'BEGIN {FS = ":.*?## "}; {printf " * \033[36m%-16s\033[0m %s\n", $$1, $$2}' 16 | 17 | up: ## Start playground environment 18 | docker-compose up -d 19 | 20 | ps: ## Show current status of playground services 21 | docker-compose ps 22 | 23 | down: ## Stop playground environment (without cleanup) 24 | docker-compose down 25 | 26 | destroy: ## Stop playground environment and clean up related resources 27 | docker-compose down -v --rmi all 28 | 29 | %/logs: ## Show service logs; % - service name, e.g. primary or standby 30 | docker-compose exec ${TARGET} /bin/bash -c 'cat $$(psql -U postgres -qAtX -c "select pg_current_logfile()")' 31 | 32 | %/logs/tail: ## Tail service logs; % - service name, e.g. primary or standby 33 | docker-compose exec ${TARGET} /bin/bash -c 'tail -f $$(psql -U postgres -qAtX -c "select pg_current_logfile()")' 34 | 35 | %/shell: ## Start shell session; % - service name, e.g. primary or standby 36 | docker-compose exec ${TARGET} /bin/bash 37 | 38 | %/psql: ## Start psql session; % - service name, e.g. primary or standby 39 | docker-compose exec ${TARGET} psql -U postgres pgbench 40 | 41 | %/pgcenter: ## Start pgcenter session; % - service name, e.g. primary or standby 42 | docker-compose exec ${TARGET} pgcenter top -U postgres pgbench 43 | -------------------------------------------------------------------------------- /playground/scripts/active_temp_files.sql: -------------------------------------------------------------------------------- 1 | WITH RECURSIVE 2 | tablespace_dirs AS ( 3 | SELECT 4 | dirname, 5 | 'pg_tblspc/' || dirname || '/' AS path, 6 | 1 AS depth 7 | FROM 8 | pg_catalog.pg_ls_dir('pg_tblspc/', true, false) AS dirname 9 | UNION ALL 10 | SELECT 11 | subdir, 12 | td.path || subdir || '/', 13 | td.depth + 1 14 | FROM 15 | tablespace_dirs AS td, 16 | pg_catalog.pg_ls_dir(td.path, true, false) AS subdir 17 | WHERE 18 | td.depth < 3 19 | ), 20 | temp_dirs AS ( 21 | SELECT 22 | td.path, 23 | ts.spcname AS tablespace 24 | FROM 25 | tablespace_dirs AS td 26 | INNER JOIN pg_catalog.pg_tablespace AS ts ON (ts.oid = substring(td.path FROM 'pg_tblspc/(\d+)')::int) 27 | WHERE 28 | td.depth = 3 29 | AND 30 | td.dirname = 'pgsql_tmp' 31 | UNION ALL 32 | VALUES 33 | ('base/pgsql_tmp/', 'pg_default') 34 | ), 35 | temp_files AS ( 36 | SELECT 37 | substring(filename FROM 'pgsql_tmp(\d+)')::int AS pid, 38 | td.tablespace, 39 | td.path || filename as filename, 40 | pg_stat_file(td.path || filename, true) AS file_stat 41 | FROM 42 | temp_dirs AS td, 43 | pg_catalog.pg_ls_dir(td.path, true, false) AS filename 44 | ) 45 | SELECT 46 | a.pid, 47 | now() - a.query_start as query_age, 48 | t.tablespace, 49 | t.filename, 50 | pg_size_pretty((file_stat).size) AS size, 51 | now() - (file_stat).modification AS last_modification, 52 | a.query 53 | FROM temp_files t 54 | JOIN pg_stat_activity a ON (t.pid = a.pid) 55 | ORDER BY (file_stat).size DESC; -------------------------------------------------------------------------------- /playground/scripts/locktree.sql: -------------------------------------------------------------------------------- 1 | with recursive activity as ( 2 | select 3 | *, 4 | pg_blocking_pids(pid) blocked_by, 5 | age(clock_timestamp(), xact_start)::interval(0) as tx_age, 6 | age(clock_timestamp(), (select max(l.waitstart) from pg_locks l where a.pid = l.pid))::interval(0) as wait_age 7 | from pg_stat_activity a 8 | where state is distinct from 'idle' 9 | ), blockers as ( 10 | select array_agg(c) as pids from (select distinct unnest(blocked_by) from activity) as dt(c) 11 | ), tree as ( 12 | select 13 | activity.*, 14 | 1 as level, 15 | activity.pid as top_blocker_pid, 16 | array[activity.pid] as path, 17 | array[activity.pid]::int[] as all_blockers_above 18 | from activity, blockers 19 | where 20 | array[pid] <@ blockers.pids 21 | and blocked_by = '{}'::int[] 22 | union all 23 | select 24 | activity.*, 25 | tree.level + 1 as level, 26 | tree.top_blocker_pid, 27 | path || array[activity.pid] as path, 28 | tree.all_blockers_above || array_agg(activity.pid) over () as all_blockers_above 29 | from activity, tree 30 | where 31 | not array[activity.pid] <@ tree.all_blockers_above 32 | and activity.blocked_by <> '{}'::int[] 33 | and activity.blocked_by <@ tree.path 34 | ) 35 | select 36 | pid, 37 | blocked_by, 38 | case when wait_event_type != 'Lock' then replace(state, 'idle in transaction', 'idletx') else 'waiting' end as state, 39 | wait_event_type || ':' || wait_event as wait, 40 | wait_age, 41 | tx_age, 42 | --to_char(age(backend_xid), 'FM999,999,999,990') AS xid_age, 43 | --to_char(2147483647 - age(backend_xmin), 'FM999,999,999,990') AS xmin_ttf, 44 | usename, 45 | datname, 46 | (select count(distinct t1.pid) from tree t1 where array[tree.pid] <@ t1.path and t1.pid <> tree.pid) as blkd, 47 | format( 48 | '%s %s%s', 49 | lpad('[' || pid::text || ']', 9, ' '), 50 | repeat('.', level - 1) || case when level > 1 then ' ' end, 51 | left(query, 1000) 52 | ) as query 53 | from tree 54 | order by top_blocker_pid, level, pid 55 | \watch 1 -------------------------------------------------------------------------------- /playground/postgres/primary-initdb.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | set -e 4 | 5 | psql -v ON_ERROR_STOP=1 -U postgres -d postgres <<-EOSQL 6 | CREATE EXTENSION IF NOT EXISTS pg_stat_statements; 7 | CREATE EXTENSION IF NOT EXISTS pg_buffercache; 8 | CREATE EXTENSION IF NOT EXISTS pg_walinspect; 9 | CREATE EXTENSION IF NOT EXISTS pgstattuple; 10 | CREATE ROLE replica WITH LOGIN REPLICATION PASSWORD 'replication'; 11 | CREATE ROLE stats WITH LOGIN PASSWORD 'stats' IN ROLE pg_monitor; 12 | CREATE ROLE pgbench WITH LOGIN PASSWORD 'pgbench'; 13 | CREATE ROLE serral WITH LOGIN PASSWORD 'serral' ROLE pgbench; 14 | CREATE ROLE maru WITH LOGIN PASSWORD 'maru' ROLE pgbench; 15 | CREATE ROLE classic WITH LOGIN PASSWORD 'classic' ROLE pgbench; 16 | CREATE DATABASE pgbench OWNER pgbench; 17 | \c pgbench 18 | CREATE EXTENSION IF NOT EXISTS pg_buffercache; 19 | CREATE EXTENSION IF NOT EXISTS pgstattuple; 20 | CREATE EXTENSION IF NOT EXISTS pg_stat_statements; 21 | \c pgbench pgbench 22 | ALTER DEFAULT PRIVILEGES GRANT ALL ON TABLES TO public; 23 | ALTER DEFAULT PRIVILEGES GRANT ALL ON SEQUENCES TO public; 24 | EOSQL 25 | 26 | cat >> ${PGDATA}/postgresql.conf <> ${PGDATA}/pg_hba.conf < 0 AND isdirty = 'f') * (SELECT current_setting('block_size')::int) AS clean_pinned, 32 | count(*) FILTER (WHERE pinning_backends = 0 AND isdirty = 't') * (SELECT current_setting('block_size')::int) AS dirty, 33 | count(*) FILTER (WHERE pinning_backends > 0 AND isdirty = 't') * (SELECT current_setting('block_size')::int) AS dirty_pinned 34 | FROM pg_buffercache 35 | metrics: 36 | - name: usage_bytes 37 | usage: GAUGE 38 | labeled_values: 39 | buffers: [ free, clean, clean_pinned, dirty, dirty_pinned ] 40 | description: "Total number of buffers in shared memory, in bytes." 41 | shared_buffers_database: 42 | query: | 43 | SELECT 44 | coalesce((SELECT datname FROM pg_database WHERE coalesce(oid, 0) = reldatabase), 'NULL') AS database, 45 | count(*) FILTER (WHERE isdirty) * (SELECT current_setting('block_size')::int) AS dirty, 46 | count(*) FILTER (WHERE NOT isdirty) * (SELECT current_setting('block_size')::int) AS clean 47 | FROM pg_buffercache 48 | WHERE reldatabase IS NOT NULL 49 | GROUP BY reldatabase 50 | metrics: 51 | - name: usage_bytes 52 | usage: GAUGE 53 | labeled_values: 54 | buffers: [ dirty, clean ] 55 | labels: [ database ] 56 | description: "Total number of buffers in shared memory used by databases, in bytes." -------------------------------------------------------------------------------- /playground/docker-compose.yaml: -------------------------------------------------------------------------------- 1 | version: "3.9" 2 | 3 | volumes: 4 | primary_data: 5 | standby_data: 6 | metrics_data: 7 | grafana_data: 8 | 9 | services: 10 | primary: 11 | build: ./postgres 12 | volumes: 13 | - primary_data:/var/lib/postgresql/data:rw 14 | - ./postgres/primary-initdb.sh:/docker-entrypoint-initdb.d/initdb.sh 15 | - ./scripts:/var/lib/postgresql/scripts:ro 16 | environment: 17 | POSTGRES_HOST_AUTH_METHOD: "trust" 18 | healthcheck: 19 | test: [ "CMD-SHELL", "sh -c 'pg_isready -U postgres'"] 20 | interval: 10s 21 | timeout: 10s 22 | retries: 10 23 | 24 | standby: 25 | build: ./postgres 26 | volumes: 27 | - standby_data:/var/lib/postgresql/data:rw 28 | - ./postgres/standby-entrypoint.sh:/docker-entrypoint.sh 29 | - ./scripts:/var/lib/postgresql/scripts:ro 30 | environment: 31 | POSTGRES_HOST_AUTH_METHOD: "trust" 32 | entrypoint: ["/docker-entrypoint.sh"] 33 | command: ["su-exec", "postgres", "postgres"] 34 | healthcheck: 35 | test: [ "CMD-SHELL", "sh -c 'pg_isready -U postgres'"] 36 | interval: 10s 37 | timeout: 10s 38 | retries: 10 39 | depends_on: [ primary ] 40 | 41 | app1: 42 | image: postgres:15 43 | command: bash -c "until pg_isready -h primary; do sleep 1; done && while true ; do pgbench -P 60 -c 1 -R 5 -T 36000 -h primary -U pgbench pgbench; done" 44 | depends_on: [ primary, standby ] 45 | 46 | app2: 47 | image: postgres:15 48 | command: bash -c "until pg_isready -h primary; do sleep 1; done && while true ; do pgbench -n -P 60 -c $$(shuf -i 1-5 -n 1) -R $$(shuf -i 1-5 -n 1) -T $$(shuf -i 100-180 -n 1) -h primary -U serral pgbench; done" 49 | depends_on: [ primary, standby ] 50 | 51 | app3: 52 | image: postgres:15 53 | command: bash -c "until pg_isready -h primary; do sleep 1; done && while true ; do pgbench -n -P 60 -c $$(shuf -i 9-15 -n 1) -R $$(shuf -i 8-12 -n 1) -T $$(shuf -i 250-330 -n 1) -h primary -U maru pgbench; done" 54 | depends_on: [ primary, standby ] 55 | 56 | app4: 57 | image: postgres:15 58 | command: bash -c "until pg_isready -h primary; do sleep 1; done && while true ; do pgbench -n -P 60 -c $$(shuf -i 19-25 -n 1) -R $$(shuf -i 16-20 -n 1) -T $$(shuf -i 400-600 -n 1) -h primary -U classic pgbench; done" 59 | depends_on: [ primary, standby ] 60 | 61 | pgscv: 62 | image: lesovsky/pgscv:v0.8.0-beta.6 63 | ports: [ "9890:9890" ] 64 | volumes: 65 | - ./pgscv/pgscv.yaml:/etc/pgscv.yaml 66 | environment: 67 | PGSCV_CONFIG_FILE: "/etc/pgscv.yaml" 68 | depends_on: 69 | primary: 70 | condition: service_healthy 71 | standby: 72 | condition: service_healthy 73 | 74 | victoriametrics: 75 | image: victoriametrics/victoria-metrics:v1.89.0 76 | volumes: 77 | - metrics_data:/data 78 | command: [ "-storageDataPath=/data", "-retentionPeriod=2d" ] 79 | 80 | vmagent: 81 | image: victoriametrics/vmagent:v1.89.0 82 | volumes: 83 | - ./victoriametrics/vmagent.yaml:/etc/vmagent.yaml 84 | command: [ "-promscrape.config=/etc/vmagent.yaml", "-remoteWrite.url=http://victoriametrics:8428/api/v1/write" ] 85 | depends_on: [ victoriametrics ] 86 | 87 | grafana: 88 | image: grafana/grafana:9.3.6 89 | volumes: 90 | - grafana_data:/var/lib/grafana 91 | - ./grafana/provisioning:/etc/grafana/provisioning 92 | environment: 93 | GF_AUTH_DISABLE_LOGIN_FORM: "true" 94 | GF_AUTH_ANONYMOUS_ENABLED: "true" 95 | GF_AUTH_ANONYMOUS_ORG_NAME: "Main Org." 96 | GF_AUTH_ANONYMOUS_ORG_ROLE: Admin 97 | GF_USERS_DEFAULT_THEME: light 98 | ports: [ "3000:3000" ] 99 | depends_on: [ vmagent ] 100 | -------------------------------------------------------------------------------- /playground/grafana/provisioning/dashboards/unofficial/lock-tree.json: -------------------------------------------------------------------------------- 1 | { 2 | "annotations": { 3 | "list": [ 4 | { 5 | "builtIn": 1, 6 | "datasource": { 7 | "type": "grafana", 8 | "uid": "-- Grafana --" 9 | }, 10 | "enable": true, 11 | "hide": true, 12 | "iconColor": "rgba(0, 211, 255, 1)", 13 | "name": "Annotations & Alerts", 14 | "type": "dashboard" 15 | } 16 | ] 17 | }, 18 | "editable": true, 19 | "fiscalYearStartMonth": 0, 20 | "graphTooltip": 0, 21 | "id": 4, 22 | "links": [], 23 | "liveNow": false, 24 | "panels": [ 25 | { 26 | "datasource": { 27 | "type": "postgres", 28 | "uid": "P986A1B7135F49861" 29 | }, 30 | "fieldConfig": { 31 | "defaults": { 32 | "color": { 33 | "mode": "thresholds" 34 | }, 35 | "custom": { 36 | "align": "auto", 37 | "cellOptions": { 38 | "type": "auto" 39 | }, 40 | "inspect": false 41 | }, 42 | "mappings": [], 43 | "thresholds": { 44 | "mode": "absolute", 45 | "steps": [ 46 | { 47 | "color": "green", 48 | "value": null 49 | }, 50 | { 51 | "color": "red", 52 | "value": 80 53 | } 54 | ] 55 | }, 56 | "unitScale": true 57 | }, 58 | "overrides": [ 59 | { 60 | "matcher": { 61 | "id": "byName", 62 | "options": "datname" 63 | }, 64 | "properties": [ 65 | { 66 | "id": "custom.width", 67 | "value": 77 68 | } 69 | ] 70 | }, 71 | { 72 | "matcher": { 73 | "id": "byName", 74 | "options": "blkd" 75 | }, 76 | "properties": [ 77 | { 78 | "id": "custom.width", 79 | "value": 74 80 | } 81 | ] 82 | }, 83 | { 84 | "matcher": { 85 | "id": "byName", 86 | "options": "tx_age" 87 | }, 88 | "properties": [ 89 | { 90 | "id": "custom.width", 91 | "value": 89 92 | } 93 | ] 94 | }, 95 | { 96 | "matcher": { 97 | "id": "byName", 98 | "options": "wait_age" 99 | }, 100 | "properties": [ 101 | { 102 | "id": "custom.width", 103 | "value": 111 104 | } 105 | ] 106 | }, 107 | { 108 | "matcher": { 109 | "id": "byName", 110 | "options": "wait" 111 | }, 112 | "properties": [ 113 | { 114 | "id": "custom.width", 115 | "value": 159 116 | } 117 | ] 118 | }, 119 | { 120 | "matcher": { 121 | "id": "byName", 122 | "options": "state" 123 | }, 124 | "properties": [ 125 | { 126 | "id": "custom.width", 127 | "value": 87 128 | } 129 | ] 130 | }, 131 | { 132 | "matcher": { 133 | "id": "byName", 134 | "options": "pid" 135 | }, 136 | "properties": [ 137 | { 138 | "id": "custom.width", 139 | "value": 80 140 | } 141 | ] 142 | }, 143 | { 144 | "matcher": { 145 | "id": "byName", 146 | "options": "blocked_by" 147 | }, 148 | "properties": [ 149 | { 150 | "id": "custom.width", 151 | "value": 101 152 | } 153 | ] 154 | }, 155 | { 156 | "matcher": { 157 | "id": "byName", 158 | "options": "usename" 159 | }, 160 | "properties": [ 161 | { 162 | "id": "custom.width", 163 | "value": 124 164 | } 165 | ] 166 | } 167 | ] 168 | }, 169 | "gridPos": { 170 | "h": 26, 171 | "w": 24, 172 | "x": 0, 173 | "y": 0 174 | }, 175 | "id": 1, 176 | "options": { 177 | "cellHeight": "sm", 178 | "footer": { 179 | "countRows": false, 180 | "fields": "", 181 | "reducer": [ 182 | "sum" 183 | ], 184 | "show": false 185 | }, 186 | "showHeader": true, 187 | "sortBy": [] 188 | }, 189 | "pluginVersion": "9.3.6", 190 | "targets": [ 191 | { 192 | "datasource": { 193 | "type": "postgres", 194 | "uid": "P986A1B7135F49861" 195 | }, 196 | "editorMode": "code", 197 | "format": "table", 198 | "rawQuery": true, 199 | "rawSql": "with recursive activity as (\n select\n *,\n pg_blocking_pids(pid) blocked_by,\n age(clock_timestamp(), xact_start)::interval(0) as tx_age,\n age(clock_timestamp(), (select max(l.waitstart) from pg_locks l where a.pid = l.pid))::interval(0) as wait_age\n from pg_stat_activity a\n where state is distinct from 'idle'\n), blockers as (\n select array_agg(c) as pids from (select distinct unnest(blocked_by) from activity) as dt(c)\n), tree as (\n select\n activity.*,\n 1 as level,\n activity.pid as top_blocker_pid,\n array[activity.pid] as path,\n array[activity.pid]::int[] as all_blockers_above\n from activity, blockers\n where\n array[pid] <@ blockers.pids\n and blocked_by = '{}'::int[]\n union all\n select\n activity.*,\n tree.level + 1 as level,\n tree.top_blocker_pid,\n path || array[activity.pid] as path,\n tree.all_blockers_above || array_agg(activity.pid) over () as all_blockers_above\n from activity, tree\n where\n not array[activity.pid] <@ tree.all_blockers_above\n and activity.blocked_by <> '{}'::int[]\n and activity.blocked_by <@ tree.path\n)\nselect\n pid,\n blocked_by,\n case when wait_event_type != 'Lock' then replace(state, 'idle in transaction', 'idletx') else 'waiting' end as state,\n wait_event_type || ':' || wait_event as wait,\n wait_age,\n tx_age,\n --to_char(age(backend_xid), 'FM999,999,999,990') AS xid_age,\n --to_char(2147483647 - age(backend_xmin), 'FM999,999,999,990') AS xmin_ttf,\n usename,\n datname,\n (select count(distinct t1.pid) from tree t1 where array[tree.pid] <@ t1.path and t1.pid <> tree.pid) as blkd,\n format(\n '%s %s%s',\n lpad('[' || pid::text || ']', 9, ' '),\n repeat('.', level - 1) || case when level > 1 then ' ' end,\n left(query, 1000)\n ) as query\nfrom tree\norder by top_blocker_pid, level, pid", 200 | "refId": "A", 201 | "sql": { 202 | "columns": [ 203 | { 204 | "parameters": [], 205 | "type": "function" 206 | } 207 | ], 208 | "groupBy": [ 209 | { 210 | "property": { 211 | "type": "string" 212 | }, 213 | "type": "groupBy" 214 | } 215 | ], 216 | "limit": 50 217 | } 218 | } 219 | ], 220 | "title": "Lock tree", 221 | "type": "table" 222 | } 223 | ], 224 | "refresh": "", 225 | "schemaVersion": 39, 226 | "tags": [], 227 | "templating": { 228 | "list": [] 229 | }, 230 | "time": { 231 | "from": "now-6h", 232 | "to": "now" 233 | }, 234 | "timepicker": {}, 235 | "timezone": "", 236 | "title": "Lock tree (unofficial)", 237 | "uid": "dd919736-2912-45a4-9c6b-b10b4f8ed36c", 238 | "version": 5, 239 | "weekStart": "" 240 | } -------------------------------------------------------------------------------- /playground/scripts/query_stat_total.sql: -------------------------------------------------------------------------------- 1 | -- Created and maintained by DataEgret 2 | -- https://github.com/dataegret/pg-utils/blob/master/sql/global_reports/query_stat_total_13.sql 3 | \a 4 | with pg_stat_statements_normalized as ( 5 | select *, 6 | translate( 7 | regexp_replace( 8 | regexp_replace( 9 | regexp_replace( 10 | regexp_replace(query, 11 | E'\\?(::[a-zA-Z_]+)?( *, *\\?(::[a-zA-Z_]+)?)+', '?', 'g'), 12 | E'\\$[0-9]+(::[a-zA-Z_]+)?( *, *\\$[0-9]+(::[a-zA-Z_]+)?)*', '$N', 'g'), 13 | E'--.*$', '', 'ng'), 14 | E'/\\*.*?\\*/', '', 'g'), 15 | E'\r', '') 16 | as query_normalized 17 | --if current database is postgres then generate report for all databases otherwise generate for current database only 18 | from pg_stat_statements where current_database() = 'postgres' or dbid in (SELECT oid from pg_database where datname=current_database()) 19 | ), 20 | totals as ( 21 | select sum(total_plan_time + total_exec_time) AS total_time, sum(blk_read_time+blk_write_time) as io_time, 22 | sum(total_plan_time + total_exec_time-blk_read_time-blk_write_time) as cpu_time, sum(calls) AS ncalls, 23 | sum(rows) as total_rows FROM pg_stat_statements 24 | WHERE current_database() = 'postgres' or dbid in (SELECT oid from pg_database where datname=current_database()) 25 | ), 26 | _pg_stat_statements as ( 27 | select 28 | coalesce((select datname from pg_database where oid = p.dbid), 'unknown') as database, 29 | coalesce((select rolname from pg_roles where oid = p.userid), 'unknown') as username, 30 | --select shortest query, replace \n\n-- strings to avoid email clients format text as footer 31 | substring( 32 | translate( 33 | replace( 34 | (array_agg(query order by length(query)))[1], 35 | E'-- \n', 36 | E'--\n'), 37 | E'\r', ''), 38 | 1, 8192) as query, 39 | sum(total_plan_time + total_exec_time) as total_time, 40 | sum(blk_read_time) as blk_read_time, sum(blk_write_time) as blk_write_time, 41 | sum(calls) as calls, sum(rows) as rows 42 | from pg_stat_statements_normalized p 43 | where calls > 0 44 | group by dbid, userid, md5(query_normalized) 45 | ), 46 | totals_readable as ( 47 | select to_char(interval '1 millisecond' * total_time, 'HH24:MI:SS') as total_time, 48 | (100*io_time/total_time)::numeric(20,2) AS io_time_percent, 49 | to_char(ncalls, 'FM999,999,999,990') AS total_queries, 50 | (select to_char(count(distinct md5(query)), 'FM999,999,990') from _pg_stat_statements) as unique_queries 51 | from totals 52 | ), 53 | statements as ( 54 | select 55 | (100*total_time/(select total_time from totals)) AS time_percent, 56 | (100*(blk_read_time+blk_write_time)/(select greatest(io_time, 1) from totals)) AS io_time_percent, 57 | (100*(total_time-blk_read_time-blk_write_time)/(select cpu_time from totals)) AS cpu_time_percent, 58 | to_char(interval '1 millisecond' * total_time, 'HH24:MI:SS') AS total_time, 59 | (total_time::numeric/calls)::numeric(20,2) AS avg_time, 60 | ((total_time-blk_read_time-blk_write_time)::numeric/calls)::numeric(20, 2) AS avg_cpu_time, 61 | ((blk_read_time+blk_write_time)::numeric/calls)::numeric(20, 2) AS avg_io_time, 62 | to_char(calls, 'FM999,999,999,990') AS calls, 63 | (100*calls/(select ncalls from totals))::numeric(20, 2) AS calls_percent, 64 | to_char(rows, 'FM999,999,999,990') AS rows, 65 | (100*rows/(select total_rows from totals))::numeric(20, 2) AS row_percent, 66 | database, 67 | username, 68 | query 69 | from _pg_stat_statements 70 | where ((total_time-blk_read_time-blk_write_time)/(select cpu_time from totals)>=0.01 or (blk_read_time+blk_write_time)/(select greatest(io_time, 1) from totals)>=0.01 or calls/(select ncalls from totals)>=0.02 or rows/(select total_rows from totals)>=0.02) 71 | union all 72 | select 73 | (100*sum(total_time)::numeric/(select total_time from totals)) AS time_percent, 74 | (100*sum(blk_read_time+blk_write_time)::numeric/(select greatest(io_time, 1) from totals)) AS io_time_percent, 75 | (100*sum(total_time-blk_read_time-blk_write_time)::numeric/(select cpu_time from totals)) AS cpu_time_percent, 76 | to_char(interval '1 millisecond' * sum(total_time), 'HH24:MI:SS') AS total_time, 77 | (sum(total_time)::numeric/sum(calls))::numeric(20,2) AS avg_time, 78 | (sum(total_time-blk_read_time-blk_write_time)::numeric/sum(calls))::numeric(20, 2) AS avg_cpu_time, 79 | (sum(blk_read_time+blk_write_time)::numeric/sum(calls))::numeric(20, 2) AS avg_io_time, 80 | to_char(sum(calls), 'FM999,999,999,990') AS calls, 81 | (100*sum(calls)/(select ncalls from totals))::numeric(20, 2) AS calls_percent, 82 | to_char(sum(rows), 'FM999,999,999,990') AS rows, 83 | (100*sum(rows)/(select total_rows from totals))::numeric(20, 2) AS row_percent, 84 | 'all' as database, 85 | 'all' as username, 86 | 'other' as query 87 | from _pg_stat_statements 88 | where not ((total_time-blk_read_time-blk_write_time)/(select cpu_time from totals)>=0.01 or (blk_read_time+blk_write_time)/(select greatest(io_time, 1) from totals)>=0.01 or calls/(select ncalls from totals)>=0.02 or rows/(select total_rows from totals)>=0.02) 89 | ), 90 | statements_readable as ( 91 | select row_number() over (order by s.time_percent desc) as pos, 92 | to_char(time_percent, 'FM990.0') || '%' AS time_percent, 93 | to_char(io_time_percent, 'FM990.0') || '%' AS io_time_percent, 94 | to_char(cpu_time_percent, 'FM990.0') || '%' AS cpu_time_percent, 95 | to_char(avg_io_time*100/(coalesce(nullif(avg_time, 0), 1)), 'FM990.0') || '%' AS avg_io_time_percent, 96 | total_time, avg_time, avg_cpu_time, avg_io_time, calls, calls_percent, rows, row_percent, 97 | database, username, query 98 | from statements s where calls is not null 99 | ) 100 | 101 | select E'total time:\t' || total_time || ' (IO: ' || io_time_percent || E'%)\n' || 102 | E'total queries:\t' || total_queries || ' (unique: ' || unique_queries || E')\n' || 103 | 'report for ' || (select case when current_database() = 'postgres' then 'all databases' else current_database() || ' database' end) || E', version 0.9.5' || 104 | ' @ PostgreSQL ' || (select setting from pg_settings where name='server_version') || E'\ntracking ' || (select setting from pg_settings where name='pg_stat_statements.track') || ' ' || 105 | (select setting from pg_settings where name='pg_stat_statements.max') || ' queries, utilities ' || (select setting from pg_settings where name='pg_stat_statements.track_utility') || 106 | ', logging ' || (select (case when setting = '0' then 'all' when setting = '-1' then 'none' when setting::int > 1000 then (setting::numeric/1000)::numeric(20, 1) || 's+' else setting || 'ms+' end) from pg_settings where name='log_min_duration_statement') || E' queries\n' || 107 | (select coalesce(string_agg('WARNING: database ' || datname || ' must be vacuumed within ' || to_char(2147483647 - age(datfrozenxid), 'FM999,999,999,990') || ' transactions', E'\n' order by age(datfrozenxid) desc) || E'\n', '') 108 | from pg_database where (2147483647 - age(datfrozenxid)) < 200000000) || E'\n' 109 | from totals_readable 110 | union all 111 | (select E'=============================================================================================================\n' || 112 | 'pos:' || pos || E'\t total time: ' || total_time || ' (' || time_percent || ', CPU: ' || cpu_time_percent || ', IO: ' || io_time_percent || E')\t calls: ' || calls || 113 | ' (' || calls_percent || E'%)\t avg_time: ' || avg_time || 'ms (IO: ' || avg_io_time_percent || E')\n' || 114 | 'user: ' || username || E'\t db: ' || database || E'\t rows: ' || rows || ' (' || row_percent || '%)' || E'\t query:\n' || coalesce(query, 'unknown') || E'\n' 115 | 116 | from statements_readable order by pos); 117 | \a -------------------------------------------------------------------------------- /playground/grafana/provisioning/dashboards/unofficial/query-stat-total.json: -------------------------------------------------------------------------------- 1 | { 2 | "annotations": { 3 | "list": [ 4 | { 5 | "builtIn": 1, 6 | "datasource": { 7 | "type": "postgres", 8 | "uid": "-- Grafana --" 9 | }, 10 | "enable": true, 11 | "hide": true, 12 | "iconColor": "rgba(0, 211, 255, 1)", 13 | "name": "Annotations & Alerts", 14 | "type": "dashboard" 15 | } 16 | ] 17 | }, 18 | "editable": true, 19 | "fiscalYearStartMonth": 0, 20 | "graphTooltip": 0, 21 | "id": 5, 22 | "links": [ 23 | { 24 | "asDropdown": false, 25 | "icon": "external link", 26 | "includeVars": false, 27 | "keepTime": false, 28 | "tags": [], 29 | "targetBlank": true, 30 | "title": "query_stat_total_13.sql", 31 | "tooltip": "", 32 | "type": "link", 33 | "url": "https://github.com/dataegret/pg-utils/blob/master/sql/global_reports/query_stat_total_13.sql" 34 | } 35 | ], 36 | "liveNow": false, 37 | "panels": [ 38 | { 39 | "datasource": { 40 | "type": "postgres", 41 | "uid": "P986A1B7135F49861" 42 | }, 43 | "fieldConfig": { 44 | "defaults": { 45 | "color": { 46 | "mode": "thresholds" 47 | }, 48 | "custom": { 49 | "align": "auto", 50 | "cellOptions": { 51 | "type": "auto" 52 | }, 53 | "inspect": false 54 | }, 55 | "mappings": [], 56 | "thresholds": { 57 | "mode": "absolute", 58 | "steps": [ 59 | { 60 | "color": "green", 61 | "value": null 62 | }, 63 | { 64 | "color": "red", 65 | "value": 80 66 | } 67 | ] 68 | }, 69 | "unitScale": true 70 | }, 71 | "overrides": [] 72 | }, 73 | "gridPos": { 74 | "h": 28, 75 | "w": 24, 76 | "x": 0, 77 | "y": 0 78 | }, 79 | "id": 1, 80 | "options": { 81 | "cellHeight": "sm", 82 | "footer": { 83 | "countRows": false, 84 | "fields": "", 85 | "reducer": [ 86 | "sum" 87 | ], 88 | "show": false 89 | }, 90 | "showHeader": false 91 | }, 92 | "pluginVersion": "9.3.6", 93 | "targets": [ 94 | { 95 | "datasource": { 96 | "type": "postgres", 97 | "uid": "P986A1B7135F49861" 98 | }, 99 | "editorMode": "code", 100 | "format": "table", 101 | "rawQuery": true, 102 | "rawSql": "with pg_stat_statements_normalized as (\n select *,\n translate(\n regexp_replace(\n regexp_replace(\n regexp_replace(\n regexp_replace(query,\n E'\\\\?(::[a-zA-Z_]+)?( *, *\\\\?(::[a-zA-Z_]+)?)+', '?', 'g'),\n E'\\\\$[0-9]+(::[a-zA-Z_]+)?( *, *\\\\$[0-9]+(::[a-zA-Z_]+)?)*', '$N', 'g'),\n E'--.*$', '', 'ng'),\n E'/\\\\*.*?\\\\*/', '', 'g'),\n E'\\r', '')\n as query_normalized\n --if current database is postgres then generate report for all databases otherwise generate for current database only\n from pg_stat_statements where current_database() = 'postgres' or dbid in (SELECT oid from pg_database where datname=current_database())\n),\ntotals as (\n select sum(total_plan_time + total_exec_time) AS total_time, sum(blk_read_time+blk_write_time) as io_time,\n sum(total_plan_time + total_exec_time-blk_read_time-blk_write_time) as cpu_time, sum(calls) AS ncalls,\n sum(rows) as total_rows FROM pg_stat_statements\n WHERE current_database() = 'postgres' or dbid in (SELECT oid from pg_database where datname=current_database())\n),\n_pg_stat_statements as (\n select\n coalesce((select datname from pg_database where oid = p.dbid), 'unknown') as database,\n coalesce((select rolname from pg_roles where oid = p.userid), 'unknown') as username,\n --select shortest query, replace \\n\\n-- strings to avoid email clients format text as footer\n substring(\n translate(\n replace(\n (array_agg(query order by length(query)))[1],\n E'-- \\n',\n E'--\\n'),\n E'\\r', ''),\n 1, 8192) as query,\n sum(total_plan_time + total_exec_time) as total_time,\n sum(blk_read_time) as blk_read_time, sum(blk_write_time) as blk_write_time,\n sum(calls) as calls, sum(rows) as rows\n from pg_stat_statements_normalized p\n where calls > 0\n group by dbid, userid, md5(query_normalized)\n),\ntotals_readable as (\n select to_char(interval '1 millisecond' * total_time, 'HH24:MI:SS') as total_time,\n (100*io_time/total_time)::numeric(20,2) AS io_time_percent,\n to_char(ncalls, 'FM999,999,999,990') AS total_queries,\n (select to_char(count(distinct md5(query)), 'FM999,999,990') from _pg_stat_statements) as unique_queries\n from totals\n),\nstatements as (\n select\n (100*total_time/(select total_time from totals)) AS time_percent,\n (100*(blk_read_time+blk_write_time)/(select greatest(io_time, 1) from totals)) AS io_time_percent,\n (100*(total_time-blk_read_time-blk_write_time)/(select cpu_time from totals)) AS cpu_time_percent,\n to_char(interval '1 millisecond' * total_time, 'HH24:MI:SS') AS total_time,\n (total_time::numeric/calls)::numeric(20,2) AS avg_time,\n ((total_time-blk_read_time-blk_write_time)::numeric/calls)::numeric(20, 2) AS avg_cpu_time,\n ((blk_read_time+blk_write_time)::numeric/calls)::numeric(20, 2) AS avg_io_time,\n to_char(calls, 'FM999,999,999,990') AS calls,\n (100*calls/(select ncalls from totals))::numeric(20, 2) AS calls_percent,\n to_char(rows, 'FM999,999,999,990') AS rows,\n (100*rows/(select total_rows from totals))::numeric(20, 2) AS row_percent,\n database,\n username,\n query\n from _pg_stat_statements\n where ((total_time-blk_read_time-blk_write_time)/(select cpu_time from totals)>=0.01 or (blk_read_time+blk_write_time)/(select greatest(io_time, 1) from totals)>=0.01 or calls/(select ncalls from totals)>=0.02 or rows/(select total_rows from totals)>=0.02)\nunion all\n select\n (100*sum(total_time)::numeric/(select total_time from totals)) AS time_percent,\n (100*sum(blk_read_time+blk_write_time)::numeric/(select greatest(io_time, 1) from totals)) AS io_time_percent,\n (100*sum(total_time-blk_read_time-blk_write_time)::numeric/(select cpu_time from totals)) AS cpu_time_percent,\n to_char(interval '1 millisecond' * sum(total_time), 'HH24:MI:SS') AS total_time,\n (sum(total_time)::numeric/sum(calls))::numeric(20,2) AS avg_time,\n (sum(total_time-blk_read_time-blk_write_time)::numeric/sum(calls))::numeric(20, 2) AS avg_cpu_time,\n (sum(blk_read_time+blk_write_time)::numeric/sum(calls))::numeric(20, 2) AS avg_io_time,\n to_char(sum(calls), 'FM999,999,999,990') AS calls,\n (100*sum(calls)/(select ncalls from totals))::numeric(20, 2) AS calls_percent,\n to_char(sum(rows), 'FM999,999,999,990') AS rows,\n (100*sum(rows)/(select total_rows from totals))::numeric(20, 2) AS row_percent,\n 'all' as database,\n 'all' as username,\n 'other' as query\n from _pg_stat_statements\n where not ((total_time-blk_read_time-blk_write_time)/(select cpu_time from totals)>=0.01 or (blk_read_time+blk_write_time)/(select greatest(io_time, 1) from totals)>=0.01 or calls/(select ncalls from totals)>=0.02 or rows/(select total_rows from totals)>=0.02)\n),\nstatements_readable as (\n select row_number() over (order by s.time_percent desc) as pos,\n to_char(time_percent, 'FM990.0') || '%' AS time_percent,\n to_char(io_time_percent, 'FM990.0') || '%' AS io_time_percent,\n to_char(cpu_time_percent, 'FM990.0') || '%' AS cpu_time_percent,\n to_char(avg_io_time*100/(coalesce(nullif(avg_time, 0), 1)), 'FM990.0') || '%' AS avg_io_time_percent,\n total_time, avg_time, avg_cpu_time, avg_io_time, calls, calls_percent, rows, row_percent,\n database, username, query\n from statements s where calls is not null\n),\n_ (s) AS (\nselect E'total time:\\t' || total_time || ' (IO: ' || io_time_percent || E'%)\\n' ||\nE'total queries:\\t' || total_queries || ' (unique: ' || unique_queries || E')\\n' ||\n'report for ' || (select case when current_database() = 'postgres' then 'all databases' else current_database() || ' database' end) || E', version 0.9.5' ||\n' @ PostgreSQL ' || (select setting from pg_settings where name='server_version') || E'\\ntracking ' || (select setting from pg_settings where name='pg_stat_statements.track') || ' ' ||\n(select setting from pg_settings where name='pg_stat_statements.max') || ' queries, utilities ' || (select setting from pg_settings where name='pg_stat_statements.track_utility') ||\n', logging ' || (select (case when setting = '0' then 'all' when setting = '-1' then 'none' when setting::int > 1000 then (setting::numeric/1000)::numeric(20, 1) || 's+' else setting || 'ms+' end) from pg_settings where name='log_min_duration_statement') || E' queries\\n' ||\n(select coalesce(string_agg('WARNING: database ' || datname || ' must be vacuumed within ' || to_char(2147483647 - age(datfrozenxid), 'FM999,999,999,990') || ' transactions', E'\\n' order by age(datfrozenxid) desc) || E'\\n', '')\n from pg_database where (2147483647 - age(datfrozenxid)) < 200000000) || E'\\n'\nfrom totals_readable\nunion all\n(select E'=============================================================================================================\\n' ||\n'pos:' || pos || E'\\t total time: ' || total_time || ' (' || time_percent || ', CPU: ' || cpu_time_percent || ', IO: ' || io_time_percent || E')\\t calls: ' || calls ||\n' (' || calls_percent || E'%)\\t avg_time: ' || avg_time || 'ms (IO: ' || avg_io_time_percent || E')\\n' ||\n'user: ' || username || E'\\t db: ' || database || E'\\t rows: ' || rows || ' (' || row_percent || '%)' || E'\\t query:\\n' || coalesce(query, 'unknown') || E'\\n'\n\nfrom statements_readable order by pos)\n)\nSELECT unnest(string_to_array(s, E'\\n')) as report from _\n", 103 | "refId": "A", 104 | "sql": { 105 | "columns": [ 106 | { 107 | "parameters": [], 108 | "type": "function" 109 | } 110 | ], 111 | "groupBy": [ 112 | { 113 | "property": { 114 | "type": "string" 115 | }, 116 | "type": "groupBy" 117 | } 118 | ], 119 | "limit": 50 120 | } 121 | } 122 | ], 123 | "title": "report", 124 | "type": "table" 125 | } 126 | ], 127 | "refresh": "", 128 | "schemaVersion": 39, 129 | "tags": [], 130 | "templating": { 131 | "list": [] 132 | }, 133 | "time": { 134 | "from": "now-6h", 135 | "to": "now" 136 | }, 137 | "timepicker": {}, 138 | "timezone": "", 139 | "title": "Query stat total (unofficial)", 140 | "uid": "c5f3eea4-501c-439d-8873-1cc9e52314e7", 141 | "version": 3, 142 | "weekStart": "" 143 | } 144 | --------------------------------------------------------------------------------