-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathpgperf_install91.sql
1793 lines (1626 loc) · 55.5 KB
/
pgperf_install91.sql
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
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
begin;
--
-- pgperf snapshot package
--
-- Copyright(C) 2012 Uptime Technologies, LLC.
--
-- This program is free software; you can redistribute it and/or modify
-- it under the terms of the GNU General Public License as published by
-- the Free Software Foundation; version 2 of the License.
--
-- This program is distributed in the hope that it will be useful,
-- but WITHOUT ANY WARRANTY; without even the implied warranty of
-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
-- GNU General Public License for more details.
--
-- You should have received a copy of the GNU General Public License along
-- with this program; if not, write to the Free Software Foundation, Inc.,
-- 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA.
--
CREATE SCHEMA pgperf;
--
-- pgperf stat tables
--
CREATE TABLE pgperf.snapshot (
sid INTEGER PRIMARY KEY,
ts TIMESTAMP NOT NULL
);
CREATE INDEX snapshot_ts_idx on pgperf.snapshot(ts);
--
-- Get a major version of the PostgreSQL server.
--
CREATE OR REPLACE FUNCTION pgperf._get_server_version (
) RETURNS INTEGER
AS '
DECLARE
_version INTEGER;
BEGIN
SELECT substr(replace(setting, ''.'', ''''), 1, 2)::integer INTO _version
FROM pg_settings
WHERE name = ''server_version'';
IF _version < 83 THEN
RAISE EXCEPTION ''Unsupported PostgreSQL version: %'', _version;
END IF;
RETURN _version;
END
' LANGUAGE 'plpgsql';
--
-- Check if a function exists.
--
CREATE OR REPLACE FUNCTION pgperf._check_function (
NAME
) RETURNS BOOLEAN
AS '
DECLARE
_name ALIAS FOR $1;
_found BOOLEAN;
BEGIN
SELECT CASE WHEN count(*)>0 THEN true ELSE false END INTO _found
FROM pg_proc
WHERE proname = _name;
RETURN _found;
END
' LANGUAGE 'plpgsql';
--
-- Check if a table or a view exists.
--
CREATE OR REPLACE FUNCTION pgperf._check_table_or_view (
NAME
) RETURNS BOOLEAN
AS '
DECLARE
_name ALIAS FOR $1;
_found BOOLEAN;
BEGIN
SELECT CASE WHEN count(*)>0 THEN true ELSE false END INTO _found
FROM pg_class
WHERE relname = _name
AND (relkind = ''r'' OR relkind = ''v'');
RETURN _found;
END
' LANGUAGE 'plpgsql';
--
-- Create a snapshot.
--
CREATE OR REPLACE FUNCTION pgperf.create_snapshot (
INTEGER
) RETURNS integer
AS '
DECLARE
_level ALIAS FOR $1;
_sid INTEGER;
_version INTEGER;
_found BOOLEAN;
BEGIN
SELECT pgperf._get_server_version() INTO _version;
SELECT max(sid) INTO _sid FROM pgperf.snapshot;
IF _sid IS NULL THEN
_sid := 0;
ELSE
_sid = _sid + 1;
END IF;
INSERT INTO pgperf.snapshot (sid,ts) VALUES (_sid, now());
PERFORM pgperf.create_snapshot_pg_database_size(_sid);
PERFORM pgperf.create_snapshot_pg_relation_size(_sid);
PERFORM pgperf.create_snapshot_pg_stat_bgwriter(_sid);
PERFORM pgperf.create_snapshot_pg_stat_database(_sid);
PERFORM pgperf.create_snapshot_pg_stat_user_tables(_sid);
PERFORM pgperf.create_snapshot_pg_statio_user_tables(_sid);
PERFORM pgperf.create_snapshot_pg_stat_user_indexes(_sid);
PERFORM pgperf.create_snapshot_pg_statio_user_indexes(_sid);
PERFORM pgperf.create_snapshot_pg_current_xlog(_sid);
PERFORM pgperf.create_snapshot_pg_stat_activity(_sid);
PERFORM pgperf.create_snapshot_pg_locks(_sid);
SELECT pgperf._check_table_or_view(''pg_stat_statements'') INTO _found;
IF _version > 83 AND _found THEN
PERFORM pgperf.create_snapshot_pg_stat_statements(_sid);
END IF;
IF _level >= 2 THEN
PERFORM pgperf.create_snapshot_pg_statistic(_sid);
END IF;
SELECT pgperf._check_function(''pgstattuple'') INTO _found;
IF _level >= 4 AND _found THEN
PERFORM pgperf.create_snapshot_pgstattuple(_sid);
PERFORM pgperf.create_snapshot_pgstatindex(_sid);
END IF;
RETURN _sid;
END
' LANGUAGE 'plpgsql';
--
-- Delete a snapshot.
--
CREATE OR REPLACE FUNCTION pgperf.delete_snapshot (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
_version INTEGER;
BEGIN
SELECT pgperf._get_server_version() INTO _version;
PERFORM pgperf.delete_snapshot_pgstatindex(_sid);
PERFORM pgperf.delete_snapshot_pgstattuple(_sid);
PERFORM pgperf.delete_snapshot_pg_stat_statements(_sid);
PERFORM pgperf.delete_snapshot_pg_locks(_sid);
PERFORM pgperf.delete_snapshot_pg_stat_activity(_sid);
PERFORM pgperf.delete_snapshot_pg_current_xlog(_sid);
PERFORM pgperf.delete_snapshot_pg_statistic(_sid);
PERFORM pgperf.delete_snapshot_pg_statio_user_indexes(_sid);
PERFORM pgperf.delete_snapshot_pg_stat_user_indexes(_sid);
PERFORM pgperf.delete_snapshot_pg_statio_user_tables(_sid);
PERFORM pgperf.delete_snapshot_pg_stat_user_tables(_sid);
PERFORM pgperf.delete_snapshot_pg_stat_database(_sid);
PERFORM pgperf.delete_snapshot_pg_stat_bgwriter(_sid);
PERFORM pgperf.delete_snapshot_pg_relation_size(_sid);
PERFORM pgperf.delete_snapshot_pg_database_size(_sid);
DELETE FROM pgperf.snapshot WHERE sid = _sid;
RETURN true;
END
' LANGUAGE 'plpgsql';
--
-- Purge old snapshots at once.
--
CREATE OR REPLACE FUNCTION pgperf.purge_snapshots (
INTERVAL
) RETURNS INTEGER
AS '
DECLARE
_interval ALIAS FOR $1;
_count INTEGER;
BEGIN
SELECT count(*) INTO _count
FROM pgperf.snapshot
WHERE ts < now() - _interval::interval;
PERFORM pgperf.delete_snapshot(sid)
FROM pgperf.snapshot
WHERE ts < now() - _interval::interval;
RETURN _count;
END
' LANGUAGE 'plpgsql';
--
-- Get an interval between snaphsots in seconds.
--
CREATE OR REPLACE FUNCTION pgperf.get_interval (
INTEGER,
INTEGER
) RETURNS INTEGER
AS '
DECLARE
_sid1 ALIAS FOR $1;
_sid2 ALIAS FOR $2;
_interval INTEGER;
BEGIN
SELECT extract(EPOCH FROM (s2.ts - s1.ts))::INTEGER INTO _interval
FROM (SELECT ts FROM pgperf.snapshot WHERE sid=_sid1 ) AS s1,
(SELECT ts FROM pgperf.snapshot WHERE sid=_sid2 ) AS s2;
RETURN _interval;
END
' LANGUAGE 'plpgsql';
CREATE TABLE pgperf.snapshot_pg_stat_bgwriter (
sid INTEGER NOT NULL,
checkpoints_timed bigint,
checkpoints_req bigint,
buffers_checkpoint bigint,
buffers_clean bigint,
maxwritten_clean bigint,
buffers_backend bigint,
buffers_backend_fsync bigint,
buffers_alloc bigint,
stats_reset timestamp with time zone
);
CREATE INDEX snapshot_pg_stat_bgwriter_sid_idx
ON pgperf.snapshot_pg_stat_bgwriter(sid);
--
-- Create a snapshot for pg_stat_bgwriter
--
CREATE OR REPLACE FUNCTION pgperf.create_snapshot_pg_stat_bgwriter (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
_r RECORD;
BEGIN
FOR _r IN SELECT checkpoints_timed,
checkpoints_req,
buffers_checkpoint,
buffers_clean,
maxwritten_clean,
buffers_backend,
buffers_backend_fsync,
buffers_alloc,
stats_reset
FROM pg_stat_bgwriter LOOP
INSERT INTO pgperf.snapshot_pg_stat_bgwriter (sid,
checkpoints_timed,
checkpoints_req,
buffers_checkpoint,
buffers_clean,
maxwritten_clean,
buffers_backend,
buffers_backend_fsync,
buffers_alloc,
stats_reset)
VALUES (_sid,
_r.checkpoints_timed,
_r.checkpoints_req,
_r.buffers_checkpoint,
_r.buffers_clean,
_r.maxwritten_clean,
_r.buffers_backend,
_r.buffers_backend_fsync,
_r.buffers_alloc,
_r.stats_reset);
END LOOP;
RETURN true;
END
' LANGUAGE 'plpgsql';
--
-- Delete a snapshot of pg_stat_bgwriter.
--
CREATE OR REPLACE FUNCTION pgperf.delete_snapshot_pg_stat_bgwriter (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
BEGIN
DELETE FROM pgperf.snapshot_pg_stat_bgwriter WHERE sid = _sid;
RETURN true;
END
' LANGUAGE 'plpgsql';
CREATE TABLE pgperf.snapshot_pg_database_size (
sid INTEGER NOT NULL,
datname name,
pg_database_size bigint
);
CREATE INDEX snapshot_pg_database_size_sid_idx
ON pgperf.snapshot_pg_database_size(sid);
--
-- Create a snapshot for pg_database_size.
--
CREATE OR REPLACE FUNCTION pgperf.create_snapshot_pg_database_size (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
_r RECORD;
BEGIN
FOR _r IN SELECT datname, pg_database_size(datname)
FROM pg_database LOOP
INSERT INTO pgperf.snapshot_pg_database_size (sid,
datname,
pg_database_size)
VALUES (_sid,
_r.datname,
_r.pg_database_size);
END LOOP;
RETURN true;
END
' LANGUAGE 'plpgsql';
--
-- Delete a snapshot of pg_database_size.
--
CREATE OR REPLACE FUNCTION pgperf.delete_snapshot_pg_database_size (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
BEGIN
DELETE FROM pgperf.snapshot_pg_database_size WHERE sid = _sid;
RETURN true;
END
' LANGUAGE 'plpgsql';
CREATE TABLE pgperf.snapshot_pg_stat_database (
sid INTEGER NOT NULL,
datid oid,
datname name,
numbackends integer,
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,
conflicts bigint,
stats_reset timestamp with time zone
);
CREATE INDEX snapshot_pg_stat_database_sid_idx
ON pgperf.snapshot_pg_stat_database(sid);
--
-- Create a snapshot for pg_stat_database
--
CREATE OR REPLACE FUNCTION pgperf.create_snapshot_pg_stat_database (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
_r RECORD;
BEGIN
FOR _r IN SELECT datid,
datname,
numbackends,
xact_commit,
xact_rollback,
blks_read,
blks_hit,
tup_returned,
tup_fetched,
tup_inserted,
tup_updated,
tup_deleted,
conflicts,
stats_reset
FROM pg_stat_database LOOP
INSERT INTO pgperf.snapshot_pg_stat_database (sid,
datid,
datname,
numbackends,
xact_commit,
xact_rollback,
blks_read,
blks_hit,
tup_returned,
tup_fetched,
tup_inserted,
tup_updated,
tup_deleted,
conflicts,
stats_reset)
VALUES (_sid,
_r.datid,
_r.datname,
_r.numbackends,
_r.xact_commit,
_r.xact_rollback,
_r.blks_read,
_r.blks_hit,
_r.tup_returned,
_r.tup_fetched,
_r.tup_inserted,
_r.tup_updated,
_r.tup_deleted,
_r.conflicts,
_r.stats_reset);
END LOOP;
RETURN true;
END
' LANGUAGE 'plpgsql';
--
-- Delete a snapshot of pg_stat_database.
--
CREATE OR REPLACE FUNCTION pgperf.delete_snapshot_pg_stat_database (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
BEGIN
DELETE FROM pgperf.snapshot_pg_stat_database WHERE sid = _sid;
RETURN true;
END
' LANGUAGE 'plpgsql';
CREATE TABLE pgperf.snapshot_pg_relation_size (
sid INTEGER NOT NULL,
schemaname name,
relid oid,
relname name,
pg_relation_size bigint,
pg_total_relation_size bigint
);
CREATE INDEX snapshot_pg_relation_size_sid_idx
ON pgperf.snapshot_pg_relation_size(sid);
--
-- Create a snapshot for pg_relation_size
--
CREATE OR REPLACE FUNCTION pgperf.create_snapshot_pg_relation_size (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
_r RECORD;
BEGIN
FOR _r IN SELECT s.*,
c.relname,
pg_relation_size(relid),
CASE WHEN c.relkind = ''r'' THEN
pg_total_relation_size(relid)
ELSE
null
END AS pg_total_relation_size
FROM (SELECT schemaname,relid FROM pg_stat_user_tables
UNION ALL
SELECT schemaname,indexrelid FROM pg_stat_user_indexes) AS s
LEFT OUTER JOIN pg_class c ON s.relid=c.oid
WHERE schemaname <> ''pgperf''
AND schemaname NOT LIKE ''pg\_%'' LOOP
INSERT INTO pgperf.snapshot_pg_relation_size (sid,
schemaname,
relid,
relname,
pg_relation_size,
pg_total_relation_size)
VALUES (_sid,
_r.schemaname,
_r.relid,
_r.relname,
_r.pg_relation_size,
_r.pg_total_relation_size);
END LOOP;
RETURN true;
END
' LANGUAGE 'plpgsql';
--
-- Delete a snapshot of pg_relation_size.
--
CREATE OR REPLACE FUNCTION pgperf.delete_snapshot_pg_relation_size (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
BEGIN
DELETE FROM pgperf.snapshot_pg_relation_size WHERE sid = _sid;
RETURN true;
END
' LANGUAGE 'plpgsql';
CREATE TABLE pgperf.snapshot_pg_stat_user_tables (
sid INTEGER NOT NULL,
relid oid,
schemaname name,
relname name,
seq_scan bigint,
seq_tup_read bigint,
idx_scan bigint,
idx_tup_fetch bigint,
n_tup_ins bigint,
n_tup_upd bigint,
n_tup_del bigint,
n_tup_hot_upd bigint,
n_live_tup bigint,
n_dead_tup bigint,
last_vacuum timestamp with time zone,
last_autovacuum timestamp with time zone,
last_analyze timestamp with time zone,
last_autoanalyze timestamp with time zone,
vacuum_count bigint,
autovacuum_count bigint,
analyze_count bigint,
autoanalyze_count bigint
);
CREATE INDEX snapshot_pg_stat_user_tables_sid_idx
ON pgperf.snapshot_pg_stat_user_tables(sid);
--
-- Create a snapshot for pg_stat_user_tables
--
CREATE OR REPLACE FUNCTION pgperf.create_snapshot_pg_stat_user_tables (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
_r RECORD;
BEGIN
FOR _r IN SELECT relid,
schemaname,
relname,
seq_scan,
seq_tup_read,
idx_scan,
idx_tup_fetch,
n_tup_ins,
n_tup_upd,
n_tup_del,
n_tup_hot_upd,
n_live_tup,
n_dead_tup,
last_vacuum,
last_autovacuum,
last_analyze,
last_autoanalyze,
vacuum_count,
autovacuum_count,
analyze_count,
autoanalyze_count
FROM pg_stat_user_tables
WHERE schemaname NOT LIKE ''pg\_%''
AND schemaname NOT LIKE ''information\_schema''
AND schemaname NOT LIKE ''pgperf'' LOOP
INSERT INTO pgperf.snapshot_pg_stat_user_tables (sid,
relid,
schemaname,
relname,
seq_scan,
seq_tup_read,
idx_scan,
idx_tup_fetch,
n_tup_ins,
n_tup_upd,
n_tup_del,
n_tup_hot_upd,
n_live_tup,
n_dead_tup,
last_vacuum,
last_autovacuum,
last_analyze,
last_autoanalyze,
vacuum_count,
autovacuum_count,
analyze_count,
autoanalyze_count)
VALUES (_sid,
_r.relid,
_r.schemaname,
_r.relname,
_r.seq_scan,
_r.seq_tup_read,
_r.idx_scan,
_r.idx_tup_fetch,
_r.n_tup_ins,
_r.n_tup_upd,
_r.n_tup_del,
_r.n_tup_hot_upd,
_r.n_live_tup,
_r.n_dead_tup,
_r.last_vacuum,
_r.last_autovacuum,
_r.last_analyze,
_r.last_autoanalyze,
_r.vacuum_count,
_r.autovacuum_count,
_r.analyze_count,
_r.autoanalyze_count);
END LOOP;
RETURN true;
END
' LANGUAGE 'plpgsql';
--
-- Delete a snapshot of pg_stat_user_tables.
--
CREATE OR REPLACE FUNCTION pgperf.delete_snapshot_pg_stat_user_tables (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
BEGIN
DELETE FROM pgperf.snapshot_pg_stat_user_tables WHERE sid = _sid;
RETURN true;
END
' LANGUAGE 'plpgsql';
CREATE TABLE pgperf.snapshot_pg_statio_user_tables (
sid INTEGER NOT NULL,
relid oid,
schemaname name,
relname name,
heap_blks_read bigint,
heap_blks_hit bigint,
idx_blks_read bigint,
idx_blks_hit bigint,
toast_blks_read bigint,
toast_blks_hit bigint,
tidx_blks_read bigint,
tidx_blks_hit bigint
);
CREATE INDEX snapshot_pg_statio_user_tables_sid_idx
ON pgperf.snapshot_pg_statio_user_tables(sid);
--
-- Create a snapshot for pg_statio_user_tables
--
CREATE OR REPLACE FUNCTION pgperf.create_snapshot_pg_statio_user_tables (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
_r RECORD;
BEGIN
FOR _r IN SELECT relid,
schemaname,
relname,
heap_blks_read,
heap_blks_hit,
idx_blks_read,
idx_blks_hit,
toast_blks_read,
toast_blks_hit,
tidx_blks_read,
tidx_blks_hit
FROM pg_statio_user_tables
WHERE schemaname NOT LIKE ''pg\_%''
AND schemaname NOT LIKE ''information\_schema''
AND schemaname NOT LIKE ''pgperf'' LOOP
INSERT INTO pgperf.snapshot_pg_statio_user_tables (sid,
relid,
schemaname,
relname,
heap_blks_read,
heap_blks_hit,
idx_blks_read,
idx_blks_hit,
toast_blks_read,
toast_blks_hit,
tidx_blks_read,
tidx_blks_hit)
VALUES (_sid,
_r.relid,
_r.schemaname,
_r.relname,
_r.heap_blks_read,
_r.heap_blks_hit,
_r.idx_blks_read,
_r.idx_blks_hit,
_r.toast_blks_read,
_r.toast_blks_hit,
_r.tidx_blks_read,
_r.tidx_blks_hit);
END LOOP;
RETURN true;
END
' LANGUAGE 'plpgsql';
--
-- Delete a snapshot of pg_statio_user_tables.
--
CREATE OR REPLACE FUNCTION pgperf.delete_snapshot_pg_statio_user_tables (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
BEGIN
DELETE FROM pgperf.snapshot_pg_statio_user_tables WHERE sid = _sid;
RETURN true;
END
' LANGUAGE 'plpgsql';
CREATE TABLE pgperf.snapshot_pg_stat_user_indexes (
sid INTEGER NOT NULL,
relid oid,
indexrelid oid,
schemaname name,
relname name,
indexrelname name,
idx_scan bigint,
idx_tup_read bigint,
idx_tup_fetch bigint
);
CREATE INDEX snapshot_pg_stat_user_indexes_sid_idx
ON pgperf.snapshot_pg_stat_user_indexes(sid);
--
-- Create a snapshot for pg_stat_user_indexes
--
CREATE OR REPLACE FUNCTION pgperf.create_snapshot_pg_stat_user_indexes (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
_r RECORD;
BEGIN
FOR _r IN SELECT relid,
indexrelid,
schemaname,
relname,
indexrelname,
idx_scan,
idx_tup_read,
idx_tup_fetch
FROM pg_stat_user_indexes
WHERE schemaname NOT LIKE ''pg\_%''
AND schemaname NOT LIKE ''information\_schema''
AND schemaname NOT LIKE ''pgperf'' LOOP
INSERT INTO pgperf.snapshot_pg_stat_user_indexes (sid,
relid,
indexrelid,
schemaname,
relname,
indexrelname,
idx_scan,
idx_tup_read,
idx_tup_fetch)
VALUES (_sid,
_r.relid,
_r.indexrelid,
_r.schemaname,
_r.relname,
_r.indexrelname,
_r.idx_scan,
_r.idx_tup_read,
_r.idx_tup_fetch);
END LOOP;
RETURN true;
END
' LANGUAGE 'plpgsql';
--
-- Delete a snapshot of pg_stat_user_indexes.
--
CREATE OR REPLACE FUNCTION pgperf.delete_snapshot_pg_stat_user_indexes (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
BEGIN
DELETE FROM pgperf.snapshot_pg_stat_user_indexes WHERE sid = _sid;
RETURN true;
END
' LANGUAGE 'plpgsql';
CREATE TABLE pgperf.snapshot_pg_statio_user_indexes (
sid INTEGER NOT NULL,
relid oid,
indexrelid oid,
schemaname name,
relname name,
indexrelname name,
idx_blks_read bigint,
idx_blks_hit bigint
);
CREATE INDEX snapshot_pg_statio_user_indexes_sid_idx
ON pgperf.snapshot_pg_statio_user_indexes(sid);
--
-- Create a snapshot for pg_statio_user_indexes
--
CREATE OR REPLACE FUNCTION pgperf.create_snapshot_pg_statio_user_indexes (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
_r RECORD;
BEGIN
FOR _r IN SELECT relid,
indexrelid,
schemaname,
relname,
indexrelname,
idx_blks_read,
idx_blks_hit
FROM pg_statio_user_indexes
WHERE schemaname NOT LIKE ''pg\_%''
AND schemaname NOT LIKE ''information\_schema''
AND schemaname NOT LIKE ''pgperf'' LOOP
INSERT INTO pgperf.snapshot_pg_statio_user_indexes (sid,
relid,
indexrelid,
schemaname,
relname,
indexrelname,
idx_blks_read,
idx_blks_hit)
VALUES (_sid,
_r.relid,
_r.indexrelid,
_r.schemaname,
_r.relname,
_r.indexrelname,
_r.idx_blks_read,
_r.idx_blks_hit);
END LOOP;
RETURN true;
END
' LANGUAGE 'plpgsql';
--
-- Delete a snapshot of pg_statio_user_indexes.
--
CREATE OR REPLACE FUNCTION pgperf.delete_snapshot_pg_statio_user_indexes (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
BEGIN
DELETE FROM pgperf.snapshot_pg_statio_user_indexes WHERE sid = _sid;
RETURN true;
END
' LANGUAGE 'plpgsql';
CREATE TABLE pgperf.snapshot_pg_statistic (
sid INTEGER NOT NULL,
starelid oid,
starelname name,
staattnum int2,
staattname name,
stainherit bool,
stanullfrac float4,
stawidth int4,
stadistinct float4,
stakind1 int2,
stakind2 int2,
stakind3 int2,
stakind4 int2,
staop1 oid,
staop2 oid,
staop3 oid,
staop4 oid,
stanumbers1 float4[],
stanumbers2 float4[],
stanumbers3 float4[],
stanumbers4 float4[],
stavalues1 text,
stavalues2 text,
stavalues3 text,
stavalues4 text
);
CREATE INDEX snapshot_pg_statistic_sid_idx
ON pgperf.snapshot_pg_statistic(sid);
--
-- Create a snapshot for pg_statistic
--
CREATE OR REPLACE FUNCTION pgperf.create_snapshot_pg_statistic (
INTEGER
) RETURNS boolean
AS '
DECLARE
_sid ALIAS FOR $1;
_r RECORD;
BEGIN
FOR _r IN SELECT s.starelid,
c.relname as starelname,
s.staattnum,
a.attname as staattname,
s.stainherit,
s.stanullfrac,
s.stawidth,
s.stadistinct,
s.stakind1,
s.stakind2,
s.stakind3,
s.stakind4,
s.staop1,
s.staop2,
s.staop3,
s.staop4,
s.stanumbers1,
s.stanumbers2,
s.stanumbers3,
s.stanumbers4,
s.stavalues1,
s.stavalues2,
s.stavalues3,
s.stavalues4
FROM pg_statistic s, pg_class c, pg_namespace n, pg_attribute a
WHERE n.nspname NOT LIKE ''pg\_%''
AND n.nspname NOT LIKE ''information_schema''
AND n.nspname NOT LIKE ''pgperf''
AND n.oid = c.relnamespace
AND c.oid = s.starelid
AND a.attnum = s.staattnum
AND a.attrelid = s.starelid LOOP
INSERT INTO pgperf.snapshot_pg_statistic (sid,
starelid,
starelname,
staattnum,
staattname,
stainherit,
stanullfrac,
stawidth,
stadistinct,
stakind1,