aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/monitoring.sgml
blob: 563d9d3ecd693cf05ab347c868e6c86fbff7a59c (plain)
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
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
<!-- $PostgreSQL: pgsql/doc/src/sgml/monitoring.sgml,v 1.55.2.1 2008/11/11 20:06:25 mha Exp $ -->

<chapter id="monitoring">
 <title>Monitoring Database Activity</title>

 <indexterm zone="monitoring">
  <primary>monitoring</primary>
  <secondary>database activity</secondary>
 </indexterm>

 <indexterm zone="monitoring">
  <primary>database activity</primary>
  <secondary>monitoring</secondary>
 </indexterm>

 <para>
  A database administrator frequently wonders, <quote>What is the system
  doing right now?</quote>
  This chapter discusses how to find that out.
 </para>

  <para>
   Several tools are available for monitoring database activity and
   analyzing performance.  Most of this chapter is devoted to describing
   <productname>PostgreSQL</productname>'s statistics collector,
   but one should not neglect regular Unix monitoring programs such as
   <command>ps</>, <command>top</>, <command>iostat</>, and <command>vmstat</>.
   Also, once one has identified a
   poorly-performing query, further investigation might be needed using
   <productname>PostgreSQL</productname>'s <xref linkend="sql-explain"
   endterm="sql-explain-title"> command.
   <xref linkend="using-explain"> discusses <command>EXPLAIN</>
   and other methods for understanding the behavior of an individual
   query.
  </para>

 <sect1 id="monitoring-ps">
  <title>Standard Unix Tools</Title>

  <indexterm zone="monitoring-ps">
   <primary>ps</primary>
   <secondary>to monitor activity</secondary>
  </indexterm>

  <para>
   On most platforms, <productname>PostgreSQL</productname> modifies its
   command title as reported by <command>ps</>, so that individual server
   processes can readily be identified.  A sample display is

<screen>
$ ps auxww | grep ^postgres
postgres   960  0.0  1.1  6104 1480 pts/1    SN   13:17   0:00 postgres -i
postgres   963  0.0  1.1  7084 1472 pts/1    SN   13:17   0:00 postgres: writer process
postgres   965  0.0  1.1  6152 1512 pts/1    SN   13:17   0:00 postgres: stats collector process   
postgres   998  0.0  2.3  6532 2992 pts/1    SN   13:18   0:00 postgres: tgl runbug 127.0.0.1 idle
postgres  1003  0.0  2.4  6532 3128 pts/1    SN   13:19   0:00 postgres: tgl regression [local] SELECT waiting
postgres  1016  0.1  2.4  6532 3080 pts/1    SN   13:19   0:00 postgres: tgl regression [local] idle in transaction
</screen>

   (The appropriate invocation of <command>ps</> varies across different
   platforms, as do the details of what is shown.  This example is from a
   recent Linux system.)  The first process listed here is the
   master server process.  The command arguments
   shown for it are the same ones given when it was launched.  The next two
   processes are background worker processes automatically launched by the
   master process.  (The <quote>stats collector</> process will not be present
   if you have set
   the system not to start the statistics collector.)  Each of the remaining
   processes is a server process handling one client connection.  Each such
   process sets its command line display in the form

<screen>
postgres: <replaceable>user</> <replaceable>database</> <replaceable>host</> <replaceable>activity</>
</screen>

  The user, database, and connection source host items remain the same for
  the life of the client connection, but the activity indicator changes.
  The activity can be <literal>idle</> (i.e., waiting for a client command),
  <literal>idle in transaction</> (waiting for client inside a <command>BEGIN</> block),
  or a command type name such as <literal>SELECT</>.  Also,
  <literal>waiting</> is attached if the server process is presently waiting
  on a lock held by another server process.  In the above example we can infer
  that process 1003 is waiting for process 1016 to complete its transaction and
  thereby release some lock or other.
  </para>

  <para>
   If you have turned off <xref linkend="guc-update-process-title"> then the
   activity indicator is not updated; the process title is set only once
   when a new process is launched.  On some platforms this saves a useful
   amount of per-command overhead, on others it's insignificant.
  </para>

  <tip>
  <para>
  <productname>Solaris</productname> requires special handling. You must
  use <command>/usr/ucb/ps</command>, rather than
  <command>/bin/ps</command>. You also must use two <option>w</option>
  flags, not just one. In addition, your original invocation of the
  <command>postgres</command> command must have a shorter
  <command>ps</command> status display than that provided by each
  server process.  If you fail to do all three things, the <command>ps</>
  output for each server process will be the original <command>postgres</>
  command line.
  </para>
  </tip>
 </sect1>

 <sect1 id="monitoring-stats">
  <title>The Statistics Collector</Title>

  <indexterm zone="monitoring-stats">
   <primary>statistics</primary>
  </indexterm>

  <para>
   <productname>PostgreSQL</productname>'s <firstterm>statistics collector</>
   is a subsystem that supports collection and reporting of information about
   server activity.  Presently, the collector can count accesses to tables
   and indexes in both disk-block and individual-row terms.  It also tracks
   total numbers of rows in each table, and the last vacuum and analyze times
   for each table.
  </para>

  <para>
   <productname>PostgreSQL</productname> also supports determining the exact
   command currently being executed by other server processes.  This is an
   independent facility that does not depend on the collector process.
  </para>

 <sect2 id="monitoring-stats-setup">
  <title>Statistics Collection Configuration</Title>

  <para>
   Since collection of statistics adds some overhead to query execution,
   the system can be configured to collect or not collect information.
   This is controlled by configuration parameters that are normally set in
   <filename>postgresql.conf</>.  (See <xref linkend="runtime-config"> for
   details about setting configuration parameters.)
  </para>

  <para>
   The parameter <xref linkend="guc-track-counts"> controls whether
   information is actually sent to the collector process and thus determines
   whether any run-time overhead occurs for event counting.
  </para>

  <para>
   The parameter <xref linkend="guc-track-activities"> enables monitoring
   of the current command being executed by any server process.
  </para>
  
  <para>
   Normally these parameters are set in <filename>postgresql.conf</> so
   that they apply to all server processes, but it is possible to turn
   them on or off in individual sessions using the <xref
   linkend="sql-set" endterm="sql-set-title"> command. (To prevent
   ordinary users from hiding their activity from the administrator,
   only superusers are allowed to change these parameters with
   <command>SET</>.)
  </para>
 </sect2>

 <sect2 id="monitoring-stats-views">
  <title>Viewing Collected Statistics</Title>

  <para>
   Several predefined views, listed in <xref
   linkend="monitoring-stats-views-table">, are available to show the results
   of statistics collection.  Alternatively, one can
   build custom views using the underlying statistics functions.
  </para>

  <para>
   When using the statistics to monitor current activity, it is important
   to realize that the information does not update instantaneously.
   Each individual server process transmits new statistical counts to
   the collector just before going idle; so a query or transaction still in
   progress does not affect the displayed totals.  Also, the collector itself
   emits a new report at most once per <varname>PGSTAT_STAT_INTERVAL</varname>
   milliseconds (500 unless altered while building the server).  So the
   displayed information lags behind actual activity.  However, current-query
   information collected by <varname>track_activities</varname> is
   always up-to-date.
  </para>

  <para>
   Another important point is that when a server process is asked to display
   any of these statistics, it first fetches the most recent report emitted by
   the collector process and then continues to use this snapshot for all
   statistical views and functions until the end of its current transaction.
   So the statistics will appear not to change as long as you continue the
   current transaction.  Similarly, information about the current queries of
   all processes is collected when any such information is first requested
   within a transaction, and the same information will be displayed throughout
   the transaction.
   This is a feature, not a bug, because it allows you to perform several
   queries on the statistics and correlate the results without worrying that
   the numbers are changing underneath you.  But if you want to see new
   results with each query, be sure to do the queries outside any transaction
   block.  Alternatively, you can invoke
   <function>pg_stat_clear_snapshot</function>(), which will discard the
   current transaction's statistics snapshot (if any).  The next use of
   statistical information will cause a new snapshot to be fetched.
  </para>

  <table id="monitoring-stats-views-table">
   <title>Standard Statistics Views</title>

   <tgroup cols="2">
    <thead>
     <row>
      <entry>View Name</entry>
      <entry>Description</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry><structname>pg_stat_activity</></entry>
      <entry>One row per server process, showing database OID, database
      name, process <acronym>ID</>, user OID, user name, current query,
      query's waiting status, time at which the current transaction and
      current query began execution, time at which the process was
      started, and client's address and port number.  The columns that
      report data on the current query are available unless the parameter
      <varname>track_activities</varname> has been turned off.
      Furthermore, these columns are only visible if the user examining
      the view is a superuser or the same as the user owning the process
      being reported on.
     </entry>
     </row>

     <row>
      <entry><structname>pg_stat_bgwriter</></entry>
      <entry>One row only, showing cluster-wide statistics from the
      background writer: number of scheduled checkpoints, requested
      checkpoints, buffers written by checkpoints and cleaning scans,
      and the number of times the background writer stopped a cleaning scan
      because it had written too many buffers.  Also includes
      statistics about the shared buffer pool, including buffers written
      by backends (that is, not by the background writer) and total buffers
      allocated.
     </entry>
     </row>

     <row>
      <entry><structname>pg_stat_database</></entry>
      <entry>One row per database, showing database OID, database name,
      number of active server processes connected to that database,
      number of transactions committed and rolled back in that database,
      total disk blocks read, total buffer hits (i.e., block
      read requests avoided by finding the block already in buffer cache),
      number of rows returned, fetched, inserted, updated and deleted.
     </entry>
     </row>

     <row>
      <entry><structname>pg_stat_all_tables</></entry>
      <entry>For each table in the current database (including TOAST tables),
      the table OID, schema and table name, number of sequential
      scans initiated, number of live rows fetched by sequential
      scans, number of index scans initiated (over all indexes
      belonging to the table), number of live rows fetched by index
      scans, numbers of row insertions, updates, and deletions,
      number of row updates that were HOT (i.e., no separate index update),
      numbers of live and dead rows,
      the last time the table was vacuumed manually,
      the last time it was vacuumed by the autovacuum daemon,
      the last time it was analyzed manually,
      and the last time it was analyzed by the autovacuum daemon.
      </entry>
     </row>

     <row>
      <entry><structname>pg_stat_sys_tables</></entry>
      <entry>Same as <structname>pg_stat_all_tables</>, except that only
      system tables are shown.</entry>
     </row>

     <row>
      <entry><structname>pg_stat_user_tables</></entry>
      <entry>Same as <structname>pg_stat_all_tables</>, except that only user
      tables are shown.</entry>
     </row>

     <row>
      <entry><structname>pg_stat_all_indexes</></entry>
      <entry>For each index in the current database,
      the table and index OID, schema, table and index name,
      number of index scans initiated on that index, number of
      index entries returned by index scans, and number of live table rows
      fetched by simple index scans using that index.
      </entry>
     </row>

     <row>
      <entry><structname>pg_stat_sys_indexes</></entry>
      <entry>Same as <structname>pg_stat_all_indexes</>, except that only
      indexes on system tables are shown.</entry>
     </row>

     <row>
      <entry><structname>pg_stat_user_indexes</></entry>
      <entry>Same as <structname>pg_stat_all_indexes</>, except that only
      indexes on user tables are shown.</entry>
     </row>

     <row>
      <entry><structname>pg_statio_all_tables</></entry>
      <entry>For each table in the current database (including TOAST tables),
      the table OID, schema and table name, number of disk
      blocks read from that table, number of buffer hits, numbers of
      disk blocks read and buffer hits in all indexes of that table,
      numbers of disk blocks read and buffer hits from that table's
      auxiliary TOAST table (if any), and numbers of disk blocks read
      and buffer hits for the TOAST table's index.
      </entry>
     </row>

     <row>
      <entry><structname>pg_statio_sys_tables</></entry>
      <entry>Same as <structname>pg_statio_all_tables</>, except that only
      system tables are shown.</entry>
     </row>

     <row>
      <entry><structname>pg_statio_user_tables</></entry>
      <entry>Same as <structname>pg_statio_all_tables</>, except that only
      user tables are shown.</entry>
     </row>

     <row>
      <entry><structname>pg_statio_all_indexes</></entry>
      <entry>For each index in the current database,
      the table and index OID, schema, table and index name,
      numbers of disk blocks read and buffer hits in that index.
      </entry>
     </row>

     <row>
      <entry><structname>pg_statio_sys_indexes</></entry>
      <entry>Same as <structname>pg_statio_all_indexes</>, except that only
      indexes on system tables are shown.</entry>
     </row>

     <row>
      <entry><structname>pg_statio_user_indexes</></entry>
      <entry>Same as <structname>pg_statio_all_indexes</>, except that only
      indexes on user tables are shown.</entry>
     </row>

     <row>
      <entry><structname>pg_statio_all_sequences</></entry>
      <entry>For each sequence object in the current database,
      the sequence OID, schema and sequence name,
      numbers of disk blocks read and buffer hits in that sequence.
      </entry>
     </row>

     <row>
      <entry><structname>pg_statio_sys_sequences</></entry>
      <entry>Same as <structname>pg_statio_all_sequences</>, except that only
      system sequences are shown.  (Presently, no system sequences are defined,
      so this view is always empty.)</entry>
     </row>

     <row>
      <entry><structname>pg_statio_user_sequences</></entry>
      <entry>Same as <structname>pg_statio_all_sequences</>, except that only
      user sequences are shown.</entry>
     </row>
    </tbody>
   </tgroup>
  </table>

  <para>
   The per-index statistics are particularly useful to determine which
   indexes are being used and how effective they are.
  </para>

  <para>
   Beginning in <productname>PostgreSQL</productname> 8.1, indexes can be
   used either directly or via <quote>bitmap scans</>.  In a bitmap scan
   the output of several indexes can be combined via AND or OR rules;
   so it is difficult to associate individual heap row fetches 
   with specific indexes when a bitmap scan is used.  Therefore, a bitmap
   scan increments the
   <structname>pg_stat_all_indexes</>.<structfield>idx_tup_read</>
   count(s) for the index(es) it uses, and it increments the
   <structname>pg_stat_all_tables</>.<structfield>idx_tup_fetch</>
   count for the table, but it does not affect
   <structname>pg_stat_all_indexes</>.<structfield>idx_tup_fetch</>.
  </para>

  <note>
   <para>
    Before <productname>PostgreSQL</productname> 8.1, the
    <structfield>idx_tup_read</> and <structfield>idx_tup_fetch</> counts
    were essentially always equal.  Now they can be different even without
    considering bitmap scans, because <structfield>idx_tup_read</> counts
    index entries retrieved from the index while <structfield>idx_tup_fetch</>
    counts live rows fetched from the table; the latter will be less if any
    dead or not-yet-committed rows are fetched using the index.
   </para>
  </note>

  <para>
   The <structname>pg_statio_</> views are primarily useful to
   determine the effectiveness of the buffer cache.  When the number
   of actual disk reads is much smaller than the number of buffer
   hits, then the cache is satisfying most read requests without
   invoking a kernel call. However, these statistics do not give the
   entire story: due to the way in which <productname>PostgreSQL</>
   handles disk I/O, data that is not in the
   <productname>PostgreSQL</> buffer cache might still reside in the
   kernel's I/O cache, and might therefore still be fetched without
   requiring a physical read. Users interested in obtaining more
   detailed information on <productname>PostgreSQL</> I/O behavior are
   advised to use the <productname>PostgreSQL</> statistics collector
   in combination with operating system utilities that allow insight
   into the kernel's handling of I/O.
  </para>

  <para>
   Other ways of looking at the statistics can be set up by writing
   queries that use the same underlying statistics access functions as
   these standard views do.  These functions are listed in <xref
   linkend="monitoring-stats-funcs-table">.  The per-database access
   functions take a database OID as argument to identify which
   database to report on.  The per-table and per-index functions take
   a table or index OID.  (Note that only tables and indexes in the
   current database can be seen with these functions.)  The
   per-server-process access functions take a server process
   number, which ranges from one to the number of currently active
   server processes.
  </para>

  <table id="monitoring-stats-funcs-table">
   <title>Statistics Access Functions</title>

   <tgroup cols="3">
    <thead>
     <row>
      <entry>Function</entry>
      <entry>Return Type</entry>
      <entry>Description</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry><literal><function>pg_stat_get_db_numbackends</function>(<type>oid</type>)</literal></entry>
      <entry><type>integer</type></entry>
      <entry>
       Number of active server processes for database
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_db_xact_commit</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Transactions committed in database
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_db_xact_rollback</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Transactions rolled back in database
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_db_blocks_fetched</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of disk block fetch requests for database
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_db_blocks_hit</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of disk block fetch requests found in cache for database
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_db_tuples_returned</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of tuples returned for database
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_db_tuples_fetched</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of tuples fetched for database
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_db_tuples_inserted</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of tuples inserted in database
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_db_tuples_updated</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of tuples updated in database
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_db_tuples_deleted</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of tuples deleted in database
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_numscans</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of sequential scans done when argument is a table,
       or number of index scans done when argument is an index
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_tuples_returned</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of rows read by sequential scans when argument is a table,
       or number of index entries returned when argument is an index
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_tuples_fetched</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of table rows fetched by bitmap scans when argument is a table,
       or table rows fetched by simple index scans using the index
       when argument is an index
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_tuples_inserted</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of rows inserted into table
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_tuples_updated</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of rows updated in table (includes HOT updates)
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_tuples_deleted</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of rows deleted from table
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_tuples_hot_updated</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of rows HOT-updated in table
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_live_tuples</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of live rows in table
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_dead_tuples</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of dead rows in table
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_blocks_fetched</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of disk block fetch requests for table or index
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_blocks_hit</function>(<type>oid</type>)</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       Number of disk block requests found in cache for table or index
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_last_vacuum_time</function>(<type>oid</type>)</literal></entry>
      <entry><type>timestamptz</type></entry>
      <entry>
       Time of the last vacuum initiated by the user on this table
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_last_autovacuum_time</function>(<type>oid</type>)</literal></entry>
      <entry><type>timestamptz</type></entry>
      <entry>
       Time of the last vacuum initiated by the autovacuum daemon on this table
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_last_analyze_time</function>(<type>oid</type>)</literal></entry>
      <entry><type>timestamptz</type></entry>
      <entry>
       Time of the last analyze initiated by the user on this table
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_last_autoanalyze_time</function>(<type>oid</type>)</literal></entry>
      <entry><type>timestamptz</type></entry>
      <entry>
       Time of the last analyze initiated by the autovacuum daemon on this
       table
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_backend_idset</function>()</literal></entry>
      <entry><type>setof integer</type></entry>
      <entry>
       Set of currently active server process numbers (from 1 to the
       number of active server processes).  See usage example in the text
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_backend_pid</function>()</literal></entry>
      <entry><type>integer</type></entry>
      <entry>
       Process ID of the server process attached to the current session
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_backend_pid</function>(<type>integer</type>)</literal></entry>
      <entry><type>integer</type></entry>
      <entry>
       Process ID of the given server process
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_backend_dbid</function>(<type>integer</type>)</literal></entry>
      <entry><type>oid</type></entry>
      <entry>
       Database ID of the given server process
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_backend_userid</function>(<type>integer</type>)</literal></entry>
      <entry><type>oid</type></entry>
      <entry>
       User ID of the given server process
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_backend_activity</function>(<type>integer</type>)</literal></entry>
      <entry><type>text</type></entry>
      <entry>
       Active command of the given server process, but only if the
       current user is a superuser or the same user as that of
       the session being queried (and
       <varname>track_activities</varname> is on)
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_backend_waiting</function>(<type>integer</type>)</literal></entry>
      <entry><type>boolean</type></entry>
      <entry>
       True if the given server process is waiting for a lock,
       but only if the current user is a superuser or the same user as that of
       the session being queried (and
       <varname>track_activities</varname> is on)
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_backend_activity_start</function>(<type>integer</type>)</literal></entry>
      <entry><type>timestamp with time zone</type></entry>
      <entry>
       The time at which the given server process' currently
       executing query was started, but only if the
       current user is a superuser or the same user as that of
       the session being queried (and
       <varname>track_activities</varname> is on)
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_backend_xact_start</function>(<type>integer</type>)</literal></entry>
      <entry><type>timestamp with time zone</type></entry>
      <entry>
       The time at which the given server process' currently
       executing transaction was started, but only if the
       current user is a superuser or the same user as that of
       the session being queried (and
       <varname>track_activities</varname> is on)
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_backend_start</function>(<type>integer</type>)</literal></entry>
      <entry><type>timestamp with time zone</type></entry>
      <entry>
       The time at which the given server process was started, or
       null if the current user is not a superuser nor the same user
       as that of the session being queried
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_backend_client_addr</function>(<type>integer</type>)</literal></entry>
      <entry><type>inet</type></entry>
      <entry>
       The IP address of the client connected to the given
       server process. Null if the connection is over a Unix domain
       socket. Also null if the current user is not a superuser nor
       the same user as that of the session being queried
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_backend_client_port</function>(<type>integer</type>)</literal></entry>
      <entry><type>integer</type></entry>
      <entry>
       The IP port number of the client connected to the given
       server process.  -1 if the connection is over a Unix domain
       socket. Null if the current user is not a superuser nor the
       same user as that of the session being queried
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_bgwriter_timed_checkpoints</function>()</literal></entry>
       <entry><type>bigint</type></entry>
       <entry>
        The number of times the background writer has started timed checkpoints
        (because the <varname>checkpoint_timeout</varname> time has expired)
       </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_bgwriter_requested_checkpoints</function>()</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       The number of times the background writer has started checkpoints based
       on requests from backends because the <varname>checkpoint_segments</varname>
       has been exceeded or because the <command>CHECKPOINT</command>
       command has been issued
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_bgwriter_buf_written_checkpoints</function>()</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       The number of buffers written by the background writer during checkpoints
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_bgwriter_buf_written_clean</function>()</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       The number of buffers written by the background writer for routine cleaning of
       dirty pages
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_bgwriter_maxwritten_clean</function>()</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       The number of times the background writer has stopped its cleaning scan because
       it has written more buffers than specified in the
       <varname>bgwriter_lru_maxpages</varname> parameter
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_buf_written_backend</function>()</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       The number of buffers written by backends because they needed
       to allocate a new buffer
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_get_buf_alloc</function>()</literal></entry>
      <entry><type>bigint</type></entry>
      <entry>
       The total number of buffer allocations
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_clear_snapshot</function>()</literal></entry>
      <entry><type>void</type></entry>
      <entry>
       Discard the current statistics snapshot
      </entry>
     </row>

     <row>
      <entry><literal><function>pg_stat_reset</function>()</literal></entry>
      <entry><type>void</type></entry>
      <entry>
       Reset all statistics counters for the current database to zero
       (requires superuser privileges)
      </entry>
     </row>
    </tbody>
   </tgroup>
  </table>

   <note>
    <para>
     <function>blocks_fetched</function> minus
     <function>blocks_hit</function> gives the number of kernel
     <function>read()</> calls issued for the table, index, or
     database; but the actual number of physical reads is usually
     lower due to kernel-level buffering.
    </para>
   </note>

  <para>
   The function <function>pg_stat_get_backend_idset</function> provides
   a convenient way to generate one row for each active server process.  For
   example, to show the <acronym>PID</>s and current queries of all server processes:

<programlisting>
SELECT pg_stat_get_backend_pid(s.backendid) AS procpid,
       pg_stat_get_backend_activity(s.backendid) AS current_query
    FROM (SELECT pg_stat_get_backend_idset() AS backendid) AS s;
</programlisting>
  </para>

 </sect2>
 </sect1>

 <sect1 id="monitoring-locks">
  <title>Viewing Locks</title>

  <indexterm zone="monitoring-locks">
   <primary>lock</primary>
   <secondary>monitoring</secondary>
  </indexterm>

  <para>
   Another useful tool for monitoring database activity is the
   <structname>pg_locks</structname> system table.  It allows the
   database administrator to view information about the outstanding
   locks in the lock manager. For example, this capability can be used
   to:

   <itemizedlist>
    <listitem>
     <para>
      View all the locks currently outstanding, all the locks on
      relations in a particular database, all the locks on a
      particular relation, or all the locks held by a particular
      <productname>PostgreSQL</productname> session.
     </para>
    </listitem>

    <listitem>
     <para>
      Determine the relation in the current database with the most
      ungranted locks (which might be a source of contention among
      database clients).
     </para>
    </listitem>

    <listitem>
     <para>
      Determine the effect of lock contention on overall database
      performance, as well as the extent to which contention varies
      with overall database traffic.
     </para>
    </listitem>
   </itemizedlist>

   Details of the <structname>pg_locks</structname> view appear in
   <xref linkend="view-pg-locks">.
   For more information on locking and managing concurrency with
   <productname>PostgreSQL</productname>, refer to <xref linkend="mvcc">.
  </para>
 </sect1>

 <sect1 id="dynamic-trace">
  <title>Dynamic Tracing</title>

 <indexterm zone="dynamic-trace">
  <primary>DTrace</primary>
 </indexterm>

  <para>
   <productname>PostgreSQL</productname> provides facilities to support
   dynamic tracing of the database server. This allows an external
   utility to be called at specific points in the code and thereby trace
   execution.  Currently, this facility is primarily intended for use by
   database developers, as it requires substantial familiarity with the code.
  </para>

  <para>
   A number of trace points, often called probes, are already inserted
   into the source code.  By default these probes are disabled, and
   the user needs to explicitly tell the configure script to make the
   probes available in <productname>PostgreSQL</productname>.
  </para>

  <para> 
   Currently, only the DTrace utility is supported, which is only available
   on Solaris Express and Solaris 10+. It is expected that DTrace will
   be available in the future on FreeBSD and Mac OS X.
   Supporting other dynamic tracing utilities is theoretically possible by
   changing the definitions for the <literal>PG_TRACE</> macros in
   <filename>src/include/pg_trace.h</>.
  </para>

  <sect2 id="compiling-for-trace">
   <title>Compiling for Dynamic Tracing</title>

  <para>
   By default, trace points are disabled, so you will need to
   explicitly tell the configure script to make the probes available
   in <productname>PostgreSQL</productname>. To include DTrace support
   specify <option>--enable-dtrace</> to configure.  See <xref
   linkend="install-procedure"> for further information.
  </para>
  </sect2>

  <sect2 id="trace-points">
   <title>Built-in Trace Points</title>

  <para>
   A few standard trace points are provided in the source code
   (of course, more can be added as needed for a particular problem).
   These are shown in <xref linkend="trace-point-table">.
  </para>

 <table id="trace-point-table">
  <title>Built-in Trace Points</title>
  <tgroup cols="3">
   <thead>
    <row>
     <entry>Name</entry>
     <entry>Parameters</entry>
     <entry>Overview</entry>
    </row>
   </thead>

   <tbody>
    <row>
     <entry>transaction__start</entry>
     <entry>(int transactionId)</entry>
     <entry>The start of a new transaction.</entry>
    </row>
    <row>
     <entry>transaction__commit</entry>
     <entry>(int transactionId)</entry>
     <entry>The successful completion of a transaction.</entry>
    </row>
    <row>
     <entry>transaction__abort</entry>
     <entry>(int transactionId)</entry>
     <entry>The unsuccessful completion of a transaction.</entry>
    </row>
             
    <row>
     <entry>lwlock__acquire</entry>
     <entry>(int lockid, int mode)</entry>
     <entry>An LWLock has been acquired.</entry>
    </row>
    <row>
     <entry>lwlock__release</entry>
     <entry>(int lockid, int mode)</entry>
     <entry>An LWLock has been released.</entry>
    </row>
    <row>
     <entry>lwlock__startwait</entry>
     <entry>(int lockid, int mode)</entry>
     <entry>An LWLock was not immediately available and a backend
       has begun to wait for the lock to become available.
     </entry>
    </row>    
    <row>
     <entry>lwlock__endwait</entry>
     <entry>(int lockid, int mode)</entry>
     <entry>A backend has been released from its wait for an LWLock.
     </entry>
    </row>
    <row>
     <entry>lwlock__condacquire</entry>
     <entry>(int lockid, int mode)</entry>
     <entry>An LWLock was successfully acquired when the caller specified no
      waiting.
     </entry>
    </row> 
    <row>
     <entry>lwlock__condacquire__fail</entry>
     <entry>(int lockid, int mode)</entry>
     <entry>An LWLock was not successfully acquired when the caller specified
      no waiting.
     </entry>
    </row>
    <row>
     <entry>lock__startwait</entry>
     <entry>(int locktag_field2, int lockmode)</entry>
     <entry>A request for a heavyweight lock (lmgr lock) has begun to wait
      because the lock is not available.
     </entry>
    </row>
    <row>
     <entry>lock__endwait</entry>
     <entry>(int locktag_field2, int lockmode)</entry>
     <entry>A request for a heavyweight lock (lmgr lock) has finished waiting
      (i.e., has acquired the lock).
     </entry>
    </row>
   </tbody>
   </tgroup>
  </table>
  </sect2>

  <sect2 id="using-trace-points">
   <title>Using Trace Points</title>

  <para>
   The example below shows a DTrace script for analyzing transaction
   counts on the system, as an alternative to snapshotting 
   <structname>pg_stat_database</> before and after a performance test:
<programlisting>
#!/usr/sbin/dtrace -qs 

postgresql$1:::transaction-start
{
      @start["Start"] = count();
      self->ts  = timestamp;
}

postgresql$1:::transaction-abort
{
      @abort["Abort"] = count();
}

postgresql$1:::transaction-commit
/self->ts/
{
      @commit["Commit"] = count();
      @time["Total time (ns)"] = sum(timestamp - self->ts);
      self->ts=0;
}
</programlisting>
   Note how the double underline in trace point names needs to
   be replaced by a hyphen when using D script.
   When executed, the example D script gives output such as:
<screen>
# ./txn_count.d `pgrep -n postgres`
^C

Start                                          71
Commit                                         70
Total time (ns)                        2312105013
</screen>
  </para>
  <para>
   You should remember that trace programs need to be carefully written and
   debugged prior to their use, otherwise the trace information collected might
   be meaningless. In most cases where problems are found it is the 
   instrumentation that is at fault, not the underlying system. When 
   discussing information found using dynamic tracing, be sure to enclose
   the script used to allow that too to be checked and discussed.
  </para>
  </sect2>

  <sect2 id="defining-trace-points">
   <title>Defining Trace Points</title>

  <para>
   New trace points can be defined within the code wherever the developer
   desires, though this will require a recompilation.
  </para>

  <para>
   A trace point can be inserted by using one of the
   trace macros. These are chosen according to how many variables will
   be made available for inspection at that trace point. Tracing the
   occurrence of an event can be achieved with a single line, using
   just the trace point name, e.g.:
<programlisting>
PG_TRACE (my__new__trace__point);
</programlisting>
   More complex trace points can be provided with one or more variables
   for inspection by the dynamic tracing utility by using the
   <literal>PG_TRACE</><replaceable>n</> macro that corresponds to the number
   of parameters after the trace point name:
<programlisting>
PG_TRACE3 (my__complex__event, varX, varY, varZ);
</programlisting>
   The definition of the transaction__start trace point is shown below:
<programlisting>
static void
StartTransaction(void)
{
    ...

    /*
     * generate a new transaction id
     */
    s->transactionId = GetNewTransactionId(false);

    XactLockTableInsert(s->transactionId);

    PG_TRACE1(transaction__start, s->transactionId);

    ...
}    
</programlisting>
   Note how the transaction ID is made available to the dynamic tracing
   utility.
  </para>

  <para>
   The dynamic tracing utility might require you to further define these trace
   points.  For example, DTrace requires you to add new probes to the file
   <filename>src/backend/utils/probes.d</> as shown here:
<programlisting>
provider postgresql {
      ...
      probe transaction__start(int);
      ...
 };
</programlisting>
  </para>

  <para>
   You should take care that the data types specified for the probe arguments
   match the data types of the variables used in the <literal>PG_TRACE</>
   macro. This is not checked at compile time. You can check that your newly
   added trace point is available by recompiling, then running the new binary,
   and as root, executing a DTrace command such as:
<programlisting>
dtrace -l -n transaction-start
</programlisting>
  </para>
  </sect2>

 </sect1>

</chapter>