Merge pull request #124 from nastena1606/PG-215-Doc-User-guide-updates-master
PG-215 User Guide updatespull/128/head
commit
c4780aba5a
|
@ -0,0 +1,73 @@
|
|||
# Comparing pg_stat_monitor and pg_stat_statements
|
||||
|
||||
The `pg_stat_monitor` extension is developed on the basis of `pg_stat_statements` as its more advanced replacement.
|
||||
|
||||
Thus, `pg_stat_monitor` inherits the columns available in `pg_stat_statements` plus provides additional ones.
|
||||
|
||||
To see all available columns, run the following command from the `psql` terminal:
|
||||
|
||||
```sql
|
||||
postgres=# \d pg_stat_monitor;
|
||||
```
|
||||
|
||||
The following table compares the `pg_stat_monitor` view with that of `pg_stat_statements`.
|
||||
|
||||
Note that the column names differ depending on the PostgreSQL version you are running.
|
||||
|
||||
|
||||
| Column name for PostgreSQL 13 and above | Column name for PostgreSQL 11 and 12 | pg_stat_monitor | pg_stat_statements
|
||||
|--------------------|--------------------------|-----------------------------|----------------------
|
||||
bucket | bucket | :heavy_check_mark: | :x:
|
||||
bucket_start_time | bucket_start_time | :heavy_check_mark: | :x:
|
||||
userid | userid | :heavy_check_mark: | :heavy_check_mark:
|
||||
datname | datname | :heavy_check_mark: | :heavy_check_mark:
|
||||
client_ip | client_ip | :heavy_check_mark:| :x:
|
||||
queryid | queryid | :heavy_check_mark: | :heavy_check_mark:
|
||||
planid | planid | :heavy_check_mark:| :x:
|
||||
query_plan | query_plan | :heavy_check_mark: | :x:
|
||||
top_query | top_query | :heavy_check_mark: | :x:
|
||||
top_queryid | top_queryid | :heavy_check_mark: | :x:
|
||||
query | query | :heavy_check_mark: | :heavy_check_mark:
|
||||
application_name | application_name | :heavy_check_mark:| :x:
|
||||
relations | relations | :heavy_check_mark: | :x:
|
||||
cmd_type | cmd_type | :heavy_check_mark: | :x:
|
||||
elevel | elevel | :heavy_check_mark: | :x:
|
||||
sqlcode | sqlcode | :heavy_check_mark: | :x:
|
||||
message | message | :heavy_check_mark: | :x:
|
||||
plans_calls | plans_calls | :heavy_check_mark: | :heavy_check_mark:
|
||||
plan_total_time | plan_total_time | :heavy_check_mark: | :heavy_check_mark:
|
||||
plan_min_time | plan_min_time | :heavy_check_mark: | :heavy_check_mark:
|
||||
plan_max_time | plan_max_time | :heavy_check_mark: | :heavy_check_mark:
|
||||
plan_mean_time | plan_mean_time | :heavy_check_mark: | :heavy_check_mark:
|
||||
calls | calls | :heavy_check_mark: | :heavy_check_mark:
|
||||
total_time | total_time | :heavy_check_mark: | :heavy_check_mark:
|
||||
min_time | min_time | :heavy_check_mark: | :heavy_check_mark:
|
||||
max_time | max_time | :heavy_check_mark: | :heavy_check_mark:
|
||||
mean_time | mean_time | :heavy_check_mark: | :heavy_check_mark:
|
||||
stddev_time | stddev_time | :heavy_check_mark: | :heavy_check_mark:
|
||||
rows_retrieved | rows_retrieved | :heavy_check_mark: | :heavy_check_mark:
|
||||
shared_blks_hit | shared_blks_hit | :heavy_check_mark: | :heavy_check_mark:
|
||||
shared_blks_read | shared_blks_read | :heavy_check_mark: | :heavy_check_mark:
|
||||
shared_blks_dirtied | shared_blks_dirtied | :heavy_check_mark: | :heavy_check_mark:
|
||||
shared_blks_written | shared_blks_written | :heavy_check_mark: | :heavy_check_mark:
|
||||
local_blks_hit | local_blks_hit | :heavy_check_mark: | :heavy_check_mark:
|
||||
local_blks_read | local_blks_read | :heavy_check_mark: | :heavy_check_mark:
|
||||
local_blks_dirtied | local_blks_dirtied | :heavy_check_mark: | :heavy_check_mark:
|
||||
local_blks_written | local_blks_written | :heavy_check_mark: | :heavy_check_mark:
|
||||
temp_blks_read | temp_blks_read | :heavy_check_mark: | :heavy_check_mark:
|
||||
temp_blks_written | temp_blks_written | :heavy_check_mark: | :heavy_check_mark:
|
||||
blk_read_time | blk_read_time | :heavy_check_mark: | :heavy_check_mark:
|
||||
blk_write_time | blk_write_time | :heavy_check_mark: | :heavy_check_mark:
|
||||
resp_calls | resp_calls | :heavy_check_mark: | :x:
|
||||
cpu_user_time | cpu_user_time | :heavy_check_mark: | :x:
|
||||
cpu_sys_time | cpu_sys_time | :heavy_check_mark: | :x:
|
||||
wal_records | wal_records | :heavy_check_mark: | :heavy_check_mark:
|
||||
wal_fpi | wal_fpi | :heavy_check_mark: | :heavy_check_mark:
|
||||
wal_bytes | wal_bytes | :heavy_check_mark: | :heavy_check_mark:
|
||||
state_code | state_code | :heavy_check_mark: | :x:
|
||||
state | state | :heavy_check_mark: | :x:
|
||||
|
||||
To learn more about the features in `pg_stat_monitor`, please see the [User guide](https://github.com/percona/pg_stat_monitor/blob/master/docs/USER_GUIDE.md).
|
||||
|
||||
|
||||
Additional reading: [pg_stat_statements](https://www.postgresql.org/docs/current/pgstatstatements.html)
|
|
@ -0,0 +1,63 @@
|
|||
# `pg_stat_monitor` view reference
|
||||
|
||||
`pg_stat_monitor` provides a view where the statistics data is displayed. To see all available columns, run the following command from `psql`:
|
||||
|
||||
```sql
|
||||
postgres=# \d pg_stat_monitor
|
||||
```
|
||||
|
||||
Depending on the PostgreSQL version, some column names may differ. The following table describes the `pg_stat_monitor` view for PostgreSQL 13 and higher versions.
|
||||
|
||||
|
||||
| Column | Type | Description
|
||||
|--------------------|--------------------------|------------------
|
||||
bucket | integer | Data collection unit. The number shows what bucket in a chain a record belongs to
|
||||
bucket_start_time | timestamp with time zone | The start time of the bucket|
|
||||
userid | regrole | An ID of the user who run a query |
|
||||
datname | name | The name of a database where the query was executed
|
||||
client_ip | inet | The IP address of a client that run the query
|
||||
queryid | text | The internal hash code serving to identify every query in a statement
|
||||
planid | text | An internally generated ID of a query plan
|
||||
query_plan | text | The sequence of steps used to execute a query. This parameter is available only when the `pgsm_enable_query_plan` is enabled.
|
||||
top_query | text | Shows the top query used in a statement |
|
||||
query | text | The actual text of the query |
|
||||
application_name | text | Shows the name of the application connected to the database
|
||||
relations | text[] | The list of tables involved in the query
|
||||
cmd_type | integer | Type of the query executed
|
||||
cmd_type_text | text[] | The description of the query executed
|
||||
elevel | integer | Shows the error level of a query (WARNING, ERROR, LOG)
|
||||
sqlcode | integer | SQL error code
|
||||
message | text | The error message
|
||||
plans_calls | bigint | The number of times the statement was planned
|
||||
plan_total_time | double precision | The total time (in ms) spent on planning the statement
|
||||
plan_min_time | double precision | Minimum time (in ms) spent on planning the statement
|
||||
plan_max_time | double precision | Maximum time (in ms) spent on planning the statement
|
||||
plan_mean_time | double precision | The mean (average) time (in ms) spent on planning the statement
|
||||
plan_stddev_time | double precision | The standard deviation of time (in ms) spent on planning the statement
|
||||
calls | bigint | The number of times a particular query was executed
|
||||
total_time | double precision | The total time (in ms) spent on executing a query
|
||||
min_time | double precision | The minimum time (in ms) it took to execute a query
|
||||
max_time | double precision | The maximum time (in ms) it took to execute a query
|
||||
mean_time | double precision | The mean (average) time (in ms) it took to execute a query
|
||||
stddev_time | double precision | The standard deviation of time (in ms) spent on executing a query
|
||||
rows_retrieved | bigint | The number of rows retrieved when executing a query
|
||||
shared_blks_hit | bigint | Shows the total number of shared memory blocks returned from the cache
|
||||
shared_blks_read | bigint | Shows the total number of shared blocks returned not from the cache
|
||||
shared_blks_dirtied | bigint | Shows the number of shared memory blocks "dirtied" by the query execution (i.e. a query modified at least one tuple in a block and this block must be written to a drive)
|
||||
shared_blks_written | bigint | Shows the number of shared memory blocks written simultaneously to a drive during the query execution
|
||||
local_blks_hit | bigint | The number of blocks which are considered as local by the backend and thus are used for temporary tables
|
||||
local_blks_read | bigint | Total number of local blocks read during the query execution
|
||||
local_blks_dirtied | bigint | Total number of local blocks "dirtied" during the query execution (i.e. a query modified at least one tuple in a block and this block must be written to a drive)
|
||||
local_blks_written | bigint | Total number of local blocks written simultaneously to a drive during the query execution
|
||||
temp_blks_read | bigint | Total number of blocks of temporary files read from a drive. Temporary files are used when there's not enough memory to execute a query
|
||||
temp_blks_written | bigint | Total number of blocks of temporary files written to a drive
|
||||
blk_read_time | double precision | Total waiting time (in ms) for reading blocks
|
||||
blk_write_time | double precision | Total waiting time (in ms) for writing blocks to a drive
|
||||
resp_calls | text[] | Call histogram
|
||||
cpu_user_time | double precision | The time (in ms) the CPU spent on running the query
|
||||
cpu_sys_time | double precision | The time (in ms) the CPU spent on executing the kernel code
|
||||
wal_records | bigint | The total number of WAL (Write Ahead Logs) generated by the query
|
||||
wal_fpi | bigint | The total number of WAL FPI (Full Page Images) generated by the query
|
||||
wal_bytes | numeric | Total number of bytes used for the WAL generated by the query
|
||||
state_code | bigint | Shows the state code of a query
|
||||
state | text | The state message
|
|
@ -1,173 +1,334 @@
|
|||
# User Guide
|
||||
|
||||
This document describes the configuration, key features and usage of ``pg_stat_monitor`` extension and compares it with ``pg_stat_statements``.
|
||||
* [Introduction](#introduction)
|
||||
* [Features](#features)
|
||||
* [Views](#views)
|
||||
* [Functions](#functions)
|
||||
* [Configuration](#configuration)
|
||||
* [Usage examples](#usage-examples)
|
||||
|
||||
For how to install and set up ``pg_stat_monitor``, see [README](https://github.com/percona/pg_stat_monitor/blob/master/README.md).
|
||||
## Introduction
|
||||
|
||||
After you've installed and enabled ``pg_stat_monitor``, create the ``pg_stat_monitor`` extension using the ``CREATE EXTENSION`` command.
|
||||
This document describes the features, functions and configuration of the ``pg_stat_monitor`` extension and gives some usage examples. For how to install and set up ``pg_stat_monitor``, see [Installation in README](https://github.com/percona/pg_stat_monitor/blob/master/README.md#installation).
|
||||
|
||||
```sql
|
||||
CREATE EXTENSION pg_stat_monitor;
|
||||
CREATE EXTENSION
|
||||
## Features
|
||||
|
||||
The following are the key features of pg_stat_monitor:
|
||||
|
||||
* [Time buckets](#time-buckets),
|
||||
* [Table and index access statistics per statement](#table-and-index-access-statistics-per-statement),
|
||||
* Query statistics:
|
||||
* [Query and client information](#query-and-client-information),
|
||||
* [Query timing information](#query-timing-information),
|
||||
* [Query execution plan information](#query-execution-plan-information),
|
||||
* [Use of actual data or parameters placeholders in queries](#use-of-actual-data-or-parameters-placeholders-in-queries),
|
||||
* [Query type filtering](#query-type-filtering),
|
||||
* [Query metadata supporting Google’s Sqlcommentor](#query-metadata),
|
||||
* [Top query tracking](#top-query-tracking),
|
||||
* [Relations](#relations) - showing tables involved in a query,
|
||||
* [Monitoring of queries terminated with ERROR, WARNING and LOG error levels](#monitoring-of-queries-terminated-with-error-warning-and-log-error-levels),
|
||||
* [Integration with Percona Monitoring and Management (PMM) tool](#integration-with-pmm),
|
||||
* [Histograms](#histogram) - visual representation of query performance.
|
||||
|
||||
|
||||
### Time buckets
|
||||
|
||||
Instead of supplying one set of ever-increasing counts, `pg_stat_monitor` computes stats for a configured number of time intervals; time buckets. This allows for much better data accuracy, especially in the case of high-resolution or unreliable networks.
|
||||
|
||||
### Table and index access statistics per statement
|
||||
|
||||
`pg_stat_monitor` collects the information about what tables were accessed by a statement. This allows you to identify all queries which access a given table easily.
|
||||
|
||||
|
||||
### Query and client information
|
||||
|
||||
|
||||
`pg_stat_monitor` provides additional metrics for detailed analysis of query performance from various perspectives, including client connection details like user name, application name, IP address to name a few relevant columns.
|
||||
With this information, `pg_stat_monitor` enables users to track a query to the originating application. More details about the application or query may be incorporated in the SQL query in a [Google’s Sqlcommenter](https://google.github.io/sqlcommenter/) format.
|
||||
|
||||
### Query timing information
|
||||
|
||||
Understanding query execution time stats helps you identify what affects query performance and take measures to optimize it. `pg_stat_monitor` collects the total, min, max and average (mean) time it took to execute a particular query and provides this data in separate columns. See the [Query timing information](#usage-examples-query-timing-information) example for the sample output.
|
||||
|
||||
|
||||
### Query execution plan information
|
||||
|
||||
Every query has a plan that was constructed for its executing. Collecting the query plan information as well as monitoring query plan timing helps you understand how you can modify the query to optimize its execution. It also helps make communication about the query clearer when discussing query performance with other DBAs and application developers.
|
||||
|
||||
See the [Query execution plan](#usage-examples-query-execution-time) example for the sample output.
|
||||
|
||||
### Use of actual data or parameters placeholders in queries
|
||||
|
||||
You can select whether to see queries with parameters placeholders or actual query data. The benefit of having the full query example is in being able to run the [EXPLAIN](https://www.postgresql.org/docs/current/sql-explain.html) command on it to see how its execution was planned. As a result, you can modify the query to make it run better.
|
||||
|
||||
### Query type filtering
|
||||
|
||||
`pg_stat_monitor` monitors queries per type (``SELECT``, `INSERT`, `UPDATE` or `DELETE`) and classifies them accordingly in the `cmd_type` column. This way you can separate the queries you are interested in and focus on identifying the issues and optimizing query performance.
|
||||
|
||||
See the [Query type filtering example](#usage-examples-query-time-filtering) for the sample output.
|
||||
|
||||
### Query metadata
|
||||
|
||||
Google’s Sqlcommenter is a useful tool that in a way bridges that gap between ORM libraries and understanding database performance. And ``pg_stat_monitor`` supports it. So, you can now put any key-value data (like what client executed a query or if it is testing vs production query) in the comments in `/* … */` syntax in your SQL statements, and the information will be parsed by `pg_stat_monitor` and made available in the comments column in the `pg_stat_monitor` view. For details on the comments’ syntax, see [Sqlcommenter documentation](https://google.github.io/sqlcommenter/).
|
||||
|
||||
To see how it works, see the [Query metadata](#isage-examples-query-metadata) example.
|
||||
|
||||
### Top query tracking
|
||||
|
||||
Using functions is common. While running, functions can execute queries internally. `pg_stat_monitor` not only keeps track of all executed queries within a function, but also marks that function as top query.
|
||||
|
||||
Top query indicates the main query. To illustrate, for the SELECT query that is invoked within a function, the top query is calling this function.
|
||||
|
||||
This enables you to backtrack to the originating function and thus simplifies the tracking and analysis.
|
||||
|
||||
Find more details in the [usage example](#usage-examples-function-execution-tracking).
|
||||
|
||||
### Relations
|
||||
|
||||
`pg_stat_monitor` provides the list of tables involved in the query in the relations column. This reduces time on identifying the tables and simplifies the analysis.
|
||||
|
||||
### Monitoring queries terminated with ERROR, WARNING and LOG error levels
|
||||
|
||||
Monitoring queries that terminate with ERROR, WARNING, LOG states can give useful information to debug an issue. Such messages have the error level (`elevel`), error code (`sqlcode`), and error message (`message`). `pg_stat_monitor` collects all this information and aggregates it so that you can measure performance for successful and failed queries separately, as well as understand why a particular query failed to execute successfully.
|
||||
|
||||
### Integration with PMM
|
||||
|
||||
To timely identify and react on issues, performance should be automated and alerts should be sent when an issue occurs. There are many monitoring tools available for PostgreSQL, some of them (like Nagios) supporting custom metrics provided via extensions. Though you can integrate `pg_stat_monitor` with these tools, it natively supports integration with Percona Management and Monitoring (PMM). This integration allows you to enjoy all the features provided by both solutions: advanced statistics data provided by `pg_stat_monitor` and automated monitoring with data visualization on dashboards, security threat checks and alerting, available in PMM out of the box.
|
||||
|
||||
To learn how to integrate pg_stat_monitor with PMM, see [Configure pg_stat_monitor in PMM](https://www.percona.com/doc/percona-monitoring-and-management/2.x/setting-up/client/postgresql.html#pg_stat_monitor)
|
||||
|
||||
### Histogram
|
||||
|
||||
Histogram (the `resp_calls` parameter) provides a visual representation of query performance. With the help of the histogram function, you can view a timing/calling data histogram in response to an SQL query.
|
||||
|
||||
Learn more about using histograms from the [usage example](#usage-examples-histogram).
|
||||
|
||||
## Views
|
||||
|
||||
`pg_stat_monitor` provides the following views:
|
||||
* `pg_stat_monitor` is the view where statistics data is presented.
|
||||
* `pg_stat_monitor_settings` view shows available configuration options which you can change.
|
||||
|
||||
### `pg_stat_monitor` view
|
||||
|
||||
The statistics gathered by the module are made available via the view named `pg_stat_monitor`. This view contains one row for each distinct combination of metrics and whether it is a top-level statement or not (up to the maximum number of distinct statements that the module can track). For details about available counters, refer to the [`pg_stat_monitor` view reference](https://github.com/percona/pg_stat_monitor/blob/master/docs/REFERENCE.md).
|
||||
|
||||
The following are the primary keys for pg_stat_monitor:
|
||||
|
||||
* `bucket`,
|
||||
* `userid`,
|
||||
* `dbid`,
|
||||
* `client_ip`,
|
||||
* `application_name`.
|
||||
|
||||
A new row is created for each key in the `pg_stat_monitor` view.
|
||||
|
||||
`pg_stat_monitor` inherits the metrics available in `pg_stat_statements`, plus provides additional ones. See the [`pg_stat_monitor` vs `pg_stat_statements` comparison](https://github.com/percona/pg_stat_monitor/blob/master/docs/REFERENCE.md) for details.
|
||||
|
||||
For security reasons, only superusers and members of the `pg_read_all_stats` role are allowed to see the SQL text and `queryid` of queries executed by other users. Other users can see the statistics, however, if the view has been installed in their database.
|
||||
|
||||
### pg_stat_monitor_settings view
|
||||
|
||||
The `pg_stat_monitor_settings` view shows one row per `pg_stat_monitor` configuration parameter. It displays configuration parameter name, value, default value, description, minimum and maximum values, and whether a restart is required for a change in value to be effective.
|
||||
|
||||
## Functions
|
||||
|
||||
### pg_stat_monitor_reset()
|
||||
|
||||
This function resets all the statistics and clears the view. Eventually, the function will delete all the previous data.
|
||||
|
||||
### pg_stat_monitor_version()
|
||||
This function provides the build version of `pg_stat_monitor` version.
|
||||
|
||||
```
|
||||
postgres=# select pg_stat_monitor_version();
|
||||
pg_stat_monitor_version
|
||||
-------------------------
|
||||
devel
|
||||
(1 row)
|
||||
```
|
||||
|
||||
### Configuration
|
||||
Here is the complete list of configuration parameters.
|
||||
### histogram(bucket id, query id)
|
||||
|
||||
It is used to generate the histogram, you can refer to histogram sections.
|
||||
|
||||
## Configuration
|
||||
|
||||
Use the following command to view available configuration parameters in the `pg_stat_monitor_settings` view:
|
||||
|
||||
```sql
|
||||
SELECT * FROM pg_stat_monitor_settings;
|
||||
name | value | default_value | description | minimum | maximum | restart
|
||||
------------------------------------------+--------+---------------+----------------------------------------------------------------------------------------------------------+---------+------------+---------
|
||||
pg_stat_monitor.pgsm_max | 100 | 100 | Sets the maximum size of shared memory in (MB) used for statement's metadata tracked by pg_stat_monitor. | 1 | 1000 | 1
|
||||
pg_stat_monitor.pgsm_query_max_len | 1024 | 1024 | Sets the maximum length of query. | 1024 | 2147483647 | 1
|
||||
pg_stat_monitor.pgsm_enable | 1 | 1 | Enable/Disable statistics collector. | 0 | 0 | 0
|
||||
pg_stat_monitor.pgsm_track_utility | 1 | 1 | Selects whether utility commands are tracked. | 0 | 0 | 0
|
||||
pg_stat_monitor.pgsm_normalized_query | 1 | 1 | Selects whether save query in normalized format. | 0 | 0 | 0
|
||||
pg_stat_monitor.pgsm_max_buckets | 10 | 10 | Sets the maximum number of buckets. | 1 | 10 | 1
|
||||
pg_stat_monitor.pgsm_bucket_time | 60 | 60 | Sets the time in seconds per bucket. | 1 | 2147483647 | 1
|
||||
pg_stat_monitor.pgsm_histogram_min | 0 | 0 | Sets the time in millisecond. | 0 | 2147483647 | 1
|
||||
pg_stat_monitor.pgsm_histogram_max | 100000 | 100000 | Sets the time in millisecond. | 10 | 2147483647 | 1
|
||||
pg_stat_monitor.pgsm_histogram_buckets | 10 | 10 | Sets the maximum number of histogram buckets | 2 | 2147483647 | 1
|
||||
pg_stat_monitor.pgsm_query_shared_buffer | 20 | 20 | Sets the maximum size of shared memory in (MB) used for query tracked by pg_stat_monitor. | 1 | 10000 | 1
|
||||
pg_stat_monitor.pgsm_overflow_target | 1 | 1 | Sets the overflow target for pg_stat_monitor | 0 | 1 | 1
|
||||
pg_stat_monitor.pgsm_track_planning | 0 | 1 | Selects whether planning statistics are tracked. | 0 | 0 | 0
|
||||
(13 rows)
|
||||
|
||||
|
||||
```
|
||||
Some configuration parameters require a server restart and should be set before the server startup. These must be set in the ``postgresql.conf`` file. Other parameters do not require a server restart and can be set permanently either in the ``postgresql.conf`` or from the client (``psql``).
|
||||
|
||||
The table below shows set up options for each configuration parameter and whether the server restart is required to apply the parameter's value:
|
||||
To amend the `pg_stat_monitor` configuration, use the General Configuration Unit (GCU) system. Some configuration parameters require the server restart and should be set before the server startup. These must be set in the `postgresql.conf` file. Other parameters do not require server restart and can be set permanently either in the `postgresql.conf` or from the client (`psql`) using the SET or ALTER SYSTEM SET commands.
|
||||
|
||||
The following table shows setup options for each configuration parameter and whether the server restart is required to apply the parameter's value:
|
||||
|
||||
| Parameter Name | postgresql.conf | SET | ALTER SYSTEM SET | server restart | configuration reload
|
||||
| Parameter Name | postgresql.conf | SET | ALTER SYSTEM SET | server restart | configuration reload
|
||||
| ----------------------------------------------|--------------------|-----|-------------------|-------------------|---------------------
|
||||
| pg_stat_monitor.pgsm_max | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| pg_stat_monitor.pgsm_query_max_len | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| pg_stat_monitor.pgsm_enable | :heavy_check_mark: | :x: |:heavy_check_mark: |:x: | :x:
|
||||
| pg_stat_monitor.pgsm_track_utility | :heavy_check_mark: | :heavy_check_mark: |:heavy_check_mark: |:x: | :heavy_check_mark:
|
||||
| pg_stat_monitor.pgsm_normalized_query | :heavy_check_mark: | :heavy_check_mark: |:heavy_check_mark: |:x: | :heavy_check_mark:
|
||||
| pg_stat_monitor.pgsm_max_buckets | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :heavy_check_mark:
|
||||
| pg_stat_monitor.pgsm_bucket_time | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| pg_stat_monitor.pgsm_object_cache | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| pg_stat_monitor.pgsm_respose_time_lower_bound | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| pg_stat_monitor.pgsm_respose_time_step | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| pg_stat_monitor.pgsm_query_shared_buffer | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
|
||||
| [pg_stat_monitor.pgsm_max](#pg-stat-monitorpgsm-max) | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| [pg_stat_monitor.pgsm_query_max_len](#pg-stat-monitorpgsm-query-max-len) | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| [pg_stat_monitor.pgsm_enable](#pg-stat-monitorpgsm-enable) | :heavy_check_mark: | :x: |:heavy_check_mark: |:x: | :x:
|
||||
| [pg_stat_monitor.pgsm_track_utility](#pg-stat-monitorpgsm-track-utility) | :heavy_check_mark: | :heavy_check_mark: |:heavy_check_mark: |:x: | :heavy_check_mark:
|
||||
| [pg_stat_monitor.pgsm_normalized_query](#pg-stat-monitorpgsm-normalized-query) | :heavy_check_mark: | :heavy_check_mark: |:heavy_check_mark: |:x: | :heavy_check_mark:
|
||||
| [pg_stat_monitor.pgsm_max_buckets](#pg-stat-monitorpgsm-max-buckets) | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :heavy_check_mark:
|
||||
| [pg_stat_monitor.pgsm_bucket_time](#pg-stat-monitorpgsm-bucket-time) | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| [pg_stat_monitor.pgsm_object_cache](#pg-stat-monitorpgsm-object-cache) | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| [pg_stat_monitor.pgsm_histogram_min](#pg-stat-monitorpgsm-histogram-min) | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| [pg_stat_monitor.pgsm_histogram_max](#pg-stat-monitorpgsm-histogram-max) | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| [pg_stat_monitor.pgsm_histogram_buckets](#pg-stat-monitorpgsm-histogram-buckets) | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| [pg_stat_monitor.pgsm_query_shared_buffer](#pg-stat-monitorpgsm-query-shared-buffer) | :heavy_check_mark: | :x: |:x: |:heavy_check_mark: | :x:
|
||||
| [pg_stat_monitor.pgsm_overflow_target](#pg-stat-monitorpgsm-overflow-target) | :heavy_check_mark: | :x: | :x: | :heavy_check_mark: | :x: |
|
||||
| [pg_stat_monitor.pgsm_enable_query_plan](pg-stat-monitorpgsm-enable-query-plan) | :heavy_check_mark: | :x: | :x: | :heavy_check_mark: | :x: |
|
||||
| [pg_stat_monitor.pgsm_track_planning](#pg-stat-monitorpgsm-track-planning) | :heavy_check_mark: | :x: | :x: | :heavy_check_mark: | :x: |
|
||||
|
||||
#### Parameters description:
|
||||
|
||||
- **pg_stat_monitor.pgsm_max**: This parameter defines the limit of shared memory for ``pg_stat_monitor``. This memory is used by buckets in a circular manner. The memory is divided between the buckets equally, at the start of the PostgreSQL.
|
||||
- **pg_stat_monitor.pgsm_query_max_len**: Sets the maximum size of the query. This parameter can only be set at the start of PostgreSQL. For long queries, the query is truncated to that particular length. This is to avoid unnecessary usage of shared memory.
|
||||
- **pg_stat_monitor.pgsm_enable**: This parameter enables or disables the monitoring. "Disable" means that ``pg_stat_monitor`` will not collect the statistics for the whole cluster.
|
||||
- **pg_stat_monitor.pgsm_track_utility**: This parameter controls whether utility commands are tracked by the module. Utility commands are all those other than ``SELECT``, ``INSERT``, ``UPDATE``, and ``DELETE``.
|
||||
- **pg_stat_monitor.pgsm_normalized_query**: By default, the query shows the actual parameter instead of the placeholder. It is quite useful when users want to use that query and try to run that query to check the abnormalities. But in most cases users like the queries with a placeholder. This parameter is used to toggle between the two said options.
|
||||
- **pg_stat_monitor.pgsm_max_buckets**: ``pg_stat_monitor`` accumulates the information in the form of buckets. All the aggregated information is bucket based. This parameter is used to set the number of buckets the system can have. For example, if this parameter is set to 2, then the system will create two buckets. First, the system will add all the information into the first bucket. After its lifetime (defined in the pg_stat_monitor.pgsm_bucket_time parameter) expires, it will switch to the second bucket, reset all the counters and repeat the process.
|
||||
- **pg_stat_monitor.pgsm_bucket_time**: This parameter is used to set the lifetime of the bucket. System switches between buckets on the basis of ``pg_stat_monitor.pgsm_bucket_time``.
|
||||
- **pg_stat_monitor.pgsm_respose_time_lower_bound**: ``pg_stat_monitor`` also stores the execution time histogram. This parameter is used to set the lower bound of the histogram.
|
||||
- **pg_stat_monitor.pgsm_respose_time_step:** This parameter is used to set the steps for the histogram.
|
||||
|
||||
##### pg_stat_monitor.pgsm_max
|
||||
|
||||
Values:
|
||||
- Min: 1
|
||||
- Max: 1000
|
||||
- Default: 100
|
||||
|
||||
|
||||
### Usage
|
||||
This parameter defines the limit of shared memory (in MB) for ``pg_stat_monitor``. This memory is used by buckets in a circular manner. The memory is divided between the buckets equally, at the start of the PostgreSQL. Requires the server restart.
|
||||
|
||||
The ``pg_stat_monitor`` extension contains a view called ``pg_stat_monitor``, which containss all the monitoring information. Find the list of columns in ``pg_stat_monitor`` view in the following table. The table also shows whether a particular column is available in ``pg_stat_statements``.
|
||||
##### pg_stat_monitor.pgsm_query_max_len
|
||||
|
||||
Values:
|
||||
- Min: 1024
|
||||
- Max: 2147483647
|
||||
- Default: 1024
|
||||
|
||||
Sets the maximum size of the query. This parameter can only be set at the start of PostgreSQL. For long queries, the query is truncated to that particular length. This is to avoid unnecessary usage of shared memory. Requires the server restart.
|
||||
|
||||
##### pg_stat_monitor.pgsm_enable
|
||||
|
||||
Type: boolean. Default: 1
|
||||
|
||||
Enables or disables the monitoring. "Disable" (0) means that ``pg_stat_monitor`` will not collect the statistics for the whole cluster.
|
||||
|
||||
##### pg_stat_monitor.pgsm_track_utility
|
||||
|
||||
Type: boolean. Default: 1
|
||||
|
||||
This parameter controls whether utility commands are tracked by the module. Utility commands are all those other than ``SELECT``, ``INSERT``, ``UPDATE``, and ``DELETE``.
|
||||
|
||||
##### pg_stat_monitor.pgsm_normalized_query
|
||||
|
||||
Type: boolean. Default: 1
|
||||
|
||||
By default, the query shows the actual parameter instead of the placeholder. It is quite useful when users want to use that query and try to run that query to check the abnormalities. But in most cases users like the queries with a placeholder. This parameter is used to toggle between the two said options.
|
||||
|
||||
##### pg_stat_monitor.pgsm_max_buckets
|
||||
|
||||
Values:
|
||||
- Min: 1
|
||||
- Max: 10
|
||||
- Default: 10
|
||||
|
||||
``pg_stat_monitor`` accumulates the information in the form of buckets. All the aggregated information is bucket based. This parameter is used to set the number of buckets the system can have. For example, if this parameter is set to 2, then the system will create two buckets. First, the system will add all the information into the first bucket. After its lifetime (defined in the [pg_stat_monitor.pgsm_bucket_time](#pg-stat-monitorpgsm-bucket-time) parameter) expires, it will switch to the second bucket, reset all the counters and repeat the process.
|
||||
|
||||
Requires the server restart.
|
||||
|
||||
#### pg_stat_monitor.pgsm_bucket_time
|
||||
|
||||
Values:
|
||||
- Min: 1
|
||||
- Max: 2147483647
|
||||
- Default: 300
|
||||
|
||||
This parameter is used to set the lifetime of the bucket. System switches between buckets on the basis of [pg_stat_monitor.pgsm_bucket_time](#pg-stat-monitorpgsm-bucket-time).
|
||||
|
||||
Requires the server restart.
|
||||
|
||||
##### pg_stat_monitor.pgsm_histogram_min
|
||||
|
||||
Values:
|
||||
- Min: 0
|
||||
- Max: 2147483647
|
||||
- Default: 0
|
||||
|
||||
``pg_stat_monitor`` also stores the execution time histogram. This parameter is used to set the lower bound of the histogram (in ms).
|
||||
|
||||
Requires the server restart.
|
||||
|
||||
##### pg_stat_monitor.pgsm_histogram_max
|
||||
|
||||
Values:
|
||||
- Min: 10
|
||||
- Max: 2147483647
|
||||
- Default: 100000
|
||||
|
||||
This parameter sets the upper bound of the execution time histogram (in ms). Requires the server restart.
|
||||
|
||||
##### pg_stat_monitor.pgsm_histogram_buckets
|
||||
|
||||
Values:
|
||||
- Min: 2
|
||||
- Max: 2147483647
|
||||
- Default: 10
|
||||
|
||||
This parameter sets the maximum number of histogram buckets. Requires the server restart.
|
||||
|
||||
##### pg_stat_monitor.pgsm_query_shared_buffer
|
||||
|
||||
Values:
|
||||
- Min: 1
|
||||
- Max: 10000
|
||||
- Default: 20
|
||||
|
||||
This parameter defines the shared memory limit (in MB) allocated for a query tracked by ``pg_stat_monitor``. Requires the server restart.
|
||||
|
||||
##### pg_stat_monitor.pgsm_overflow_target
|
||||
|
||||
Type: boolean. Default: 1
|
||||
|
||||
Sets the overflow target for the `pg_stat_monitor`. Requires the server restart.
|
||||
|
||||
#### pg_stat_monitor.pgsm_enable_query_plan
|
||||
|
||||
Type: boolean. Default: 1
|
||||
|
||||
Enables or disables query plan monitoring. When the `pgsm_enable_query_plan` is disabled (0), the query plan will not be captured by `pg_stat_monitor`. Enabling it may adversely affect the database performance. Requires the server restart.
|
||||
|
||||
|
||||
| Column | Type | pg_stat_monitor | pg_stat_statements
|
||||
|--------------------|--------------------------|----------------------|------------------
|
||||
bucket | integer | :heavy_check_mark: | :x:
|
||||
bucket_start_time | timestamp with time zone | :heavy_check_mark: | :x:
|
||||
userid | oid | :heavy_check_mark: | :heavy_check_mark:
|
||||
dbid | oid | :heavy_check_mark: | :heavy_check_mark:
|
||||
client_ip | inet | :heavy_check_mark: | :x:
|
||||
queryid | text | :heavy_check_mark: | :heavy_check_mark:
|
||||
planid | text | :heavy_check_mark: | :x:
|
||||
query_plan | text | :heavy_check_mark: | :x:
|
||||
top_query | text | :heavy_check_mark: | :x:
|
||||
query | text | :heavy_check_mark: | :heavy_check_mark:
|
||||
application_name | text | :heavy_check_mark: | :x:
|
||||
relations | text[] | :heavy_check_mark: | :x:
|
||||
cmd_type | text[] | :heavy_check_mark: | :x:
|
||||
elevel | integer | :heavy_check_mark: | :x:
|
||||
sqlcode | integer | :heavy_check_mark: | :x:
|
||||
message | text | :heavy_check_mark: | :x:
|
||||
plans | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
plan_total_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
plan_min_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
plan_max_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
plan_mean_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
plan_stddev_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
calls | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
total_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
min_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
max_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
mean_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
stddev_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
rows_retrieved | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
shared_blks_hit | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
shared_blks_read | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
shared_blks_dirtied | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
shared_blks_written | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
local_blks_hit | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
local_blks_read | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
local_blks_dirtied | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
local_blks_written | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
temp_blks_read | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
temp_blks_written | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
blk_read_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
blk_write_time | double precision | :heavy_check_mark: | :heavy_check_mark:
|
||||
resp_calls | text[] | :heavy_check_mark: | :x:
|
||||
cpu_user_time | double precision | :heavy_check_mark: | :x:
|
||||
cpu_sys_time | double precision | :heavy_check_mark: | :x:
|
||||
wal_records | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
wal_fpi | bigint | :heavy_check_mark: | :heavy_check_mark:
|
||||
wal_bytes | numeric | :heavy_check_mark: | :heavy_check_mark:
|
||||
state_code | bigint | :heavy_check_mark: | :x:
|
||||
state | text | :heavy_check_mark: | :x:
|
||||
##### pg_stat_monitor.pgsm_track_planning
|
||||
|
||||
Type: boolean. Default: 0
|
||||
|
||||
This parameter instructs ``pg_stat_monitor`` to monitor query planning statistics. Requires the server restart.
|
||||
|
||||
## Usage examples
|
||||
|
||||
Note that the column names differ depending on the PostgreSQL version you are using. The following usage examples are provided for PostgreSQL version 13.
|
||||
For versions 11 and 12, please consult the [pg_stat_monitor reference](https://github.com/percona/pg_stat_monitor/blob/master/docs/REFERENCE.md).
|
||||
|
||||
### Querying buckets
|
||||
|
||||
|
||||
|
||||
The following are some key features of pg_stat_monitor and usage examples.
|
||||
|
||||
#### Buckets
|
||||
|
||||
**`bucket`**: Accumulates the statistics per bucket. All the information and aggregate reset for each bucket. The bucket will be a number showing the number of buckets for which this record belongs.
|
||||
|
||||
**`bucket_start_time`**: shows the start time of the bucket.
|
||||
|
||||
```sql
|
||||
postgres=# select bucket, bucket_start_time, query,calls from pg_stat_monitor order by bucket;
|
||||
|
||||
bucket | bucket_start_time | query | calls
|
||||
--------+---------------------+---------------------------------------------------------------------------------------------------------------+-------
|
||||
3 | 11-01-2021 17:30:45 | copy pgbench_accounts from stdin | 1
|
||||
3 | 11-01-2021 17:30:45 | alter table pgbench_accounts add primary key (aid) | 1
|
||||
3 | 11-01-2021 17:30:45 | vacuum analyze pgbench_accounts | 1
|
||||
3 | 11-01-2021 17:30:45 | vacuum analyze pgbench_tellers | 1
|
||||
3 | 11-01-2021 17:30:45 | insert into pgbench_branches(bid,bbalance) values($1,$2) | 100
|
||||
5 | 11-01-2021 17:31:15 | vacuum analyze pgbench_branches | 1
|
||||
5 | 11-01-2021 17:31:15 | copy pgbench_accounts from stdin | 1
|
||||
5 | 11-01-2021 17:31:15 | vacuum analyze pgbench_tellers | 1
|
||||
5 | 11-01-2021 17:31:15 | commit | 1
|
||||
6 | 11-01-2021 17:31:30 | alter table pgbench_branches add primary key (bid) | 1
|
||||
6 | 11-01-2021 17:31:30 | vacuum analyze pgbench_accounts | 1
|
||||
-[ RECORD 1 ]-----+------------------------------------------------------------------------------------
|
||||
bucket | 0
|
||||
bucket_start_time | 2021-10-22 11:10:00
|
||||
query | select bucket, bucket_start_time, query,calls from pg_stat_monitor order by bucket;
|
||||
calls | 1
|
||||
```
|
||||
|
||||
#### Query Information
|
||||
The `bucket` parameter shows the number of a bucket for which a given record belongs.
|
||||
The `bucket_start_time` shows the start time of the bucket.
|
||||
`query` shows the actual query text.
|
||||
`calls` shows how many times a given query was called.
|
||||
|
||||
**`userid`**: An ID of the user to whom that query belongs. ``pg_stat_monitor`` collects queries from all the users and uses the `userid` to segregate the queries based on different users.
|
||||
### Query information
|
||||
|
||||
**`dbid`**: The database ID of the query. ``pg_stat_monitor`` accumulates queries from all the databases; therefore, this column is used to identify the database.
|
||||
**Example 1: Shows the usename, database name, unique queryid hash, query, and the total number of calls of that query.**
|
||||
|
||||
**`queryid`**: ``pg_stat_monitor`` generates a unique ID for each query (queryid).
|
||||
|
||||
**`query`**: The query column contains the actual text of the query. This parameter depends on the **`pg_stat_monitor.pgsm_normalized_query`** configuration parameters, in which format to show the query.
|
||||
|
||||
**`calls`**: Number of calls of that particular query.
|
||||
|
||||
|
||||
##### Example: Shows the usename, database name, unique queryid hash, query, and the total number of calls of that query.
|
||||
```sql
|
||||
postgres=# SELECT userid, datname, queryid, substr(query,0, 50) AS query, calls FROM pg_stat_monitor;
|
||||
userid | datname | queryid | query | calls
|
||||
userid | datname | queryid | query | calls
|
||||
---------+----------+------------------+---------------------------------------------------+-------
|
||||
vagrant | postgres | 939C2F56E1F6A174 | END | 561
|
||||
vagrant | postgres | 2A4437C4905E0E23 | SELECT abalance FROM pgbench_accounts WHERE aid = | 561
|
||||
|
@ -186,220 +347,43 @@ postgres=# SELECT userid, datname, queryid, substr(query,0, 50) AS query, calls
|
|||
|
||||
```
|
||||
|
||||
##### Example: Shows the connected application_name.
|
||||
**Example 2: Shows the connected application details.**
|
||||
|
||||
```sql
|
||||
SELECT application_name, query FROM pg_stat_monitor;
|
||||
application_name | query
|
||||
------------------+------------------------------------------------------------------------------------------------------
|
||||
pgbench | UPDATE pgbench_branches SET bbalance = bbalance + $1 WHERE bid = $2
|
||||
pgbench | UPDATE pgbench_accounts SET abalance = abalance + $1 WHERE aid = $2
|
||||
pgbench | vacuum pgbench_tellers
|
||||
pgbench | SELECT abalance FROM pgbench_accounts WHERE aid = $1
|
||||
pgbench | END
|
||||
pgbench | select count(*) from pgbench_branches
|
||||
pgbench | BEGIN
|
||||
pgbench | INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES ($1, $2, $3, $4, CURRENT_TIMESTAMP)
|
||||
psql | select application_name, query from pg_stat_monitor
|
||||
pgbench | vacuum pgbench_branches
|
||||
psql | select application_name query from pg_stat_monitor
|
||||
pgbench | truncate pgbench_history
|
||||
pgbench | UPDATE pgbench_tellers SET tbalance = tbalance + $1 WHERE tid = $2
|
||||
postgres=# SELECT application_name, client_ip, substr(query,0,100) as query FROM pg_stat_monitor;
|
||||
application_name | client_ip | query
|
||||
------------------+-----------+-----------------------------------------------------------------------------------------------------
|
||||
pgbench | 127.0.0.1 | truncate pgbench_history
|
||||
pgbench | 127.0.0.1 | SELECT abalance FROM pgbench_accounts WHERE aid = $1
|
||||
pgbench | 127.0.0.1 | UPDATE pgbench_accounts SET abalance = abalance + $1 WHERE aid = $2
|
||||
pgbench | 127.0.0.1 | BEGIN;
|
||||
pgbench | 127.0.0.1 | INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES ($1, $2, $3, $4, CURRENT_TIMESTAMP
|
||||
pgbench | 127.0.0.1 | END;
|
||||
pgbench | 127.0.0.1 | vacuum pgbench_branches
|
||||
pgbench | 127.0.0.1 | UPDATE pgbench_tellers SET tbalance = tbalance + $1 WHERE tid = $2
|
||||
pgbench | 127.0.0.1 | vacuum pgbench_tellers
|
||||
pgbench | 127.0.0.1 | UPDATE pgbench_branches SET bbalance = bbalance + $1 WHERE bid = $2
|
||||
pgbench | 127.0.0.1 | select o.n, p.partstrat, pg_catalog.count(i.inhparent) from pg_catalog.pg_class as c join pg_catalo
|
||||
psql | 127.0.0.1 | SELECT application_name, client_ip, substr(query,$1,$2) as query FROM pg_stat_monitor
|
||||
pgbench | 127.0.0.1 | select count(*) from pgbench_branches
|
||||
(13 rows)
|
||||
|
||||
```
|
||||
|
||||
#### Error Messages / Error Codes and Error Level
|
||||
|
||||
**`elevel`**, **`sqlcode`**,**`message`**,: error level / sql code and log/warning/ error message
|
||||
### Query timing information
|
||||
|
||||
```sql
|
||||
SELECT substr(query,0,50) AS query, decode_error_level(elevel) AS elevel,sqlcode, calls, substr(message,0,50) message
|
||||
FROM pg_stat_monitor;
|
||||
query | elevel | sqlcode | calls | message
|
||||
---------------------------------------------------+--------+---------+-------+---------------------------------------------------
|
||||
select substr(query,$1,$2) as query, decode_error | | 0 | 1 |
|
||||
select bucket,substr(query,$1,$2),decode_error_le | | 0 | 3 |
|
||||
| LOG | 0 | 1 | database system is ready to accept connections
|
||||
select 1/0; | ERROR | 130 | 1 | division by zero
|
||||
| LOG | 0 | 1 | database system was shut down at 2020-11-11 11:37
|
||||
select $1/$2 | | 0 | 1 |
|
||||
(6 rows)
|
||||
```
|
||||
|
||||
#### Query Timing Information
|
||||
|
||||
**`total_time`**, **`min_time`**, **`max_time`**, **`mean_time`**: The total / minimum / maximum and mean time spent for the same query.
|
||||
|
||||
|
||||
```
|
||||
SELECT userid, total_time, min_time, max_time, mean_time, query FROM pg_stat_monitor;
|
||||
userid | total_time | min_time | max_time | mean_time | query
|
||||
SELECT userid, total_time, min_time, max_time, mean_time, query FROM pg_stat_monitor;
|
||||
userid | total_time | min_time | max_time | mean_time | query
|
||||
--------+--------------------+--------------------+--------------------+--------------------+------------------------------------------------------------------
|
||||
10 | 0.14 | 0.14 | 0.14 | 0.14 | select * from pg_stat_monitor_reset()
|
||||
10 | 0.19 | 0.19 | 0.19 | 0.19 | select userid, dbid, queryid, query from pg_stat_monitor
|
||||
10 | 0.30 | 0.13 | 0.16 | 0.15 | select bucket, bucket_start_time, query from pg_stat_monitor
|
||||
10 | 0.29 | 0.29 | 0.29 | 0.29 | select userid, dbid, queryid, query, calls from pg_stat_monitor
|
||||
10 | 11277.79 | 11277.79 | 11277.79 | 11277.79 | SELECT * FROM foo
|
||||
10 | 0.14 | 0.14 | 0.14 | 0.14 | select * from pg_stat_monitor_reset()
|
||||
10 | 0.19 | 0.19 | 0.19 | 0.19 | select userid, dbid, queryid, query from pg_stat_monitor
|
||||
10 | 0.30 | 0.13 | 0.16 | 0.15 | select bucket, bucket_start_time, query from pg_stat_monitor
|
||||
10 | 0.29 | 0.29 | 0.29 | 0.29 | select userid, dbid, queryid, query, calls from pg_stat_monitor
|
||||
10 | 11277.79 | 11277.79 | 11277.79 |
|
||||
```
|
||||
|
||||
#### Client IP address
|
||||
|
||||
**`client_ip`**: The IP address of the client that originated the query.
|
||||
|
||||
```sql
|
||||
SELECT userid::regrole, datname, substr(query,0, 50) AS query, calls, client_ip
|
||||
FROM pg_stat_monitor, pg_database
|
||||
WHERE dbid = oid;
|
||||
userid | datname | query | calls | client_ip
|
||||
---------+----------+---------------------------------------------------+-------+-----------
|
||||
vagrant | postgres | UPDATE pgbench_branches SET bbalance = bbalance + | 1599 | 10.0.2.15
|
||||
vagrant | postgres | select userid::regrole, datname, substr(query,$1, | 5 | 10.0.2.15
|
||||
vagrant | postgres | UPDATE pgbench_accounts SET abalance = abalance + | 1599 | 10.0.2.15
|
||||
vagrant | postgres | select userid::regrole, datname, substr(query,$1, | 1 | 127.0.0.1
|
||||
vagrant | postgres | vacuum pgbench_tellers | 1 | 10.0.2.15
|
||||
vagrant | postgres | SELECT abalance FROM pgbench_accounts WHERE aid = | 1599 | 10.0.2.15
|
||||
vagrant | postgres | END | 1599 | 10.0.2.15
|
||||
vagrant | postgres | select count(*) from pgbench_branches | 1 | 10.0.2.15
|
||||
vagrant | postgres | BEGIN | 1599 | 10.0.2.15
|
||||
vagrant | postgres | INSERT INTO pgbench_history (tid, bid, aid, delta | 1599 | 10.0.2.15
|
||||
vagrant | postgres | vacuum pgbench_branches | 1 | 10.0.2.15
|
||||
vagrant | postgres | truncate pgbench_history | 1 | 10.0.2.15
|
||||
vagrant | postgres | UPDATE pgbench_tellers SET tbalance = tbalance + | 1599 | 10.0.2.15
|
||||
```
|
||||
|
||||
#### Call Timings Histogram
|
||||
|
||||
**`resp_calls`**: Call histogram
|
||||
|
||||
```sql
|
||||
SELECT resp_calls, query FROM pg_stat_monitor;
|
||||
resp_calls | query
|
||||
--------------------------------------------------+----------------------------------------------
|
||||
{1," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 0"} | select client_ip, query from pg_stat_monitor
|
||||
{3," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 1"} | select * from pg_stat_monitor_reset()
|
||||
{3," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 1"} | SELECT * FROM foo
|
||||
|
||||
postgres=# SELECT * FROM histogram(0, 'F44CD1B4B33A47AF') AS a(range TEXT, freq INT, bar TEXT);
|
||||
range | freq | bar
|
||||
--------------------+------+--------------------------------
|
||||
(0 - 3)} | 2 | ■■■■■■■■■■■■■■■■■■■■■■■■■■■■■■
|
||||
(3 - 10)} | 0 |
|
||||
(10 - 31)} | 1 | ■■■■■■■■■■■■■■■
|
||||
(31 - 100)} | 0 |
|
||||
(100 - 316)} | 0 |
|
||||
(316 - 1000)} | 0 |
|
||||
(1000 - 3162)} | 0 |
|
||||
(3162 - 10000)} | 0 |
|
||||
(10000 - 31622)} | 0 |
|
||||
(31622 - 100000)} | 0 |
|
||||
(10 rows)
|
||||
```
|
||||
|
||||
There are 10 timebase buckets of the time **`pg_stat_monitor.pgsm_respose_time_step`** in the field ``resp_calls``. The field's value shows how many queries run in that period of time.
|
||||
|
||||
|
||||
#### Object Information.
|
||||
|
||||
**`relations`**: The list of tables involved in the query
|
||||
Views will be added with * like VIEW_NAME*
|
||||
|
||||
##### Example 1: List all the table names involved in the query.
|
||||
```sql
|
||||
postgres=# SELECT relations,query FROM pg_stat_monitor;
|
||||
relations | query
|
||||
-------------------------------+------------------------------------------------------------------------------------------------------
|
||||
| END
|
||||
{pgbench_accounts} | SELECT abalance FROM pgbench_accounts WHERE aid = $1
|
||||
| vacuum pgbench_branches
|
||||
{pgbench_branches} | select count(*) from pgbench_branches
|
||||
{pgbench_accounts} | UPDATE pgbench_accounts SET abalance = abalance + $1 WHERE aid = $2
|
||||
| truncate pgbench_history
|
||||
{pgbench_history} | INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES ($1, $2, $3, $4, CURRENT_TIMESTAMP)
|
||||
{pg_stat_monitor,pg_database} | SELECT relations query FROM pg_stat_monitor
|
||||
| vacuum pgbench_tellers
|
||||
| BEGIN
|
||||
{pgbench_tellers} | UPDATE pgbench_tellers SET tbalance = tbalance + $1 WHERE tid = $2
|
||||
{pgbench_branches} | UPDATE pgbench_branches SET bbalance = bbalance + $1 WHERE bid = $2
|
||||
(12 rows)
|
||||
```
|
||||
|
||||
##### Example 2: List all the views and the name of the table in the view. Here we have a view "test_view"
|
||||
```sql
|
||||
\d+ test_view
|
||||
View "public.test_view"
|
||||
Column | Type | Collation | Nullable | Default | Storage | Description
|
||||
--------+---------+-----------+----------+---------+---------+-------------
|
||||
foo_a | integer | | | | plain |
|
||||
bar_a | integer | | | | plain |
|
||||
View definition:
|
||||
SELECT f.a AS foo_a,
|
||||
b.a AS bar_a
|
||||
FROM foo f,
|
||||
bar b;
|
||||
```
|
||||
|
||||
Now when we query ``pg_stat_monitor``, it will show the view name and also all the table names in the view.
|
||||
```sql
|
||||
SELECT relations, query FROM pg_stat_monitor;
|
||||
relations | query
|
||||
---------------------+------------------------------------------------------------------------------------------------------
|
||||
{test_view*,foo,bar} | select * from test_view
|
||||
{foo,bar} | select * from foo,bar
|
||||
(2 rows)
|
||||
```
|
||||
|
||||
#### Query command Type (SELECT, INSERT, UPDATE OR DELETE)
|
||||
|
||||
**`cmd_type`**: List the command type of the query.
|
||||
|
||||
```sql
|
||||
postgres=# SELECT bucket, substr(query,0, 50) AS query, cmd_type FROM pg_stat_monitor WHERE elevel = 0;
|
||||
bucket | query | cmd_type
|
||||
--------+---------------------------------------------------+----------
|
||||
4 | END |
|
||||
4 | SELECT abalance FROM pgbench_accounts WHERE aid = | SELECT
|
||||
4 | vacuum pgbench_branches |
|
||||
4 | select count(*) from pgbench_branches | SELECT
|
||||
4 | UPDATE pgbench_accounts SET abalance = abalance + | UPDATE
|
||||
4 | truncate pgbench_history |
|
||||
4 | INSERT INTO pgbench_history (tid, bid, aid, delta | INSERT
|
||||
5 | SELECT relations query FROM pg_stat_monitor | SELECT
|
||||
9 | SELECT bucket, substr(query,$1, $2) AS query, cmd |
|
||||
4 | vacuum pgbench_tellers |
|
||||
4 | BEGIN |
|
||||
5 | SELECT relations,query FROM pg_stat_monitor | SELECT
|
||||
4 | UPDATE pgbench_tellers SET tbalance = tbalance + | UPDATE
|
||||
4 | UPDATE pgbench_branches SET bbalance = bbalance + | UPDATE
|
||||
(14 rows)
|
||||
```
|
||||
|
||||
#### Function Execution Tracking
|
||||
|
||||
**`top_queryid`**: Outer layer caller's query id.
|
||||
|
||||
```sql
|
||||
CREATE OR REPLACE function add2(int, int) RETURNS int as
|
||||
$$
|
||||
BEGIN
|
||||
return (select $1 + $2);
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
|
||||
SELECT add2(1,2);
|
||||
add2
|
||||
-----
|
||||
3
|
||||
(1 row)
|
||||
|
||||
postgres=# SELECT queryid, top_queryid, query, top_query FROM pg_stat_monitor;
|
||||
queryid | top_queryid | query. | top_query
|
||||
------------------+------------------+-------------------------------------------------------------------------+-------------------
|
||||
3408CA84B2353094 | | select add2($1,$2) |
|
||||
762B99349F6C7F31 | 3408CA84B2353094 | SELECT (select $1 + $2) | select add2($1,$2)
|
||||
(2 rows)
|
||||
```
|
||||
|
||||
#### Monitor Query Execution Plan.
|
||||
### Query execution plan
|
||||
|
||||
```sql
|
||||
postgres=# SELECT substr(query,0,50), query_plan from pg_stat_monitor limit 10;
|
||||
|
@ -446,9 +430,13 @@ postgres=# SELECT substr(query,0,50), query_plan from pg_stat_monitor limit 10;
|
|||
vacuum pgbench_tellers |
|
||||
UPDATE pgbench_accounts SET abalance = abalance + |
|
||||
(10 rows)
|
||||
|
||||
```
|
||||
#### SQL Commenter / tags.
|
||||
|
||||
The `plan` column does not contain costing, width and other values. This is an expected behavior as each row is an accumulation of statistics based on `plan` and amongst other key columns. Plan is only available when the `pgsm_enable_query_plan` configuration parameter is enabled.
|
||||
|
||||
### Query metadata
|
||||
|
||||
The `comments` column contains any text wrapped in `“/*”` and `“*/”` comment tags. The `pg_stat_monitor` extension picks up these comments and makes them available in the comments column. Please note that only the latest comment value is preserved per row. The comments may be put in any format that can be parsed by a tool.
|
||||
|
||||
```sql
|
||||
CREATE EXTENSION hstore;
|
||||
|
@ -460,68 +448,220 @@ EXCEPTION WHEN OTHERS THEN
|
|||
END; $$ LANGUAGE plpgsql STRICT;
|
||||
|
||||
postgres=# SELECT 1 AS num /* { "application", java_app, "real_ip", 192.168.1.1} */;
|
||||
num
|
||||
num
|
||||
-----
|
||||
1
|
||||
(1 row)
|
||||
|
||||
postgres=# SELECT 1 AS num1,2 AS num2 /* { "application", java_app, "real_ip", 192.168.1.2} */;
|
||||
num1 | num2
|
||||
num1 | num2
|
||||
------+------
|
||||
1 | 2
|
||||
(1 row)
|
||||
|
||||
postgres=# SELECT 1 AS num1,2 AS num2, 3 AS num3 /* { "application", java_app, "real_ip", 192.168.1.3} */;
|
||||
num1 | num2 | num3
|
||||
num1 | num2 | num3
|
||||
------+------+------
|
||||
1 | 2 | 3
|
||||
(1 row)
|
||||
|
||||
postgres=# SELECT 1 AS num1,2 AS num2, 3 AS num3, 4 AS num4 /* { "application", psql_app, "real_ip", 192.168.1.3} */;
|
||||
num1 | num2 | num3 | num4
|
||||
num1 | num2 | num3 | num4
|
||||
------+------+------+------
|
||||
1 | 2 | 3 | 4
|
||||
(1 row)
|
||||
|
||||
postgres=# select query, text_to_hstore(comments) as comments_tags from pg_stat_monitor;
|
||||
query | comments_tags
|
||||
query | comments_tags
|
||||
---------------------------------------------------------------------------------------------------------------+-----------------------------------------------------
|
||||
SELECT $1 AS num /* { "application", psql_app, "real_ip", 192.168.1.3) */ | "real_ip"=>"192.168.1.1", "application"=>"java_app"
|
||||
SELECT pg_stat_monitor_reset(); |
|
||||
select query, comments, text_to_hstore(comments) from pg_stat_monitor; |
|
||||
SELECT pg_stat_monitor_reset(); |
|
||||
select query, comments, text_to_hstore(comments) from pg_stat_monitor; |
|
||||
SELECT $1 AS num1,$2 AS num2, $3 AS num3 /* { "application", java_app, "real_ip", 192.168.1.3} */ | "real_ip"=>"192.168.1.3", "application"=>"java_app"
|
||||
select query, text_to_hstore(comments) as comments_tags from pg_stat_monitor; |
|
||||
select query, text_to_hstore(comments) as comments_tags from pg_stat_monitor; |
|
||||
SELECT $1 AS num1,$2 AS num2 /* { "application", java_app, "real_ip", 192.168.1.2} */ | "real_ip"=>"192.168.1.2", "application"=>"java_app"
|
||||
SELECT $1 AS num1,$2 AS num2, $3 AS num3, $4 AS num4 /* { "application", psql_app, "real_ip", 192.168.1.3} */ | "real_ip"=>"192.168.1.3", "application"=>"psql_app"
|
||||
(7 rows)
|
||||
|
||||
postgres=# select query, text_to_hstore(comments)->'application' as application_name from pg_stat_monitor;
|
||||
query | application_name
|
||||
query | application_name
|
||||
---------------------------------------------------------------------------------------------------------------+----------
|
||||
SELECT $1 AS num /* { "application", psql_app, "real_ip", 192.168.1.3) */ | java_app
|
||||
SELECT pg_stat_monitor_reset(); |
|
||||
select query, text_to_hstore(comments)->"real_ip" as comments_tags from pg_stat_monitor; |
|
||||
select query, text_to_hstore(comments)->$1 from pg_stat_monitor |
|
||||
select query, text_to_hstore(comments) as comments_tags from pg_stat_monitor; |
|
||||
select query, text_to_hstore(comments)->"application" as comments_tags from pg_stat_monitor; |
|
||||
SELECT pg_stat_monitor_reset(); |
|
||||
select query, text_to_hstore(comments)->"real_ip" as comments_tags from pg_stat_monitor; |
|
||||
select query, text_to_hstore(comments)->$1 from pg_stat_monitor |
|
||||
select query, text_to_hstore(comments) as comments_tags from pg_stat_monitor; |
|
||||
select query, text_to_hstore(comments)->"application" as comments_tags from pg_stat_monitor; |
|
||||
SELECT $1 AS num1,$2 AS num2 /* { "application", java_app, "real_ip", 192.168.1.2} */ | java_app
|
||||
SELECT $1 AS num1,$2 AS num2, $3 AS num3 /* { "application", java_app, "real_ip", 192.168.1.3} */ | java_app
|
||||
select query, comments, text_to_hstore(comments) from pg_stat_monitor; |
|
||||
select query, comments, text_to_hstore(comments) from pg_stat_monitor; |
|
||||
SELECT $1 AS num1,$2 AS num2, $3 AS num3, $4 AS num4 /* { "application", psql_app, "real_ip", 192.168.1.3} */ | psql_app
|
||||
(10 rows)
|
||||
|
||||
postgres=# select query, text_to_hstore(comments)->'real_ip' as real_ip from pg_stat_monitor;
|
||||
query | real_ip
|
||||
query | real_ip
|
||||
---------------------------------------------------------------------------------------------------------------+-------------
|
||||
SELECT $1 AS num /* { "application", psql_app, "real_ip", 192.168.1.3) */ | 192.168.1.1
|
||||
SELECT pg_stat_monitor_reset(); |
|
||||
select query, text_to_hstore(comments)->"real_ip" as comments_tags from pg_stat_monitor; |
|
||||
select query, text_to_hstore(comments)->$1 from pg_stat_monitor |
|
||||
select query, text_to_hstore(comments) as comments_tags from pg_stat_monitor; |
|
||||
select query, text_to_hstore(comments)->"application" as comments_tags from pg_stat_monitor; |
|
||||
SELECT pg_stat_monitor_reset(); |
|
||||
select query, text_to_hstore(comments)->"real_ip" as comments_tags from pg_stat_monitor; |
|
||||
select query, text_to_hstore(comments)->$1 from pg_stat_monitor |
|
||||
select query, text_to_hstore(comments) as comments_tags from pg_stat_monitor; |
|
||||
select query, text_to_hstore(comments)->"application" as comments_tags from pg_stat_monitor; |
|
||||
SELECT $1 AS num1,$2 AS num2 /* { "application", java_app, "real_ip", 192.168.1.2} */ | 192.168.1.2
|
||||
SELECT $1 AS num1,$2 AS num2, $3 AS num3 /* { "application", java_app, "real_ip", 192.168.1.3} */ | 192.168.1.3
|
||||
select query, comments, text_to_hstore(comments) from pg_stat_monitor; |
|
||||
select query, comments, text_to_hstore(comments) from pg_stat_monitor; |
|
||||
SELECT $1 AS num1,$2 AS num2, $3 AS num3, $4 AS num4 /* { "application", psql_app, "real_ip", 192.168.1.3} */ | 192.168.1.3
|
||||
(10 rows)
|
||||
```
|
||||
|
||||
### Query type filtering
|
||||
|
||||
``pg_stat_monitor`` monitors queries per type (SELECT, INSERT, UPDATE OR DELETE) and classifies them accordingly in the ``cmd_type`` column thus reducing your efforts.
|
||||
|
||||
```sql
|
||||
postgres=# SELECT bucket, substr(query,0, 50) AS query, cmd_type FROM pg_stat_monitor WHERE elevel = 0;
|
||||
bucket | query | cmd_type
|
||||
--------+---------------------------------------------------+----------
|
||||
4 | END |
|
||||
4 | SELECT abalance FROM pgbench_accounts WHERE aid = | SELECT
|
||||
4 | vacuum pgbench_branches |
|
||||
4 | select count(*) from pgbench_branches | SELECT
|
||||
4 | UPDATE pgbench_accounts SET abalance = abalance + | UPDATE
|
||||
4 | truncate pgbench_history |
|
||||
4 | INSERT INTO pgbench_history (tid, bid, aid, delta | INSERT
|
||||
5 | SELECT relations query FROM pg_stat_monitor | SELECT
|
||||
9 | SELECT bucket, substr(query,$1, $2) AS query, cmd |
|
||||
4 | vacuum pgbench_tellers |
|
||||
4 | BEGIN |
|
||||
5 | SELECT relations,query FROM pg_stat_monitor | SELECT
|
||||
4 | UPDATE pgbench_tellers SET tbalance = tbalance + | UPDATE
|
||||
4 | UPDATE pgbench_branches SET bbalance = bbalance + | UPDATE
|
||||
(14 rows)
|
||||
```
|
||||
|
||||
### Queries terminated with errors
|
||||
|
||||
```sql
|
||||
SELECT substr(query,0,50) AS query, decode_error_level(elevel) AS elevel,sqlcode, calls, substr(message,0,50) message
|
||||
FROM pg_stat_monitor;
|
||||
query | elevel | sqlcode | calls | message
|
||||
---------------------------------------------------+--------+---------+-------+---------------------------------------------------
|
||||
select substr(query,$1,$2) as query, decode_error | | 0 | 1 |
|
||||
select bucket,substr(query,$1,$2),decode_error_le | | 0 | 3 |
|
||||
| LOG | 0 | 1 | database system is ready to accept connections
|
||||
select 1/0; | ERROR | 130 | 1 | division by zero
|
||||
| LOG | 0 | 1 | database system was shut down at 2020-11-11 11:37
|
||||
select $1/$2 | | 0 | 1 |
|
||||
(6 rows)
|
||||
11277.79 | SELECT * FROM foo
|
||||
```
|
||||
|
||||
### Histogram
|
||||
|
||||
Histogram (the `resp_calls` parameter) provides a visual representation of query performance. With the help of the histogram function, you can view a timing/calling data histogram in response to a SQL query.
|
||||
|
||||
|
||||
```sql
|
||||
SELECT resp_calls, query FROM pg_stat_monitor;
|
||||
resp_calls | query
|
||||
--------------------------------------------------+----------------------------------------------
|
||||
{1," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 0"} | select client_ip, query from pg_stat_monitor
|
||||
{3," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 1"} | select * from pg_stat_monitor_reset()
|
||||
{3," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 0"," 1"} | SELECT * FROM foo
|
||||
|
||||
postgres=# SELECT * FROM histogram(0, 'F44CD1B4B33A47AF') AS a(range TEXT, freq INT, bar TEXT);
|
||||
range | freq | bar
|
||||
--------------------+------+--------------------------------
|
||||
(0 - 3)} | 2 | ■■■■■■■■■■■■■■■■■■■■■■■■■■■■■■
|
||||
(3 - 10)} | 0 |
|
||||
(10 - 31)} | 1 | ■■■■■■■■■■■■■■■
|
||||
(31 - 100)} | 0 |
|
||||
(100 - 316)} | 0 |
|
||||
(316 - 1000)} | 0 |
|
||||
(1000 - 3162)} | 0 |
|
||||
(3162 - 10000)} | 0 |
|
||||
(10000 - 31622)} | 0 |
|
||||
(31622 - 100000)} | 0 |
|
||||
(10 rows)
|
||||
```
|
||||
|
||||
There are 10 time based buckets of the time **`pg_stat_monitor.pgsm_respose_time_step`** in the field ``resp_calls``. The value in the field shows how many queries run in that period of time.
|
||||
|
||||
### Top query tracking
|
||||
|
||||
In the following example we create a function `add2` that adds one parameter value to another one and call this function to calculate 1+2.
|
||||
|
||||
|
||||
```sql
|
||||
CREATE OR REPLACE function add2(int, int) RETURNS int as
|
||||
$$
|
||||
BEGIN
|
||||
return (select $1 + $2);
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
|
||||
SELECT add2(1,2);
|
||||
add2
|
||||
-----
|
||||
3
|
||||
(1 row)
|
||||
|
||||
The ``pg_stat_monitor`` view shows all executed queries and shows the very first query in a row - calling the `add2` function.
|
||||
|
||||
postgres=# SELECT queryid, top_queryid, query, top_query FROM pg_stat_monitor;
|
||||
queryid | top_queryid | query. | top_query
|
||||
------------------+------------------+-------------------------------------------------------------------------+-------------------
|
||||
3408CA84B2353094 | | select add2($1,$2) |
|
||||
762B99349F6C7F31 | 3408CA84B2353094 | SELECT (select $1 + $2) | select add2($1,$2)
|
||||
(2 rows)
|
||||
```
|
||||
|
||||
### Relations
|
||||
|
||||
**Example 1: List all the table names involved in the query.**
|
||||
|
||||
```sql
|
||||
postgres=# SELECT relations,query FROM pg_stat_monitor;
|
||||
relations | query
|
||||
-------------------------------+------------------------------------------------------------------------------------------------------
|
||||
| END
|
||||
{public.pgbench_accounts} | SELECT abalance FROM pgbench_accounts WHERE aid = $1
|
||||
| vacuum pgbench_branches
|
||||
{public.pgbench_branches} | select count(*) from pgbench_branches
|
||||
{public.pgbench_accounts} | UPDATE pgbench_accounts SET abalance = abalance + $1 WHERE aid = $2
|
||||
| truncate pgbench_history
|
||||
{public.pgbench_history} | INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES ($1, $2, $3, $4, CURRENT_TIMESTAMP)
|
||||
{public.pg_stat_monitor,pg_catalog.pg_database} | SELECT relations query FROM pg_stat_monitor
|
||||
| vacuum pgbench_tellers
|
||||
| BEGIN
|
||||
{public.pgbench_tellers} | UPDATE pgbench_tellers SET tbalance = tbalance + $1 WHERE tid = $2
|
||||
{public.pgbench_branches} | UPDATE pgbench_branches SET bbalance = bbalance + $1 WHERE bid = $2
|
||||
(12 rows)
|
||||
```
|
||||
|
||||
**Example 2: List all the views and the name of the table in the view. Here we have a view "test_view"**
|
||||
|
||||
```sql
|
||||
\d+ test_view
|
||||
View "public.test_view"
|
||||
Column | Type | Collation | Nullable | Default | Storage | Description
|
||||
--------+---------+-----------+----------+---------+---------+-------------
|
||||
foo_a | integer | | | | plain |
|
||||
bar_a | integer | | | | plain |
|
||||
View definition:
|
||||
SELECT f.a AS foo_a,
|
||||
b.a AS bar_a
|
||||
FROM foo f,
|
||||
bar b;
|
||||
```
|
||||
|
||||
Now when we query the ``pg_stat_monitor``, it will show the view name and also all the table names in the view. Note that the view name is followed by an asterisk (*).
|
||||
|
||||
```sql
|
||||
SELECT relations, query FROM pg_stat_monitor;
|
||||
relations | query
|
||||
---------------------+----------------------------------------------------
|
||||
{test_view*,foo,bar} | select * from test_view
|
||||
{foo,bar} | select * from foo,bar
|
||||
(2 rows)
|
||||
```
|
||||
|
|
Loading…
Reference in New Issue