Skip to content

Commit

Permalink
Add pg_stat_statements metrics & dashboard (#200)
Browse files Browse the repository at this point in the history
  • Loading branch information
keithf4 authored and Yogesh Sharma committed Sep 22, 2020
1 parent f578f83 commit c5a8c21
Show file tree
Hide file tree
Showing 23 changed files with 1,140 additions and 511 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -36,7 +36,7 @@ start() {

echo -n $"Starting postgres_exporter: "
set -o pipefail
cat $QUERY_FILE_LIST | sed "s/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g" > $(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')
cat $QUERY_FILE_LIST | sed -e "s/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g" -e "s/#PG_STAT_STATEMENTS_LIMIT#/${PG_STAT_STATEMENTS_LIMIT}/g" > $(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')
echo $DATA_SOURCE_NAME
daemonize -u ${DAEMON_USER} -p ${PID_FILE} -l ${LOCK_FILE} -a -e ${LOG_FILE} -o ${LOG_FILE} ${DAEMON} $OPT
RETVAL=$?
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -36,7 +36,7 @@ start() {

echo -n $"Starting postgres_exporter: "
set -o pipefail
cat $QUERY_FILE_LIST | sed "s/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g" > $(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')
cat $QUERY_FILE_LIST | sed -e "s/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g" -e "s/#PG_STAT_STATEMENTS_LIMIT#/${PG_STAT_STATEMENTS_LIMIT}/g" > $(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')
echo $DATA_SOURCE_NAME
daemonize -u ${DAEMON_USER} -p ${PID_FILE} -l ${LOCK_FILE} -a -e ${LOG_FILE} -o ${LOG_FILE} ${DAEMON} $OPT
RETVAL=$?
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -36,7 +36,7 @@ start() {

echo -n $"Starting postgres_exporter: "
set -o pipefail
cat $QUERY_FILE_LIST | sed "s/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g" > $(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')
cat $QUERY_FILE_LIST | sed -e "s/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g" -e "s/#PG_STAT_STATEMENTS_LIMIT#/${PG_STAT_STATEMENTS_LIMIT}/g" > $(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')
echo $DATA_SOURCE_NAME
daemonize -u ${DAEMON_USER} -p ${PID_FILE} -l ${LOCK_FILE} -a -e ${LOG_FILE} -o ${LOG_FILE} ${DAEMON} $OPT
RETVAL=$?
Expand Down
83 changes: 0 additions & 83 deletions exporter/postgres/crunchy-postgres-exporter-pg94-el6.service

This file was deleted.

Original file line number Diff line number Diff line change
Expand Up @@ -36,7 +36,7 @@ start() {

echo -n $"Starting postgres_exporter: "
set -o pipefail
cat $QUERY_FILE_LIST | sed "s/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g" > $(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')
cat $QUERY_FILE_LIST | sed -e "s/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g" -e "s/#PG_STAT_STATEMENTS_LIMIT#/${PG_STAT_STATEMENTS_LIMIT}/g" > $(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')
echo $DATA_SOURCE_NAME
daemonize -u ${DAEMON_USER} -p ${PID_FILE} -l ${LOCK_FILE} -a -e ${LOG_FILE} -o ${LOG_FILE} ${DAEMON} $OPT
RETVAL=$?
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -36,7 +36,7 @@ start() {

echo -n $"Starting postgres_exporter: "
set -o pipefail
cat $QUERY_FILE_LIST | sed "s/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g" > $(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')
cat $QUERY_FILE_LIST | sed -e "s/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g" -e "s/#PG_STAT_STATEMENTS_LIMIT#/${PG_STAT_STATEMENTS_LIMIT}/g" > $(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')
echo $DATA_SOURCE_NAME
daemonize -u ${DAEMON_USER} -p ${PID_FILE} -l ${LOCK_FILE} -a -e ${LOG_FILE} -o ${LOG_FILE} ${DAEMON} $OPT
RETVAL=$?
Expand Down
3 changes: 1 addition & 2 deletions exporter/postgres/[email protected]
Original file line number Diff line number Diff line change
Expand Up @@ -10,12 +10,11 @@ After=network.target
PermissionsStartOnly=true
User=ccp_monitoring
EnvironmentFile=/etc/sysconfig/%i
ExecStartPre=/bin/bash -c "set -o pipefail; cat $QUERY_FILE_LIST | sed 's/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g'> $$(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')"
ExecStartPre=/bin/bash -c "set -o pipefail; cat $QUERY_FILE_LIST | sed -e 's/#PGBACKREST_INFO_THROTTLE_MINUTES#/${PGBACKREST_INFO_THROTTLE_MINUTES}/g' -e 's/#PG_STAT_STATEMENTS_LIMIT#/${PG_STAT_STATEMENTS_LIMIT}/g' > $$(echo $OPT | sed 's/.*--extend.query-path=\(.*\.yml\).*/\1/')"
ExecStart=/usr/bin/postgres_exporter $OPT
ExecReload=/usr/bin/kill -HUP $MAINPID
Restart=always

[Install]
WantedBy=multi-user.target
DefaultInstance=postgres_exporter

113 changes: 0 additions & 113 deletions exporter/postgres/queries_pg94.yml

This file was deleted.

134 changes: 134 additions & 0 deletions exporter/postgres/queries_pg_stat_statements.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,134 @@
###
#
# Begin File: queries_pg_stat_statements.yml
#
###

ccp_pg_stat_statements_total:
query: "SELECT pg_get_userbyid(s.userid) as role,
d.datname AS dbname,
sum(s.calls) AS calls_count,
sum(s.total_time) AS time_ms,
avg(s.mean_time) AS mean_time_ms,
sum(s.rows) AS row_count
FROM public.pg_stat_statements s
JOIN pg_catalog.pg_database d
ON d.oid = s.dbid
GROUP BY 1,2"
metrics:
- role:
usage: "LABEL"
description: "Role that executed the statement"
- dbname:
usage: "LABEL"
description: "Database in which the statement was executed"
- calls_count:
usage: "GAUGE"
description: "Total number of queries run per user/database"
- time_ms:
usage: "GAUGE"
description: "Total runtime of all queries per user/database"
- mean_time_ms:
usage: "GAUGE"
description: "Mean runtime of all queries per user/database"
- row_count:
usage: "GAUGE"
description: "Total rows returned from all queries per user/database"


ccp_pg_stat_statements_top_mean:
query: "SELECT pg_get_userbyid(s.userid) as role,
d.datname AS dbname,
s.queryid,
btrim(replace(left(s.query, 40), '\n', '')) AS query,
max(s.mean_time) time_ms
FROM public.pg_stat_statements s
JOIN pg_catalog.pg_database d
ON d.oid = s.dbid
GROUP BY 1,2,3,4
ORDER BY 5 DESC
LIMIT #PG_STAT_STATEMENTS_LIMIT#"
metrics:
- role:
usage: "LABEL"
description: "Role that executed the statement"
- dbname:
usage: "LABEL"
description: "Database in which the statement was executed"
- queryid:
usage: "LABEL"
description: "Internal hash code, computed from the statement's parse tree"
- query:
usage: "LABEL"
description: "First 40 characters of query text"
- time_ms:
usage: "GAUGE"
description: "Average query runtime in milliseconds"


# Note that individual query stats can only be reset in PG12
ccp_pg_stat_statements_top_total:
query: "SELECT pg_get_userbyid(s.userid) as role,
d.datname AS dbname,
s.queryid,
btrim(replace(left(s.query, 40), '\n', '')) AS query,
s.total_time time_ms
FROM public.pg_stat_statements s
JOIN pg_catalog.pg_database d
ON d.oid = s.dbid
ORDER BY 5 DESC
LIMIT #PG_STAT_STATEMENTS_LIMIT#"
metrics:
- role:
usage: "LABEL"
description: "Role that executed the statement"
- dbname:
usage: "LABEL"
description: "Database in which the statement was executed"
- queryid:
usage: "LABEL"
description: "Internal hash code, computed from the statement's parse tree"
- query:
usage: "LABEL"
description: "First 40 characters of query text"
- time_ms:
usage: "GAUGE"
description: "Total time spent in the statement in milliseconds"


# Note that individual query stats can only be reset in PG12
ccp_pg_stat_statements_top_max:
query: "SELECT pg_get_userbyid(s.userid) as role,
d.datname AS dbname,
s.queryid,
btrim(replace(left(s.query, 40), '\n', '')) AS query,
s.max_time AS time_ms
FROM public.pg_stat_statements s
JOIN pg_catalog.pg_database d
ON d.oid = s.dbid
ORDER BY 5 DESC
LIMIT #PG_STAT_STATEMENTS_LIMIT#"
metrics:
- role:
usage: "LABEL"
description: "Role that executed the statement"
- dbname:
usage: "LABEL"
description: "Database in which the statement was executed"
- queryid:
usage: "LABEL"
description: "Internal hash code, computed from the statement's parse tree"
- query:
usage: "LABEL"
description: "First 40 characters of query text"
- time_ms:
usage: "GAUGE"
description: "Maximum time spent in the statement in milliseconds"


###
#
# End File: queries_pg_stat_statements.yml
#
###

Loading

0 comments on commit c5a8c21

Please sign in to comment.