From 00afb731317041130e185a8cbeebf8bd58e433ba Mon Sep 17 00:00:00 2001 From: Sarah Date: Tue, 27 Jul 2021 17:09:00 -0400 Subject: [PATCH 1/8] Add table bloat percentage metric --- LICENSE-3rdparty.csv | 1 + .../postgres/relationsmanager.py | 56 ++++++++++++++++++- 2 files changed, 55 insertions(+), 2 deletions(-) diff --git a/LICENSE-3rdparty.csv b/LICENSE-3rdparty.csv index df40a2af19556..5a332d764f7e0 100644 --- a/LICENSE-3rdparty.csv +++ b/LICENSE-3rdparty.csv @@ -16,6 +16,7 @@ boto,PyPI,MIT,Mitch Garnaat boto3,PyPI,Apache-2.0,Amazon Web Services botocore,PyPI,Apache-2.0,Amazon Web Services cachetools,PyPI,MIT,Thomas Kemmer +check-postgres,https://github.com/bucardo/,BSD-2-Clause,Greg Sabino Mullane clickhouse-cityhash,PyPI,MIT,Alexander [Amper] Marshalov clickhouse-driver,PyPI,MIT,Konstantin Lebedev contextlib2,PyPI,PSF,Nick Coghlan diff --git a/postgres/datadog_checks/postgres/relationsmanager.py b/postgres/datadog_checks/postgres/relationsmanager.py index 96445a3df11cc..923e05acbf2d5 100644 --- a/postgres/datadog_checks/postgres/relationsmanager.py +++ b/postgres/datadog_checks/postgres/relationsmanager.py @@ -111,7 +111,6 @@ {relations}""", } - # The pg_statio_all_tables view will contain one row for each table in the current database, # showing statistics about I/O on that specific table. The pg_statio_user_tables views contain the same information, # but filtered to only show user tables. @@ -135,9 +134,62 @@ WHERE {relations}""", 'relation': True, } +'pg_index' +BLOAT_QUERY = """ +SELECT + schemaname, relname, iname, /*reltuples::bigint, relpages::bigint, otta,*/ + ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::float/otta END)::numeric,1) AS tbloat +FROM ( + SELECT + schemaname, tablename, cc.relname as relname, cc.reltuples, cc.relpages, bs, + CEIL((cc.reltuples*((datahdr+ma- + (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::float)) AS otta, + COALESCE(c2.relname,'?') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages, + COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::float)),0) AS iotta -- very rough approximation, assumes all cols + FROM ( + SELECT + ma,bs,schemaname,tablename, + (datawidth+(hdr+ma-(case when hdr%ma=0 THEN ma ELSE hdr%ma END)))::numeric AS datahdr, + (maxfracsum*(nullhdr+ma-(case when nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2 + FROM ( + SELECT + schemaname, tablename, hdr, ma, bs, + SUM((1-null_frac)*avg_width) AS datawidth, + MAX(null_frac) AS maxfracsum, + hdr+( + SELECT 1+count(*)/8 + FROM pg_stats s2 + WHERE null_frac<>0 AND s2.schemaname = s.schemaname AND s2.tablename = s.tablename + ) AS nullhdr + FROM pg_stats s, ( + SELECT + (SELECT current_setting('block_size')::numeric) AS bs, + CASE WHEN substring(v,12,3) IN ('8.0','8.1','8.2') THEN 27 ELSE 23 END AS hdr, + CASE WHEN v ~ 'mingw32' THEN 8 ELSE 4 END AS ma + FROM (SELECT version() AS v) AS foo + ) AS constants + GROUP BY 1,2,3,4,5 + ) AS foo + ) AS rs + JOIN pg_class cc ON cc.relname = rs.tablename + JOIN pg_namespace nn ON cc.relnamespace = nn.oid + AND nn.nspname = rs.schemaname + AND nn.nspname <> 'information_schema' + LEFT JOIN pg_index i ON indrelid = cc.oid + LEFT JOIN pg_class c2 ON c2.oid = i.indexrelid +) AS sml WHERE {relations}; +""" -RELATION_METRICS = [LOCK_METRICS, REL_METRICS, IDX_METRICS, SIZE_METRICS, STATIO_METRICS] +BLOAT_METRICS = { + 'descriptors': [('schemaname', 'schema'), ('relname', 'table'), ('iname', 'index')], + 'metrics': { + 'tbloat': ('postgresql.bloat', AgentCheck.gauge), + }, + 'query': BLOAT_QUERY, + 'relation': True, +} +RELATION_METRICS = [LOCK_METRICS, REL_METRICS, IDX_METRICS, SIZE_METRICS, STATIO_METRICS, BLOAT_METRICS] class RelationsManager(object): From a7d0fca2b9ae8969fa8ae1e9b059f70b9ee56d52 Mon Sep 17 00:00:00 2001 From: Sarah Date: Tue, 27 Jul 2021 17:12:20 -0400 Subject: [PATCH 2/8] Update metadata.csv --- postgres/datadog_checks/postgres/relationsmanager.py | 2 +- postgres/metadata.csv | 1 + 2 files changed, 2 insertions(+), 1 deletion(-) diff --git a/postgres/datadog_checks/postgres/relationsmanager.py b/postgres/datadog_checks/postgres/relationsmanager.py index 923e05acbf2d5..134ae1d3097b1 100644 --- a/postgres/datadog_checks/postgres/relationsmanager.py +++ b/postgres/datadog_checks/postgres/relationsmanager.py @@ -184,7 +184,7 @@ BLOAT_METRICS = { 'descriptors': [('schemaname', 'schema'), ('relname', 'table'), ('iname', 'index')], 'metrics': { - 'tbloat': ('postgresql.bloat', AgentCheck.gauge), + 'tbloat': ('postgresql.table_bloat', AgentCheck.gauge), }, 'query': BLOAT_QUERY, 'relation': True, diff --git a/postgres/metadata.csv b/postgres/metadata.csv index 4d18ece928af2..ed3d392a6063b 100644 --- a/postgres/metadata.csv +++ b/postgres/metadata.csv @@ -52,6 +52,7 @@ postgresql.heap_blocks_read,gauge,,block,second,The number of disk blocks read f postgresql.heap_blocks_hit,gauge,,hit,second,The number of buffer hits in this table.,0,postgres,heap blks hit postgresql.index_blocks_read,gauge,,block,second,The number of disk blocks read from all indexes on this table.,0,postgres,idx blks read postgresql.index_blocks_hit,gauge,,hit,second,The number of buffer hits in all indexes on this table.,0,postgres,idx blks hit +postgresql.table_bloat,gauge,,percent,,The percentage of table bloat.,0,postgres,tbloat postgresql.toast_blocks_read,gauge,,block,second,The number of disk blocks read from this table's TOAST table.,0,postgres,toast blks read postgresql.toast_blocks_hit,gauge,,hit,second,The number of buffer hits in this table's TOAST table.,0,postgres,toast blks hit postgresql.toast_index_blocks_read,gauge,,block,second,The number of disk blocks read from this table's TOAST table index.,0,postgres,toast idx blks read From 9f528ed7e22dd41a24374e9f1be681ba1dd49f83 Mon Sep 17 00:00:00 2001 From: Sarah Date: Tue, 27 Jul 2021 17:27:00 -0400 Subject: [PATCH 3/8] Add test for bloat --- postgres/tests/test_relations.py | 19 +++++++++++++++++++ 1 file changed, 19 insertions(+) diff --git a/postgres/tests/test_relations.py b/postgres/tests/test_relations.py index 1c31ab559dde7..08e2ba3d3f11f 100644 --- a/postgres/tests/test_relations.py +++ b/postgres/tests/test_relations.py @@ -75,6 +75,25 @@ def test_relations_metrics(aggregator, integration_check, pg_instance): for name in RELATION_SIZE_METRICS: aggregator.assert_metric(name, count=1, tags=expected_size_tags) +@pytest.mark.integration +@pytest.mark.usefixtures('dd_environment') +def test_bloat_metric(aggregator, integration_check, pg_instance): + pg_instance['relations'] = ['pg_index'] + + posgres_check = integration_check(pg_instance) + posgres_check.check(pg_instance) + + expected_tags = pg_instance['tags'] + [ + 'server:{}'.format(pg_instance['host']), + 'port:{}'.format(pg_instance['port']), + 'db:%s' % pg_instance['dbname'], + 'table:pg_index', + 'schema:pg_catalog', + 'index:pg_index_indrelid_index' + ] + + aggregator.assert_metric('postgresql.table_bloat', count=1, tags=expected_tags) + @pytest.mark.integration @pytest.mark.usefixtures('dd_environment') From 1c7632320de4acfcd13ab7d989e6d221641a2898 Mon Sep 17 00:00:00 2001 From: Sarah Date: Tue, 27 Jul 2021 17:40:53 -0400 Subject: [PATCH 4/8] Style and update notes --- postgres/datadog_checks/postgres/relationsmanager.py | 3 +++ postgres/metadata.csv | 2 +- postgres/tests/test_relations.py | 3 ++- 3 files changed, 6 insertions(+), 2 deletions(-) diff --git a/postgres/datadog_checks/postgres/relationsmanager.py b/postgres/datadog_checks/postgres/relationsmanager.py index 134ae1d3097b1..a4eb957edeb31 100644 --- a/postgres/datadog_checks/postgres/relationsmanager.py +++ b/postgres/datadog_checks/postgres/relationsmanager.py @@ -136,6 +136,7 @@ } 'pg_index' +# adapted from https://wiki.postgresql.org/wiki/Show_database_bloat and https://github.com/bucardo/check_postgres/ BLOAT_QUERY = """ SELECT schemaname, relname, iname, /*reltuples::bigint, relpages::bigint, otta,*/ @@ -181,6 +182,7 @@ ) AS sml WHERE {relations}; """ +# The estimated table bloat BLOAT_METRICS = { 'descriptors': [('schemaname', 'schema'), ('relname', 'table'), ('iname', 'index')], 'metrics': { @@ -189,6 +191,7 @@ 'query': BLOAT_QUERY, 'relation': True, } + RELATION_METRICS = [LOCK_METRICS, REL_METRICS, IDX_METRICS, SIZE_METRICS, STATIO_METRICS, BLOAT_METRICS] diff --git a/postgres/metadata.csv b/postgres/metadata.csv index ed3d392a6063b..5dc758745ce20 100644 --- a/postgres/metadata.csv +++ b/postgres/metadata.csv @@ -52,7 +52,7 @@ postgresql.heap_blocks_read,gauge,,block,second,The number of disk blocks read f postgresql.heap_blocks_hit,gauge,,hit,second,The number of buffer hits in this table.,0,postgres,heap blks hit postgresql.index_blocks_read,gauge,,block,second,The number of disk blocks read from all indexes on this table.,0,postgres,idx blks read postgresql.index_blocks_hit,gauge,,hit,second,The number of buffer hits in all indexes on this table.,0,postgres,idx blks hit -postgresql.table_bloat,gauge,,percent,,The percentage of table bloat.,0,postgres,tbloat +postgresql.table_bloat,gauge,,percent,,The estimated percentage of table bloat.,0,postgres,tbloat postgresql.toast_blocks_read,gauge,,block,second,The number of disk blocks read from this table's TOAST table.,0,postgres,toast blks read postgresql.toast_blocks_hit,gauge,,hit,second,The number of buffer hits in this table's TOAST table.,0,postgres,toast blks hit postgresql.toast_index_blocks_read,gauge,,block,second,The number of disk blocks read from this table's TOAST table index.,0,postgres,toast idx blks read diff --git a/postgres/tests/test_relations.py b/postgres/tests/test_relations.py index 08e2ba3d3f11f..d7fa6960085b2 100644 --- a/postgres/tests/test_relations.py +++ b/postgres/tests/test_relations.py @@ -75,6 +75,7 @@ def test_relations_metrics(aggregator, integration_check, pg_instance): for name in RELATION_SIZE_METRICS: aggregator.assert_metric(name, count=1, tags=expected_size_tags) + @pytest.mark.integration @pytest.mark.usefixtures('dd_environment') def test_bloat_metric(aggregator, integration_check, pg_instance): @@ -89,7 +90,7 @@ def test_bloat_metric(aggregator, integration_check, pg_instance): 'db:%s' % pg_instance['dbname'], 'table:pg_index', 'schema:pg_catalog', - 'index:pg_index_indrelid_index' + 'index:pg_index_indrelid_index', ] aggregator.assert_metric('postgresql.table_bloat', count=1, tags=expected_tags) From 3ebcf1e7f16999cb4fd72c4eae633700ab77267d Mon Sep 17 00:00:00 2001 From: Sarah Date: Tue, 27 Jul 2021 17:43:47 -0400 Subject: [PATCH 5/8] Remove typo --- postgres/datadog_checks/postgres/relationsmanager.py | 1 - 1 file changed, 1 deletion(-) diff --git a/postgres/datadog_checks/postgres/relationsmanager.py b/postgres/datadog_checks/postgres/relationsmanager.py index a4eb957edeb31..f53b48ce6188a 100644 --- a/postgres/datadog_checks/postgres/relationsmanager.py +++ b/postgres/datadog_checks/postgres/relationsmanager.py @@ -134,7 +134,6 @@ WHERE {relations}""", 'relation': True, } -'pg_index' # adapted from https://wiki.postgresql.org/wiki/Show_database_bloat and https://github.com/bucardo/check_postgres/ BLOAT_QUERY = """ From cf2b0885feed5861598d4bfcf50f20521504142f Mon Sep 17 00:00:00 2001 From: Sarah Date: Tue, 27 Jul 2021 17:45:15 -0400 Subject: [PATCH 6/8] Remove comment --- postgres/datadog_checks/postgres/relationsmanager.py | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/postgres/datadog_checks/postgres/relationsmanager.py b/postgres/datadog_checks/postgres/relationsmanager.py index f53b48ce6188a..60744f0fcf912 100644 --- a/postgres/datadog_checks/postgres/relationsmanager.py +++ b/postgres/datadog_checks/postgres/relationsmanager.py @@ -138,7 +138,7 @@ # adapted from https://wiki.postgresql.org/wiki/Show_database_bloat and https://github.com/bucardo/check_postgres/ BLOAT_QUERY = """ SELECT - schemaname, relname, iname, /*reltuples::bigint, relpages::bigint, otta,*/ + schemaname, relname, iname, ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::float/otta END)::numeric,1) AS tbloat FROM ( SELECT From 1b84374a4540dd892233fc06793100ccbed6842d Mon Sep 17 00:00:00 2001 From: Sarah Date: Wed, 28 Jul 2021 15:27:19 -0400 Subject: [PATCH 7/8] Add extra license file --- LICENSE-3rdparty.csv | 2 +- postgres/LICENSE-3rdparty-extra.csv | 1 + 2 files changed, 2 insertions(+), 1 deletion(-) create mode 100644 postgres/LICENSE-3rdparty-extra.csv diff --git a/LICENSE-3rdparty.csv b/LICENSE-3rdparty.csv index 5a332d764f7e0..da02d8dbac463 100644 --- a/LICENSE-3rdparty.csv +++ b/LICENSE-3rdparty.csv @@ -16,7 +16,7 @@ boto,PyPI,MIT,Mitch Garnaat boto3,PyPI,Apache-2.0,Amazon Web Services botocore,PyPI,Apache-2.0,Amazon Web Services cachetools,PyPI,MIT,Thomas Kemmer -check-postgres,https://github.com/bucardo/,BSD-2-Clause,Greg Sabino Mullane +check-postgres,"https://github.com/bucardo/",BSD-2-Clause,Greg Sabino Mullane clickhouse-cityhash,PyPI,MIT,Alexander [Amper] Marshalov clickhouse-driver,PyPI,MIT,Konstantin Lebedev contextlib2,PyPI,PSF,Nick Coghlan diff --git a/postgres/LICENSE-3rdparty-extra.csv b/postgres/LICENSE-3rdparty-extra.csv new file mode 100644 index 0000000000000..387cfcceee29b --- /dev/null +++ b/postgres/LICENSE-3rdparty-extra.csv @@ -0,0 +1 @@ +check-postgres,"https://github.com/bucardo/",BSD-2-Clause,Greg Sabino Mullane From 54c340833f7456707ee1f5f60ba26b3ea7aaca19 Mon Sep 17 00:00:00 2001 From: Sarah Date: Thu, 29 Jul 2021 09:54:20 -0400 Subject: [PATCH 8/8] Add header line --- postgres/LICENSE-3rdparty-extra.csv | 1 + 1 file changed, 1 insertion(+) diff --git a/postgres/LICENSE-3rdparty-extra.csv b/postgres/LICENSE-3rdparty-extra.csv index 387cfcceee29b..d7821f1e2821c 100644 --- a/postgres/LICENSE-3rdparty-extra.csv +++ b/postgres/LICENSE-3rdparty-extra.csv @@ -1 +1,2 @@ +Component,Origin,License,Copyright check-postgres,"https://github.com/bucardo/",BSD-2-Clause,Greg Sabino Mullane