1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485
|
/*
// pg_statviz - stats visualization and time series analysis
//
// Copyright (c) 2025 Jimmy Angelakos
// This software is released under the PostgreSQL Licence
//
// pg_statviz--0.7 - Release v0.7
*/
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "CREATE EXTENSION pg_statviz" to load this file. \quit
CREATE TABLE IF NOT EXISTS @extschema@.snapshots(
snapshot_tstamp timestamptz PRIMARY KEY
);
-- Buffers and checkpoints
CREATE TABLE IF NOT EXISTS @extschema@.buf(
snapshot_tstamp timestamptz REFERENCES @extschema@.snapshots(snapshot_tstamp) ON DELETE CASCADE PRIMARY KEY,
checkpoints_timed bigint,
checkpoints_req bigint,
checkpoint_write_time double precision,
checkpoint_sync_time double precision,
buffers_checkpoint bigint,
buffers_clean bigint,
maxwritten_clean bigint,
buffers_backend bigint,
buffers_backend_fsync bigint,
buffers_alloc bigint,
stats_reset timestamptz);
-- PG17+ moved things out of pg_stat_bgwriter
DO $block$
BEGIN
IF (SELECT current_setting('server_version_num')::int >= 170000) THEN
CREATE OR REPLACE FUNCTION @extschema@.snapshot_buf(snapshot_tstamp timestamptz)
RETURNS void
AS $$
INSERT INTO @extschema@.buf (
snapshot_tstamp,
checkpoints_timed,
checkpoints_req,
checkpoint_write_time,
checkpoint_sync_time,
buffers_checkpoint,
buffers_clean,
maxwritten_clean,
buffers_backend,
buffers_backend_fsync,
buffers_alloc,
stats_reset)
SELECT
snapshot_tstamp,
c.num_timed,
c.num_requested,
c.write_time,
c.sync_time,
c.buffers_written,
b.buffers_clean,
b.maxwritten_clean,
i.writes,
i.fsyncs,
b.buffers_alloc,
b.stats_reset
FROM pg_stat_bgwriter b, pg_stat_checkpointer c, pg_stat_io i
WHERE i.backend_type = 'client backend'
AND i.context = 'normal'
AND i.object = 'relation';
$$ LANGUAGE SQL;
ELSE
CREATE OR REPLACE FUNCTION @extschema@.snapshot_buf(snapshot_tstamp timestamptz)
RETURNS void
AS $$
INSERT INTO @extschema@.buf (
snapshot_tstamp,
checkpoints_timed,
checkpoints_req,
checkpoint_write_time,
checkpoint_sync_time,
buffers_checkpoint,
buffers_clean,
maxwritten_clean,
buffers_backend,
buffers_backend_fsync,
buffers_alloc,
stats_reset)
SELECT
snapshot_tstamp,
checkpoints_timed,
checkpoints_req,
checkpoint_write_time,
checkpoint_sync_time,
buffers_checkpoint,
buffers_clean,
maxwritten_clean,
buffers_backend,
buffers_backend_fsync,
buffers_alloc,
stats_reset
FROM pg_stat_bgwriter;
$$ LANGUAGE SQL;
END IF;
END
$block$ LANGUAGE PLPGSQL;
-- Configuration
CREATE TABLE IF NOT EXISTS @extschema@.conf(
snapshot_tstamp timestamptz REFERENCES @extschema@.snapshots(snapshot_tstamp) ON DELETE CASCADE PRIMARY KEY,
conf jsonb);
CREATE OR REPLACE FUNCTION @extschema@.snapshot_conf(snapshot_tstamp timestamptz)
RETURNS void
AS $$
INSERT INTO @extschema@.conf (
snapshot_tstamp,
conf)
SELECT
snapshot_tstamp,
jsonb_object_agg("variable", "value")
FROM (
SELECT "name" AS "variable",
"setting" AS "value"
FROM pg_settings
WHERE "name" IN (
'autovacuum',
'autovacuum_max_workers',
'autovacuum_naptime',
'autovacuum_work_mem',
'bgwriter_delay',
'bgwriter_lru_maxpages',
'bgwriter_lru_multiplier',
'checkpoint_completion_target',
'checkpoint_timeout',
'max_connections',
'max_wal_size',
'max_wal_senders',
'work_mem',
'maintenance_work_mem',
'max_replication_slots',
'max_parallel_workers',
'max_parallel_maintenance_workers',
'server_version_num',
'shared_buffers',
'vacuum_cost_delay',
'vacuum_cost_limit')) s;
$$ LANGUAGE SQL;
-- Connections
CREATE TABLE IF NOT EXISTS @extschema@.conn(
snapshot_tstamp timestamptz REFERENCES @extschema@.snapshots(snapshot_tstamp) ON DELETE CASCADE PRIMARY KEY,
conn_total int,
conn_active int,
conn_idle int,
conn_idle_trans int,
conn_idle_trans_abort int,
conn_fastpath int,
conn_users jsonb);
CREATE OR REPLACE FUNCTION @extschema@.snapshot_conn(snapshot_tstamp timestamptz)
RETURNS void
AS $$
WITH
pgsa AS (
SELECT *
FROM pg_stat_activity
WHERE datname = current_database()
AND state IS NOT NULL),
userconns AS (
SELECT jsonb_agg(uc)
FROM (
SELECT usename AS user, count(*) AS connections
FROM pgsa
WHERE usename IS NOT NULL
GROUP BY usename) uc)
INSERT INTO @extschema@.conn (
snapshot_tstamp,
conn_total,
conn_active,
conn_idle,
conn_idle_trans,
conn_idle_trans_abort,
conn_fastpath,
conn_users)
SELECT
snapshot_tstamp,
count(*) AS conn_total,
count(*) FILTER (WHERE state = 'active') AS conn_active,
count(*) FILTER (WHERE state = 'idle') AS conn_idle,
count(*) FILTER (WHERE state = 'idle in transaction') AS conn_idle_trans,
count(*) FILTER (WHERE state = 'idle in transaction (aborted)') AS conn_idle_trans_abort,
count(*) FILTER (WHERE state = 'fastpath function call') AS conn_fastpath,
(SELECT * from userconns) AS conn_users
FROM pgsa;
$$ LANGUAGE SQL;
-- Locks
CREATE TABLE IF NOT EXISTS @extschema@.lock(
snapshot_tstamp timestamptz REFERENCES @extschema@.snapshots(snapshot_tstamp) ON DELETE CASCADE PRIMARY KEY,
locks_total int,
locks jsonb);
CREATE OR REPLACE FUNCTION @extschema@.snapshot_lock(snapshot_tstamp timestamptz)
RETURNS void
AS $$
WITH
pgl AS (
SELECT *
FROM pg_locks l, pg_database d
WHERE d.datname = current_database()
AND l.database = oid
AND locktype = 'relation'
AND pid != pg_backend_pid()), -- ignore snapshot session
lcks AS (
SELECT coalesce(jsonb_agg(l), '[]'::jsonb)
FROM (
SELECT mode AS lock_mode, count(*) AS lock_count
FROM pgl
GROUP BY lock_mode) l)
INSERT INTO @extschema@.lock (
snapshot_tstamp,
locks_total,
locks)
SELECT
snapshot_tstamp,
count(*) AS locks_total,
(SELECT * from lcks) AS locks
FROM pgl;
$$ LANGUAGE SQL;
-- Wait events
CREATE TABLE IF NOT EXISTS @extschema@.wait(
snapshot_tstamp timestamptz REFERENCES @extschema@.snapshots(snapshot_tstamp) ON DELETE CASCADE PRIMARY KEY,
wait_events_total int,
wait_events jsonb);
CREATE OR REPLACE FUNCTION @extschema@.snapshot_wait(snapshot_tstamp timestamptz)
RETURNS void
AS $$
WITH
pgsa AS (
SELECT *
FROM pg_stat_activity
WHERE datname = current_database()
AND state = 'active'
AND wait_event IS NOT NULL),
waitevents AS (
SELECT coalesce(jsonb_agg(we), '[]'::jsonb)
FROM (
SELECT wait_event_type, wait_event, count(*) AS wait_event_count
FROM pgsa
GROUP BY wait_event_type, wait_event) we)
INSERT INTO @extschema@.wait (
snapshot_tstamp,
wait_events_total,
wait_events)
SELECT
snapshot_tstamp,
count(*) AS wait_events_total,
(SELECT * from waitevents) AS wait_events
FROM pgsa;
$$ LANGUAGE SQL;
-- WAL
CREATE TABLE IF NOT EXISTS @extschema@.wal(
snapshot_tstamp timestamptz REFERENCES @extschema@.snapshots(snapshot_tstamp) ON DELETE CASCADE PRIMARY KEY,
wal_records bigint,
wal_fpi bigint,
wal_bytes numeric,
wal_buffers_full bigint,
wal_write bigint,
wal_sync bigint,
wal_write_time double precision,
wal_sync_time double precision,
stats_reset timestamptz);
-- pg_stat_wal only exists in PG14+
DO $block$
BEGIN
IF (SELECT current_setting('server_version_num')::int >= 140000) THEN
CREATE OR REPLACE FUNCTION @extschema@.snapshot_wal(snapshot_tstamp timestamptz)
RETURNS void
AS $$
INSERT INTO @extschema@.wal (
snapshot_tstamp,
wal_records,
wal_fpi,
wal_bytes,
wal_buffers_full,
wal_write,
wal_sync,
wal_write_time,
wal_sync_time,
stats_reset)
SELECT
snapshot_tstamp,
wal_records,
wal_fpi,
wal_bytes,
wal_buffers_full,
wal_write,
wal_sync,
wal_write_time,
wal_sync_time,
stats_reset
FROM pg_stat_wal;
$$ LANGUAGE SQL;
END IF;
END
$block$ LANGUAGE PLPGSQL;
-- DB
CREATE TABLE IF NOT EXISTS @extschema@.db(
snapshot_tstamp timestamptz REFERENCES @extschema@.snapshots(snapshot_tstamp) ON DELETE CASCADE PRIMARY KEY,
xact_commit bigint,
xact_rollback bigint,
blks_read bigint,
blks_hit bigint,
tup_returned bigint,
tup_fetched bigint,
tup_inserted bigint,
tup_updated bigint,
tup_deleted bigint,
temp_files bigint,
temp_bytes bigint,
block_size int,
stats_reset timestamptz,
postmaster_start_time timestamptz);
CREATE OR REPLACE FUNCTION @extschema@.snapshot_db(snapshot_tstamp timestamptz)
RETURNS void
AS $$
INSERT INTO @extschema@.db (
snapshot_tstamp,
xact_commit,
xact_rollback,
blks_read,
blks_hit,
tup_returned,
tup_fetched,
tup_inserted,
tup_updated,
tup_deleted,
temp_files,
temp_bytes,
stats_reset,
block_size,
postmaster_start_time)
SELECT
snapshot_tstamp,
xact_commit,
xact_rollback,
blks_read,
blks_hit,
tup_returned,
tup_fetched,
tup_inserted,
tup_updated,
tup_deleted,
temp_files,
temp_bytes,
stats_reset,
current_setting('block_size')::int,
pg_postmaster_start_time()
FROM pg_stat_database
WHERE datname = current_database();
$$ LANGUAGE SQL;
-- I/O
CREATE TABLE IF NOT EXISTS @extschema@.io(
snapshot_tstamp timestamptz REFERENCES @extschema@.snapshots(snapshot_tstamp) ON DELETE CASCADE PRIMARY KEY,
io_stats jsonb,
stats_reset timestamptz);
-- pg_stat_io only exists in PG16+
DO $block$
BEGIN
IF (SELECT current_setting('server_version_num')::int >= 160000) THEN
CREATE OR REPLACE FUNCTION @extschema@.snapshot_io(snapshot_tstamp timestamptz)
RETURNS void
AS $$
WITH
pgsi AS (
SELECT
backend_type,
object,
context,
reads,
read_time,
writes,
write_time,
writebacks,
writeback_time,
extends,
extend_time,
hits,
evictions,
reuses,
fsyncs,
fsync_time,
stats_reset
FROM pg_stat_io
WHERE NOT (reads = 0 AND writes = 0)),
ioagg AS (
SELECT jsonb_agg(io)
FROM (SELECT *
FROM pgsi) io)
INSERT INTO @extschema@.io (
snapshot_tstamp,
io_stats,
stats_reset)
SELECT snapshot_tstamp,
(SELECT * FROM ioagg) AS io_stats,
(SELECT stats_reset FROM pgsi LIMIT 1) AS stats_reset;
$$ LANGUAGE SQL;
END IF;
END
$block$ LANGUAGE PLPGSQL;
-- Snapshots
CREATE OR REPLACE FUNCTION @extschema@.snapshot()
RETURNS timestamptz
AS $$
DECLARE ts timestamptz;
BEGIN
ts := clock_timestamp();
INSERT INTO @extschema@.snapshots
VALUES (ts);
PERFORM @extschema@.snapshot_buf(ts);
PERFORM @extschema@.snapshot_conf(ts);
PERFORM @extschema@.snapshot_conn(ts);
PERFORM @extschema@.snapshot_db(ts);
-- pg_stat_io only exists in PG16+
IF (SELECT current_setting('server_version_num')::int >= 160000) THEN
PERFORM @extschema@.snapshot_io(ts);
END IF;
PERFORM @extschema@.snapshot_lock(ts);
PERFORM @extschema@.snapshot_wait(ts);
-- pg_stat_wal only exists in PG14+
IF (SELECT current_setting('server_version_num')::int >= 140000) THEN
PERFORM @extschema@.snapshot_wal(ts);
END IF;
RAISE NOTICE 'created pg_statviz snapshot';
RETURN ts;
END
$$ LANGUAGE PLPGSQL;
CREATE OR REPLACE FUNCTION @extschema@.delete_snapshots()
RETURNS void
AS $$
BEGIN
RAISE NOTICE 'truncating table "snapshots"';
TRUNCATE @extschema@.snapshots CASCADE;
END
$$ LANGUAGE PLPGSQL;
-- Make tables dumpable
SELECT pg_catalog.pg_extension_config_dump('pgstatviz.buf', '');
SELECT pg_catalog.pg_extension_config_dump('pgstatviz.conf', '');
SELECT pg_catalog.pg_extension_config_dump('pgstatviz.conn', '');
SELECT pg_catalog.pg_extension_config_dump('pgstatviz.db', '');
SELECT pg_catalog.pg_extension_config_dump('pgstatviz.io', '');
SELECT pg_catalog.pg_extension_config_dump('pgstatviz.lock', '');
SELECT pg_catalog.pg_extension_config_dump('pgstatviz.snapshots', '');
SELECT pg_catalog.pg_extension_config_dump('pgstatviz.wait', '');
SELECT pg_catalog.pg_extension_config_dump('pgstatviz.wal', '');
-- Permissions
GRANT USAGE ON SCHEMA @extschema@ TO pg_monitor;
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA @extschema@ TO pg_monitor;
GRANT SELECT ON ALL TABLES IN SCHEMA @extschema@ TO pg_monitor;
GRANT INSERT ON ALL TABLES IN SCHEMA @extschema@ TO pg_monitor;
GRANT DELETE ON ALL TABLES IN SCHEMA @extschema@ TO pg_monitor;
GRANT TRUNCATE ON ALL TABLES IN SCHEMA @extschema@ TO pg_monitor;
|