Skip to content

Commit

Permalink
Add postgresql charts
Browse files Browse the repository at this point in the history
* Add temp files chart
* Add WAL written chart
* Rename previous bgwriter char to checkpointer
* Add several bgwriter charts
* Add autovacuum chart
* Add replication chart
  • Loading branch information
anayrat committed Feb 14, 2018
1 parent c3fb560 commit 284a734
Show file tree
Hide file tree
Showing 2 changed files with 268 additions and 32 deletions.
247 changes: 215 additions & 32 deletions python.d/postgres.chart.py
Original file line number Diff line number Diff line change
Expand Up @@ -32,18 +32,29 @@
'tup_updated',
'tup_deleted',
'conflicts',
'temp_files',
'temp_bytes',
'size'],
BACKENDS=['backends_active',
'backends_idle'],
INDEX_STATS=['index_count',
'index_size'],
TABLE_STATS=['table_size',
'table_count'],
WAL=['written_wal',
'recycled_wal',
'total_wal'],
ARCHIVE=['ready_count',
'done_count',
'file_count'],
BGWRITER=['writer_scheduled',
'writer_requested'],
CHECKPOINTER=['checkpoint_scheduled',
'checkpoint_requested'],
BGWRITER=['buffers_checkpoint',
'buffers_clean',
'maxwritten_clean',
'buffers_backend',
'buffers_alloc',
'buffers_backend_fsync'],
LOCKS=['ExclusiveLock',
'RowShareLock',
'SIReadLock',
Expand All @@ -52,10 +63,34 @@
'AccessShareLock',
'ShareRowExclusiveLock',
'ShareLock',
'RowExclusiveLock']
'RowExclusiveLock'],
AUTOVACUUM=['analyze',
'vacuum_analyze',
'vacuum',
'vacuum_freeze',
'brin_summarize'],
STANDBY_DELTA=['sent_delta',
'write_delta',
'flush_delta',
'replay_delta']
)

QUERIES = dict(
WAL="""
SELECT
count(*) as total_wal,
count(*) FILTER (WHERE type = 'recycled') AS recycled_wal,
count(*) FILTER (WHERE type = 'written') AS written_wal
FROM
(SELECT wal.name,
pg_walfile_name(pg_current_wal_lsn()),
CASE WHEN wal.name > pg_walfile_name(pg_current_wal_lsn()) THEN 'recycled'
ELSE 'written'
END AS type
FROM pg_ls_waldir() AS wal
WHERE name ~ '^[0-9A-F]{24}$'
ORDER BY wal.modification, wal.name DESC) sub;
""",
ARCHIVE="""
SELECT
CAST(COUNT(*) AS INT) AS file_count,
Expand Down Expand Up @@ -86,28 +121,41 @@
DATABASE="""
SELECT
datname AS database_name,
sum(numbackends) AS connections,
sum(xact_commit) AS xact_commit,
sum(xact_rollback) AS xact_rollback,
sum(blks_read) AS blks_read,
sum(blks_hit) AS blks_hit,
sum(tup_returned) AS tup_returned,
sum(tup_fetched) AS tup_fetched,
sum(tup_inserted) AS tup_inserted,
sum(tup_updated) AS tup_updated,
sum(tup_deleted) AS tup_deleted,
sum(conflicts) AS conflicts,
pg_database_size(datname) AS size
numbackends AS connections,
xact_commit AS xact_commit,
xact_rollback AS xact_rollback,
blks_read AS blks_read,
blks_hit AS blks_hit,
tup_returned AS tup_returned,
tup_fetched AS tup_fetched,
tup_inserted AS tup_inserted,
tup_updated AS tup_updated,
tup_deleted AS tup_deleted,
conflicts AS conflicts,
pg_database_size(datname) AS size,
temp_files AS temp_files,
temp_bytes AS temp_bytes
FROM pg_stat_database
WHERE datname IN %(databases)s
GROUP BY datname;
;
""",
CHECKPOINTER="""
SELECT
checkpoints_timed AS checkpoint_scheduled,
checkpoints_req AS checkpoint_requested
FROM pg_stat_bgwriter;
""",
BGWRITER="""
SELECT
checkpoints_timed AS writer_scheduled,
checkpoints_req AS writer_requested
FROM pg_stat_bgwriter;""",
LOCKS="""
buffers_checkpoint * current_setting('block_size')::numeric buffers_checkpoint,
buffers_clean * current_setting('block_size')::numeric buffers_clean,
maxwritten_clean,
buffers_backend * current_setting('block_size')::numeric buffers_backend,
buffers_alloc * current_setting('block_size')::numeric buffers_alloc,
buffers_backend_fsync
FROM pg_stat_bgwriter;
""",
LOCKS="""
SELECT
pg_database.datname as database_name,
mode,
Expand All @@ -122,13 +170,40 @@
FROM pg_stat_database
WHERE has_database_privilege((SELECT current_user), datname, 'connect')
AND NOT datname ~* '^template\d+';
""",
FIND_STANDBY="""
SELECT application_name
FROM pg_stat_replication
WHERE application_name IS NOT NULL
GROUP BY application_name;
""",
STANDBY_DELTA="""
SELECT application_name,
pg_wal_lsn_diff(pg_current_wal_lsn() , sent_lsn) AS sent_delta,
pg_wal_lsn_diff(pg_current_wal_lsn() , write_lsn) AS write_delta,
pg_wal_lsn_diff(pg_current_wal_lsn() , flush_lsn) AS flush_delta,
pg_wal_lsn_diff(pg_current_wal_lsn() , replay_lsn) AS replay_delta
FROM pg_stat_replication
WHERE application_name IS NOT NULL
""",
IF_SUPERUSER="""
SELECT current_setting('is_superuser') = 'on' AS is_superuser;
""",
""",
DETECT_SERVER_VERSION="""
SHOW server_version_num;
"""
""",
AUTOVACUUM="""
SELECT
count(*) FILTER (WHERE query LIKE 'autovacuum: ANALYZE%%') AS analyze,
count(*) FILTER (WHERE query LIKE 'autovacuum: VACUUM ANALYZE%%') AS vacuum_analyze,
count(*) FILTER (WHERE query LIKE 'autovacuum: VACUUM%%'
AND query NOT LIKE 'autovacuum: VACUUM ANALYZE%%'
AND query NOT LIKE '%%to prevent wraparound%%') AS vacuum,
count(*) FILTER (WHERE query LIKE '%%to prevent wraparound%%') AS vacuum_freeze,
count(*) FILTER (WHERE query LIKE 'autovacuum: BRIN summarize%%') AS brin_summarize
FROM pg_stat_activity
WHERE query NOT LIKE '%%pg_stat_activity%%';
"""
)


Expand All @@ -138,8 +213,10 @@
QUERIES['LOCKS']: METRICS['LOCKS']
}

ORDER = ['db_stat_transactions', 'db_stat_tuple_read', 'db_stat_tuple_returned', 'db_stat_tuple_write', 'database_size',
'backend_process', 'index_count', 'index_size', 'table_count', 'table_size', 'wal', 'background_writer']
ORDER = ['db_stat_transactions', 'db_stat_blks', 'db_stat_tuple_returned', 'db_stat_tuple_write', 'db_stat_temp_bytes', 'db_stat_temp_files',
'database_size', 'backend_process', 'index_count', 'index_size', 'table_count', 'table_size', 'wal', 'archive_wal',
'checkpointer','stat_bgwriter_alloc','stat_bgwriter_checkpoint','stat_bgwriter_backend','stat_bgwriter_backend_fsync',
'stat_bgwriter_bgwriter','stat_bgwriter_maxwritten','standby_delta','autovacuum']

CHARTS = {
'db_stat_transactions': {
Expand All @@ -155,8 +232,8 @@
'lines': [
['connections', 'connections', 'absolute']
]},
'db_stat_tuple_read': {
'options': [None, 'Tuple reads from db', 'reads/s', 'db statistics', 'postgres.db_stat_tuple_read', 'line'],
'db_stat_blks': {
'options': [None, 'Disk blocks reads from db', 'reads/s', 'db statistics', 'postgres.db_stat_blks', 'line'],
'lines': [
['blks_read', 'disk', 'incremental'],
['blks_hit', 'cache', 'incremental']
Expand All @@ -176,6 +253,16 @@
['tup_deleted', 'deleted', 'incremental'],
['conflicts', 'conflicts', 'incremental']
]},
'db_stat_temp_bytes': {
'options': [None, 'Temp files written to disk', 'KB/s', 'db statistics', 'postgres.db_stat_temp_bytes', 'line'],
'lines': [
['temp_bytes', 'size', 'incremental', 1, 1024]
]},
'db_stat_temp_files': {
'options': [None, 'Temp files written to disk', 'files', 'db statistics', 'postgres.db_stat_temp_files', 'line'],
'lines': [
['temp_files', 'files', 'incremental']
]},
'database_size': {
'options': [None, 'Database size', 'MB', 'database size', 'postgres.db_size', 'stacked'],
'lines': [
Expand Down Expand Up @@ -208,17 +295,71 @@
['table_size', 'size', 'absolute', 1, 1024 * 1024]
]},
'wal': {
'options': [None, 'Write-Ahead Logging Statistics', 'files/s', 'write ahead log', 'postgres.wal', 'line'],
'options': [None, 'Write-Ahead Logs', 'files', 'wal', 'postgres.wal', 'line'],
'lines': [
['written_wal', 'written', 'absolute'],
['recycled_wal', 'recycled', 'absolute'],
['total_wal', 'total', 'absolute']
]},
'archive_wal': {
'options': [None, 'Archive Write-Ahead Logs', 'files/s', 'archive wal', 'postgres.archive_wal', 'line'],
'lines': [
['file_count', 'total', 'incremental'],
['ready_count', 'ready', 'incremental'],
['done_count', 'done', 'incremental']
]},
'background_writer': {
'options': [None, 'Checkpoints', 'writes/s', 'background writer', 'postgres.background_writer', 'line'],
'checkpointer': {
'options': [None, 'Checkpoints', 'writes', 'checkpointer', 'postgres.checkpointer', 'line'],
'lines': [
['checkpoint_scheduled', 'scheduled', 'incremental'],
['checkpoint_requested', 'requested', 'incremental']
]},
'stat_bgwriter_alloc': {
'options': [None, 'Buffers allocated', 'kilobytes/s', 'bgwriter', 'postgres.stat_bgwriter_alloc', 'line'],
'lines': [
['buffers_alloc', 'alloc', 'incremental', 8, 1024]
]},
'stat_bgwriter_checkpoint': {
'options': [None, 'Buffers written during checkpoints', 'kilobytes/s', 'bgwriter', 'postgres.stat_bgwriter_checkpoint', 'line'],
'lines': [
['buffers_checkpoint', 'checkpoint', 'incremental', 8, 1024]
]},
'stat_bgwriter_backend': {
'options': [None, 'Buffers written directly by a backend', 'kilobytes/s', 'bgwriter', 'postgres.stat_bgwriter_backend', 'line'],
'lines': [
['buffers_backend', 'backend', 'incremental', 8, 1024]
]},
'stat_bgwriter_backend_fsync': {
'options': [None, 'Fsync by backend', 'times', 'bgwriter', 'postgres.stat_bgwriter_backend_fsync', 'line'],
'lines': [
['buffers_backend_fsync', 'backend fsync', 'incremental']
]},
'stat_bgwriter_bgwriter': {
'options': [None, 'Buffers written by the background writer', 'kilobytes/s', 'bgwriter', 'postgres.bgwriter_bgwriter', 'line'],
'lines': [
['buffers_clean', 'clean', 'incremental', 8, 1024]
]},
'stat_bgwriter_maxwritten': {
'options': [None, 'Too many buffers written', 'times', 'bgwriter', 'postgres.stat_bgwriter_maxwritten', 'line'],
'lines': [
['maxwritten_clean', 'maxwritten', 'incremental']
]},
'autovacuum': {
'options': [None, 'Autovacuum workers', 'workers', 'autovacuum', 'postgres.autovacuum', 'line'],
'lines': [
['analyze', 'analyze', 'absolute'],
['vacuum', 'vacuum', 'absolute'],
['vacuum_analyze', 'vacuum analyze', 'absolute'],
['vacuum_freeze', 'vacuum freeze', 'absolute'],
['brin_summarize', 'brin summarize', 'absolute']
]},
'standby_delta': {
'options': [None, 'Standby delta', 'kilobytes', 'replication delta', 'postgres.standby_delta', 'line'],
'lines': [
['writer_scheduled', 'scheduled', 'incremental'],
['writer_requested', 'requested', 'incremental']
['sent_delta', 'sent delta', 'absolute', 1, 1024],
['write_delta', 'write delta', 'absolute', 1, 1024],
['flush_delta', 'flush delta', 'absolute', 1, 1024],
['replay_delta', 'replay delta', 'absolute', 1, 1024]
]}
}

Expand All @@ -237,6 +378,7 @@ def __init__(self, configuration=None, name=None):
self.data = dict()
self.locks_zeroed = dict()
self.databases = list()
self.secondaries = list()
self.queries = QUERY_STATS.copy()

def _connect(self):
Expand Down Expand Up @@ -270,6 +412,7 @@ def check(self):
cursor = self.connection.cursor()
self.databases = discover_databases_(cursor, QUERIES['FIND_DATABASES'])
is_superuser = check_if_superuser_(cursor, QUERIES['IF_SUPERUSER'])
self.secondaries = discover_secondaries_(cursor, QUERIES['FIND_STANDBY'])
self.server_version = detect_server_version(cursor, QUERIES['DETECT_SERVER_VERSION'])
cursor.close()

Expand All @@ -291,12 +434,17 @@ def add_additional_queries_(self, is_superuser):
if self.table_stats:
self.queries[QUERIES['TABLE_STATS']] = METRICS['TABLE_STATS']
if is_superuser:
self.queries[QUERIES['CHECKPOINTER']] = METRICS['CHECKPOINTER']
self.queries[QUERIES['BGWRITER']] = METRICS['BGWRITER']
if self.server_version >= 100000:
wal_dir_name = 'pg_wal'
self.queries[QUERIES['WAL']] = METRICS['WAL']
else:
wal_dir_name = 'pg_xlog'
self.queries[QUERIES['ARCHIVE'].format(wal_dir_name)] = METRICS['ARCHIVE']
if self.server_version >= 90400:
self.queries[QUERIES['AUTOVACUUM']] = METRICS['AUTOVACUUM']
self.queries[QUERIES['STANDBY_DELTA']] = METRICS['STANDBY_DELTA']

def create_dynamic_charts_(self):

Expand All @@ -309,6 +457,11 @@ def create_dynamic_charts_(self):

add_database_lock_chart_(order=self.order, definitions=self.definitions, database_name=database_name)

for application_name in self.secondaries[::-1]:
add_replication_delta_chart_(order=self.order, definitions=self.definitions,
name='standby_delta', application_name=application_name)


def _get_data(self):
result, error = self._connect()
if result:
Expand All @@ -332,7 +485,12 @@ def query_stats_(self, cursor, query, metrics):
cursor.execute(query, dict(databases=tuple(self.databases)))
for row in cursor:
for metric in metrics:
dimension_id = '_'.join([row['database_name'], metric]) if 'database_name' in row else metric
if 'database_name' in row:
dimension_id = '_'.join([row['database_name'], metric])
elif 'application_name' in row:
dimension_id = '_'.join([row['application_name'], metric])
else:
dimension_id = metric
if metric in row:
self.data[dimension_id] = int(row[metric])
elif 'locks_count' in row:
Expand All @@ -347,6 +505,14 @@ def discover_databases_(cursor, query):
result.append(db)
return result

def discover_secondaries_(cursor, query):
cursor.execute(query)
result = list()
for sc in [standby[0] for standby in cursor]:
if sc not in result:
result.append(sc)
return result


def check_if_superuser_(cursor, query):
cursor.execute(query)
Expand Down Expand Up @@ -398,3 +564,20 @@ def create_lines(database, lines):
definitions[chart_name] = {
'options': [name, title + ': ' + database_name, units, 'db ' + database_name, context, chart_type],
'lines': create_lines(database_name, chart_template['lines'])}

def add_replication_delta_chart_(order, definitions, name, application_name):
def create_lines(standby, lines):
result = list()
for line in lines:
new_line = ['_'.join([standby, line[0]])] + line[1:]
result.append(new_line)
return result

chart_template = CHARTS[name]
chart_name = '_'.join([application_name, name])
position = order.index('database_size')
order.insert(position, chart_name)
name, title, units, family, context, chart_type = chart_template['options']
definitions[chart_name] = {
'options': [name, title + ': ' + application_name, units, 'replication delta', context, chart_type],
'lines': create_lines(application_name, chart_template['lines'])}
Loading

0 comments on commit 284a734

Please sign in to comment.