Skip to content
This repository was archived by the owner on Dec 17, 2024. It is now read-only.

Commit 9123adc

Browse files
committed
new metrics (locks, blocking_locks) + config DB owned and accessed by a separate user (was postgres)
1 parent 6ca8aa1 commit 9123adc

File tree

9 files changed

+154
-105
lines changed

9 files changed

+154
-105
lines changed

pg_hba.conf

+3-3
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,5 @@
1-
local all postgres trust
2-
host all postgres 127.0.0.1/32 trust
3-
host all postgres ::1/128 trust
1+
local all all trust
2+
host all all 127.0.0.1/32 trust
3+
host all all ::1/128 trust
44
host all all 0.0.0.0/0 md5
55
host all all ::0/0 md5

pgwatch2/bootstrap/change_pw.sql

+3-1
Original file line numberDiff line numberDiff line change
@@ -1 +1,3 @@
1-
ALTER ROLE postgres PASSWORD 'pgwatch2admin';
1+
CREATE ROLE pgwatch2 WITH LOGIN PASSWORD 'pgwatch2admin'; -- NB! change the pw for production
2+
3+
alter role pgwatch2 set statement_timeout to '5s';
+1-1
Original file line numberDiff line numberDiff line change
@@ -1 +1 @@
1-
CREATE DATABASE pgwatch2;
1+
CREATE DATABASE pgwatch2 OWNER pgwatch2;

pgwatch2/pgwatch2.go

+1-1
Original file line numberDiff line numberDiff line change
@@ -556,7 +556,7 @@ var opts struct {
556556
Host string `short:"h" long:"host" description:"PG config DB host" default:"localhost"`
557557
Port string `short:"p" long:"port" description:"PG config DB port" default:"5432"`
558558
Dbname string `short:"d" long:"dbname" description:"PG config DB dbname" default:"pgwatch2"`
559-
User string `short:"u" long:"user" description:"PG config DB host" default:"postgres"`
559+
User string `short:"u" long:"user" description:"PG config DB host" default:"pgwatch2"`
560560
Password string `long:"password" description:"PG config DB password"`
561561
InfluxURL string `long:"iurl" description:"Influx address" default:"http://localhost:8086"`
562562
InfluxDbname string `long:"idbname" description:"Influx DB name" default:"pgwatch2"`

pgwatch2/sql/datastore_setup/config_store.sql

+111-25
Original file line numberDiff line numberDiff line change
@@ -1,11 +1,15 @@
1-
create schema if not exists pgwatch2;
1+
create schema if not exists pgwatch2 authorization pgwatch2;
22

3-
create extension if not exists pg_stat_statements SCHEMA public;
3+
create extension if not exists pg_stat_statements SCHEMA public; -- NB! for demo purposes only, can fail
4+
5+
create extension if not exists plpythonu SCHEMA public; -- NB! for demo purposes only, to enable CPU load gathering
46

57
set search_path to pgwatch2, public;
68

79
alter database pgwatch2 set search_path to pgwatch2, public;
810

11+
set role to pgwatch2; -- NB! Role/db create script is in bootstrap/create_db_pgwatch.sql
12+
913
drop table if exists preset_config cascade;
1014

1115
/* preset configs for typical usecases */
@@ -81,8 +85,9 @@ alter table pgwatch2.monitored_db add constraint preset_or_custom_config check
8185
((not (md_preset_config_name is null and md_config is null))
8286
and not (md_preset_config_name is not null and md_config is not null));
8387

88+
/* for demo purposes only */
8489
insert into pgwatch2.monitored_db (md_unique_name, md_preset_config_name, md_config, md_hostname, md_port, md_dbname, md_user, md_password)
85-
values ('test', 'exhaustive', null, 'localhost', '5432', 'pgwatch2', 'postgres', 'pgwatch2admin');
90+
values ('test', 'exhaustive', null, 'localhost', '5432', 'pgwatch2', 'pgwatch2', 'pgwatch2admin');
8691

8792

8893
create table pgwatch2.metric (
@@ -97,7 +102,7 @@ create table pgwatch2.metric (
97102

98103
/* backends */
99104

100-
insert into metric(m_name, m_pg_version_from,m_sql)
105+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
101106
values (
102107
'backends',
103108
9.0,
@@ -119,7 +124,7 @@ select
119124
$sql$
120125
);
121126

122-
insert into metric(m_name, m_pg_version_from,m_sql)
127+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
123128
values (
124129
'backends',
125130
9.6,
@@ -143,7 +148,7 @@ $sql$
143148

144149
/* bgwriter */
145150

146-
insert into metric(m_name, m_pg_version_from,m_sql)
151+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
147152
values (
148153
'bgwriter',
149154
9.0,
@@ -167,7 +172,7 @@ $sql$
167172

168173
/* cpu_load */
169174

170-
insert into metric(m_name, m_pg_version_from,m_sql)
175+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
171176
values (
172177
'cpu_load',
173178
9.0,
@@ -185,7 +190,7 @@ $sql$
185190

186191
/* db_stats */
187192

188-
insert into metric(m_name, m_pg_version_from,m_sql)
193+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
189194
values (
190195
'db_stats',
191196
9.0,
@@ -218,7 +223,7 @@ $sql$
218223

219224
/* index_stats */
220225

221-
insert into metric(m_name, m_pg_version_from,m_sql)
226+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
222227
values (
223228
'index_stats',
224229
9.0,
@@ -245,7 +250,7 @@ $sql$
245250

246251
/* kpi */
247252

248-
insert into metric(m_name, m_pg_version_from,m_sql)
253+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
249254
values (
250255
'kpi',
251256
9.0,
@@ -290,7 +295,7 @@ $sql$
290295

291296
/* kpi */
292297

293-
insert into metric(m_name, m_pg_version_from,m_sql)
298+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
294299
values (
295300
'kpi',
296301
9.6,
@@ -336,7 +341,7 @@ $sql$
336341

337342
/* replication */
338343

339-
insert into metric(m_name, m_pg_version_from,m_sql)
344+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
340345
values (
341346
'replication',
342347
9.1,
@@ -354,7 +359,7 @@ $sql$
354359

355360
/* sproc_stats */
356361

357-
insert into metric(m_name, m_pg_version_from,m_sql)
362+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
358363
values (
359364
'sproc_stats',
360365
9.0,
@@ -378,7 +383,7 @@ $sql$
378383

379384
/* table_io_stats */
380385

381-
insert into metric(m_name, m_pg_version_from,m_sql)
386+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
382387
values (
383388
'table_io_stats',
384389
9.0,
@@ -405,7 +410,7 @@ $sql$
405410

406411
/* table_stats */
407412

408-
insert into metric(m_name, m_pg_version_from,m_sql)
413+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
409414
values (
410415
'table_stats',
411416
9.0,
@@ -415,7 +420,7 @@ select
415420
schemaname::text as tag_schema,
416421
relname::text as tag_table_name,
417422
pg_relation_size(relid) as table_size_b,
418-
pg_total_relation_size(relid) as total_relation_size_b,
423+
pg_total_relation_size(relid) as total_relation_size_b, --TODO add approx as pg_total_relation_size uses locks and can block
419424
extract(epoch from now() - greatest(last_vacuum, last_autovacuum)) as seconds_since_last_vacuum,
420425
extract(epoch from now() - greatest(last_analyze, last_autoanalyze)) as seconds_since_last_analyze,
421426
seq_scan,
@@ -433,13 +438,14 @@ select
433438
from
434439
pg_stat_user_tables
435440
where
436-
not schemaname like E'pg\\_temp%';
441+
not schemaname like E'pg\\_temp%'
442+
and not exists (select 1 from pg_locks where relation = relid and locktype = 'AccessExclusiveLock' and granted);
437443
$sql$
438444
);
439445

440446
/* wal */
441447

442-
insert into metric(m_name, m_pg_version_from,m_sql)
448+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
443449
values (
444450
'wal',
445451
9.2,
@@ -453,7 +459,7 @@ $sql$
453459

454460
/* stat_statements */
455461

456-
insert into metric(m_name, m_pg_version_from,m_sql)
462+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
457463
values (
458464
'stat_statements',
459465
9.2,
@@ -462,7 +468,7 @@ with q_data as (
462468
select
463469
(extract(epoch from now()) * 1e9)::int8 as epoch_ns,
464470
queryid::text as tag_queryid,
465-
max(ltrim(regexp_replace(query, E'[ \\t\\n\\r]+' , ' ', 'g'))) as query,
471+
max(ltrim(regexp_replace(query, E'[ \\t\\n\\r]+' , ' ', 'g'))) as tag_query,
466472
sum(s.calls)::int8 as calls,
467473
sum(s.total_time)::double precision as total_time,
468474
sum(shared_blks_hit)::int8 as shared_blks_hit,
@@ -471,7 +477,7 @@ with q_data as (
471477
sum(temp_blks_read)::int8 as temp_blks_read,
472478
sum(temp_blks_written)::int8 as temp_blks_written
473479
from
474-
public.pg_stat_statements s
480+
public.get_stat_statements() s
475481
where
476482
calls > 1
477483
and total_time > 0
@@ -555,7 +561,7 @@ $sql$
555561

556562

557563
/* buffercache_by_db */
558-
insert into metric(m_name, m_pg_version_from,m_sql)
564+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
559565
values (
560566
'buffercache_by_db',
561567
9.2,
@@ -575,7 +581,7 @@ $sql$
575581
);
576582

577583
/* buffercache_by_type */
578-
insert into metric(m_name, m_pg_version_from,m_sql)
584+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
579585
values (
580586
'buffercache_by_type',
581587
9.2,
@@ -596,7 +602,7 @@ $sql$
596602

597603

598604
/* pg_stat_ssl */ -- join with backends?
599-
insert into metric(m_name, m_pg_version_from,m_sql)
605+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
600606
values (
601607
'pg_stat_ssl',
602608
9.5,
@@ -618,7 +624,7 @@ $sql$
618624

619625

620626
/* pg_stat_database_conflicts */
621-
insert into metric(m_name, m_pg_version_from,m_sql)
627+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
622628
values (
623629
'pg_stat_database_conflicts',
624630
9.2,
@@ -637,3 +643,83 @@ WHERE
637643
$sql$
638644
);
639645

646+
647+
/* locks - counts only */
648+
649+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
650+
values (
651+
'locks',
652+
9.0,
653+
$sql$
654+
WITH q_locks AS (
655+
select
656+
*
657+
from
658+
pg_locks
659+
where
660+
pid != pg_backend_pid()
661+
and database = (select oid from pg_database where datname = current_database())
662+
)
663+
SELECT
664+
(extract(epoch from now()) * 1e9)::int8 as epoch_ns,
665+
locktypes AS tag_locktype,
666+
coalesce((select count(*) FROM q_locks WHERE locktype = locktypes), 0) AS count
667+
FROM
668+
unnest('{relation, extend, page, tuple, transactionid, virtualxid, object, userlock, advisory}'::text[]) locktypes;
669+
$sql$
670+
);
671+
672+
673+
/* blocking_locks - based on https://wiki.postgresql.org/wiki/Lock_dependency_information.
674+
not sure if it makes sense though, locks are quite volatile normally */
675+
676+
insert into pgwatch2.metric(m_name, m_pg_version_from,m_sql)
677+
values (
678+
'blocking_locks',
679+
9.2,
680+
$sql$
681+
SELECT
682+
(extract(epoch from now()) * 1e9)::int8 AS epoch_ns,
683+
waiting.locktype AS tag_waiting_locktype,
684+
waiting_stm.usename AS tag_waiting_user,
685+
coalesce(waiting.mode, 'null'::text) AS tag_waiting_mode,
686+
coalesce(waiting.relation::regclass::text, 'null') AS tag_waiting_table,
687+
waiting_stm.query AS waiting_query,
688+
waiting.pid AS waiting_pid,
689+
other.locktype AS other_locktype,
690+
other.relation::regclass AS other_table,
691+
other_stm.query AS other_query,
692+
other.mode AS other_mode,
693+
other.pid AS other_pid,
694+
other_stm.usename AS other_user
695+
FROM
696+
pg_catalog.pg_locks AS waiting
697+
JOIN
698+
pg_catalog.pg_stat_activity AS waiting_stm
699+
ON (
700+
waiting_stm.pid = waiting.pid
701+
)
702+
JOIN
703+
pg_catalog.pg_locks AS other
704+
ON (
705+
(
706+
waiting."database" = other."database"
707+
AND waiting.relation = other.relation
708+
)
709+
OR waiting.transactionid = other.transactionid
710+
)
711+
JOIN
712+
pg_catalog.pg_stat_activity AS other_stm
713+
ON (
714+
other_stm.pid = other.pid
715+
)
716+
WHERE
717+
NOT waiting.GRANTED
718+
AND
719+
waiting.pid <> other.pid
720+
AND
721+
other.GRANTED
722+
AND
723+
waiting_stm.datname = current_database();
724+
$sql$
725+
);

0 commit comments

Comments
 (0)