1
- create schema if not exists pgwatch2;
1
+ create schema if not exists pgwatch2 authorization pgwatch2 ;
2
2
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
4
6
5
7
set search_path to pgwatch2, public;
6
8
7
9
alter database pgwatch2 set search_path to pgwatch2, public;
8
10
11
+ set role to pgwatch2; -- NB! Role/db create script is in bootstrap/create_db_pgwatch.sql
12
+
9
13
drop table if exists preset_config cascade;
10
14
11
15
/* preset configs for typical usecases */
@@ -81,8 +85,9 @@ alter table pgwatch2.monitored_db add constraint preset_or_custom_config check
81
85
((not (md_preset_config_name is null and md_config is null ))
82
86
and not (md_preset_config_name is not null and md_config is not null ));
83
87
88
+ /* for demo purposes only */
84
89
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' );
86
91
87
92
88
93
create table pgwatch2 .metric (
@@ -97,7 +102,7 @@ create table pgwatch2.metric (
97
102
98
103
/* backends */
99
104
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)
101
106
values (
102
107
' backends' ,
103
108
9 .0 ,
@@ -119,7 +124,7 @@ select
119
124
$sql$
120
125
);
121
126
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)
123
128
values (
124
129
' backends' ,
125
130
9 .6 ,
@@ -143,7 +148,7 @@ $sql$
143
148
144
149
/* bgwriter */
145
150
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)
147
152
values (
148
153
' bgwriter' ,
149
154
9 .0 ,
@@ -167,7 +172,7 @@ $sql$
167
172
168
173
/* cpu_load */
169
174
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)
171
176
values (
172
177
' cpu_load' ,
173
178
9 .0 ,
@@ -185,7 +190,7 @@ $sql$
185
190
186
191
/* db_stats */
187
192
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)
189
194
values (
190
195
' db_stats' ,
191
196
9 .0 ,
@@ -218,7 +223,7 @@ $sql$
218
223
219
224
/* index_stats */
220
225
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)
222
227
values (
223
228
' index_stats' ,
224
229
9 .0 ,
@@ -245,7 +250,7 @@ $sql$
245
250
246
251
/* kpi */
247
252
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)
249
254
values (
250
255
' kpi' ,
251
256
9 .0 ,
@@ -290,7 +295,7 @@ $sql$
290
295
291
296
/* kpi */
292
297
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)
294
299
values (
295
300
' kpi' ,
296
301
9 .6 ,
@@ -336,7 +341,7 @@ $sql$
336
341
337
342
/* replication */
338
343
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)
340
345
values (
341
346
' replication' ,
342
347
9 .1 ,
@@ -354,7 +359,7 @@ $sql$
354
359
355
360
/* sproc_stats */
356
361
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)
358
363
values (
359
364
' sproc_stats' ,
360
365
9 .0 ,
@@ -378,7 +383,7 @@ $sql$
378
383
379
384
/* table_io_stats */
380
385
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)
382
387
values (
383
388
' table_io_stats' ,
384
389
9 .0 ,
@@ -405,7 +410,7 @@ $sql$
405
410
406
411
/* table_stats */
407
412
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)
409
414
values (
410
415
' table_stats' ,
411
416
9 .0 ,
@@ -415,7 +420,7 @@ select
415
420
schemaname::text as tag_schema,
416
421
relname::text as tag_table_name,
417
422
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
419
424
extract(epoch from now() - greatest(last_vacuum, last_autovacuum)) as seconds_since_last_vacuum,
420
425
extract(epoch from now() - greatest(last_analyze, last_autoanalyze)) as seconds_since_last_analyze,
421
426
seq_scan,
@@ -433,13 +438,14 @@ select
433
438
from
434
439
pg_stat_user_tables
435
440
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);
437
443
$sql$
438
444
);
439
445
440
446
/* wal */
441
447
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)
443
449
values (
444
450
' wal' ,
445
451
9 .2 ,
@@ -453,7 +459,7 @@ $sql$
453
459
454
460
/* stat_statements */
455
461
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)
457
463
values (
458
464
' stat_statements' ,
459
465
9 .2 ,
@@ -462,7 +468,7 @@ with q_data as (
462
468
select
463
469
(extract(epoch from now()) * 1e9)::int8 as epoch_ns,
464
470
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 ,
466
472
sum (s .calls )::int8 as calls,
467
473
sum (s .total_time )::double precision as total_time,
468
474
sum (shared_blks_hit)::int8 as shared_blks_hit,
@@ -471,7 +477,7 @@ with q_data as (
471
477
sum (temp_blks_read)::int8 as temp_blks_read,
472
478
sum (temp_blks_written)::int8 as temp_blks_written
473
479
from
474
- public .pg_stat_statements s
480
+ public .get_stat_statements () s
475
481
where
476
482
calls > 1
477
483
and total_time > 0
@@ -555,7 +561,7 @@ $sql$
555
561
556
562
557
563
/* 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)
559
565
values (
560
566
' buffercache_by_db' ,
561
567
9 .2 ,
@@ -575,7 +581,7 @@ $sql$
575
581
);
576
582
577
583
/* 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)
579
585
values (
580
586
' buffercache_by_type' ,
581
587
9 .2 ,
@@ -596,7 +602,7 @@ $sql$
596
602
597
603
598
604
/* 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)
600
606
values (
601
607
' pg_stat_ssl' ,
602
608
9 .5 ,
@@ -618,7 +624,7 @@ $sql$
618
624
619
625
620
626
/* 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)
622
628
values (
623
629
' pg_stat_database_conflicts' ,
624
630
9 .2 ,
@@ -637,3 +643,83 @@ WHERE
637
643
$sql$
638
644
);
639
645
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