Skip to content

Commit ffb4d3b

Browse files
authored
DBMON-5416 Collect table size metrics for SQLServer (#20367)
* Sqlserver table size metrics * wip * Wip * Collect table size metrics for SQLServer * Format * Exclude tempdb * Changelog * Validate * Integration test * Style * Metadata file * License * Skip table size metrics for windows * Lint
1 parent 27aad04 commit ffb4d3b

File tree

14 files changed

+257
-4
lines changed

14 files changed

+257
-4
lines changed

sqlserver/assets/configuration/spec.yaml

Lines changed: 17 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -430,6 +430,23 @@ files:
430430
- name: enabled
431431
type: boolean
432432
example: false
433+
- name: table_size_metrics
434+
description: |
435+
Configure collection of table size metrics.
436+
437+
Set `table_size_metrics.enabled` to true to enable collection of table size metrics.
438+
Does not collect tempdb metrics.
439+
Defaults to false.
440+
value:
441+
type: object
442+
properties:
443+
- name: enabled
444+
type: boolean
445+
example: false
446+
- name: collection_interval
447+
type: integer
448+
example: 600
449+
display_default: 600
433450
- name: agent_jobs
434451
description: Configure collection of SQL Server Agent jobs events and metrics
435452
options:

sqlserver/changelog.d/20367.added

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
Add size and row count collection for tables in SQLServer

sqlserver/datadog_checks/sqlserver/config.py

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -217,6 +217,7 @@ def _build_database_metrics_configs(self, instance):
217217
"task_scheduler_metrics": {'enabled': False},
218218
"tempdb_file_space_usage_metrics": {'enabled': True},
219219
"xe_metrics": {'enabled': False},
220+
"table_size_metrics": {'enabled': False, 'collection_interval': DEFAULT_LONG_METRICS_COLLECTION_INTERVAL},
220221
}
221222
# Check if the instance has any configuration for the metrics in legacy structure
222223
legacy_configuration_metrics = {

sqlserver/datadog_checks/sqlserver/config_models/instance.py

Lines changed: 10 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -197,6 +197,15 @@ class ServerStateMetrics(BaseModel):
197197
enabled: Optional[bool] = Field(None, examples=[True])
198198

199199

200+
class TableSizeMetrics(BaseModel):
201+
model_config = ConfigDict(
202+
arbitrary_types_allowed=True,
203+
frozen=True,
204+
)
205+
collection_interval: Optional[int] = Field(None, examples=[600])
206+
enabled: Optional[bool] = Field(None, examples=[False])
207+
208+
200209
class TaskSchedulerMetrics(BaseModel):
201210
model_config = ConfigDict(
202211
arbitrary_types_allowed=True,
@@ -239,6 +248,7 @@ class DatabaseMetrics(BaseModel):
239248
primary_log_shipping_metrics: Optional[PrimaryLogShippingMetrics] = None
240249
secondary_log_shipping_metrics: Optional[SecondaryLogShippingMetrics] = None
241250
server_state_metrics: Optional[ServerStateMetrics] = None
251+
table_size_metrics: Optional[TableSizeMetrics] = None
242252
task_scheduler_metrics: Optional[TaskSchedulerMetrics] = None
243253
tempdb_file_space_usage_metrics: Optional[TempdbFileSpaceUsageMetrics] = None
244254
xe_metrics: Optional[XeMetrics] = None

sqlserver/datadog_checks/sqlserver/const.py

Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -253,6 +253,13 @@
253253
('sqlserver.database.master_files.state', 'sys.master_files', 'state'),
254254
]
255255

256+
TABLE_SIZE_METRICS = [
257+
('sqlserver.table.row_count', 'sys.dm_db_partition_stats', 'row_count'),
258+
('sqlserver.table.total_size', 'sys.dm_db_partition_stats', 'total_size'),
259+
('sqlserver.table.used_size', 'sys.dm_db_partition_stats', 'used_size'),
260+
('sqlserver.table.data_size', 'sys.dm_db_partition_stats', 'data_size'),
261+
]
262+
256263
TEMPDB_FILE_SPACE_USAGE_METRICS = [
257264
('sqlserver.tempdb.file_space_usage.free_space', 'sys.dm_db_file_space_usage', 'free_space'),
258265
(

sqlserver/datadog_checks/sqlserver/data/conf.yaml.example

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -290,6 +290,15 @@ instances:
290290
#
291291
# xe_metrics: {}
292292

293+
## @param table_size_metrics - mapping - optional
294+
## Configure collection of table size metrics.
295+
##
296+
## Set `table_size_metrics.enabled` to true to enable collection of table size metrics.
297+
## Does not collect tempdb metrics.
298+
## Defaults to false.
299+
#
300+
# table_size_metrics: {}
301+
293302
## Configure collection of SQL Server Agent jobs events and metrics
294303
#
295304
# agent_jobs:

sqlserver/datadog_checks/sqlserver/database_metrics/__init__.py

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -21,3 +21,4 @@
2121
from .server_state_metrics import SqlserverServerStateMetrics
2222
from .tempdb_file_space_usage_metrics import SqlserverTempDBFileSpaceUsageMetrics
2323
from .xe_session_metrics import SQLServerXESessionMetrics
24+
from .table_size_metrics import SqlserverTableSizeMetrics
Lines changed: 101 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,101 @@
1+
# (C) Datadog, Inc. 2025-present
2+
# All rights reserved
3+
# Licensed under a 3-clause BSD style license (see LICENSE)
4+
import functools
5+
6+
from datadog_checks.base.errors import ConfigurationError
7+
8+
from .base import SqlserverDatabaseMetricsBase
9+
10+
TABLE_SIZE_STATS_QUERY = {
11+
"name": "sys.dm_db_partition_stats",
12+
"query": """
13+
SELECT
14+
t.name AS table_name,
15+
s.name AS schema_name,
16+
db_name() AS database_name,
17+
SUM(p.row_count) AS row_count,
18+
CAST(SUM(a.total_pages) * 8.0 AS DECIMAL(18,2)) AS total_size,
19+
CAST(SUM(a.used_pages) * 8.0 AS DECIMAL(18,2)) AS used_size,
20+
CAST(SUM(a.data_pages) * 8.0 AS DECIMAL(18,2)) AS data_size
21+
FROM
22+
sys.tables t
23+
INNER JOIN
24+
sys.schemas s ON t.schema_id = s.schema_id
25+
INNER JOIN
26+
sys.indexes i ON t.object_id = i.object_id
27+
INNER JOIN
28+
sys.dm_db_partition_stats p ON i.object_id = p.object_id AND i.index_id = p.index_id
29+
INNER JOIN
30+
sys.allocation_units a ON p.partition_id = a.container_id
31+
GROUP BY
32+
t.name, s.name
33+
""",
34+
"columns": [
35+
{"name": "table", "type": "tag"},
36+
{"name": "schema", "type": "tag"},
37+
{"name": "database", "type": "tag"},
38+
{"name": "table.row_count", "type": "gauge"},
39+
{"name": "table.total_size", "type": "gauge"},
40+
{"name": "table.used_size", "type": "gauge"},
41+
{"name": "table.data_size", "type": "gauge"},
42+
],
43+
}
44+
45+
46+
# https://learn.microsoft.com/en-us/sql/relational-databases/system-dynamic-management-views/sys-dm-db-index-usage-stats-transact-sql?view=sql-server-ver15
47+
class SqlserverTableSizeMetrics(SqlserverDatabaseMetricsBase):
48+
@property
49+
def include_table_size_metrics(self) -> bool:
50+
return self.config.database_metrics_config["table_size_metrics"]["enabled"]
51+
52+
@property
53+
def collection_interval(self) -> int:
54+
'''
55+
Returns the interval in seconds at which to collect table size metrics.
56+
Note: The table size metrics query can be expensive, so it is recommended to set a higher interval.
57+
'''
58+
return self.config.database_metrics_config["table_size_metrics"]["collection_interval"]
59+
60+
@property
61+
def databases(self):
62+
'''
63+
Returns a list of databases to collect table size metrics for.
64+
tempdb is excluded.
65+
'''
66+
if not self._databases:
67+
raise ConfigurationError("No databases configured for table size metrics")
68+
if 'tempdb' in self._databases:
69+
self._databases.remove('tempdb')
70+
return self._databases
71+
72+
@property
73+
def enabled(self):
74+
if not self.include_table_size_metrics:
75+
return False
76+
return True
77+
78+
@property
79+
def queries(self):
80+
# make a copy of the query to avoid modifying the original
81+
# in case different instances have different collection intervals
82+
query = TABLE_SIZE_STATS_QUERY.copy()
83+
query['collection_interval'] = self.collection_interval
84+
return [query]
85+
86+
def __repr__(self) -> str:
87+
return (
88+
f"{self.__class__.__name__}(" f"enabled={self.enabled}, " f"collection_interval={self.collection_interval})"
89+
)
90+
91+
def _build_query_executors(self):
92+
executors = []
93+
for database in self.databases:
94+
executor = self.new_query_executor(
95+
self.queries,
96+
executor=functools.partial(self.execute_query_handler, db=database),
97+
track_operation_time=self.track_operation_time,
98+
)
99+
executor.compile_queries()
100+
executors.append(executor)
101+
return executors

sqlserver/datadog_checks/sqlserver/sqlserver.py

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -44,6 +44,7 @@
4444
SqlserverPrimaryLogShippingMetrics,
4545
SqlserverSecondaryLogShippingMetrics,
4646
SqlserverServerStateMetrics,
47+
SqlserverTableSizeMetrics,
4748
SqlserverTempDBFileSpaceUsageMetrics,
4849
SQLServerXESessionMetrics,
4950
)
@@ -887,6 +888,7 @@ def _database_level_database_metrics(self):
887888
SqlserverIndexUsageMetrics,
888889
SqlserverDBFragmentationMetrics,
889890
SqlserverDatabaseFilesMetrics,
891+
SqlserverTableSizeMetrics,
890892
]
891893

892894
@property

sqlserver/metadata.csv

Lines changed: 6 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -141,6 +141,10 @@ sqlserver.stats.procs_blocked,gauge,,process,,The number of processes blocked. (
141141
sqlserver.stats.safe_auto_param_attempts,gauge,,attempt,,Number of safe auto-parameterization attempts per second. (Perf. Counter: `SQL Statistics - Safe Auto-Params/sec`),0,sql_server,stats safe auto param,,
142142
sqlserver.stats.sql_compilations,gauge,,operation,second,The number of SQL compilations per second. (Perf. Counter: `SQL Statistics - SQL Compilations/sec`),0,sql_server,sql compils,,
143143
sqlserver.stats.sql_recompilations,gauge,,operation,second,The number of SQL re-compilations per second. (Perf. Counter: `SQL Statistics - SQL Re-Compilations/sec`),-1,sql_server,sql recompils,,
144+
sqlserver.table.data_size,gauge,,kibibyte,,The size in kibibytes of data stored in this table excluding internal index pages and allocation-management pages. Tags: `database` `schema` `table`,0,sql_server,total table size,,
145+
sqlserver.table.row_count,gauge,,row,,The number of rows in this table. Tags: `database` `schema` `table`,0,sql_server,table row count,,
146+
sqlserver.table.total_size,gauge,,kibibyte,,The total size of the table in kibibytes. Tags: `database` `schema` `table`,0,sql_server,table data size,,
147+
sqlserver.table.used_size,gauge,,kibibyte,,The size in kibibytes of data stored in this table including internal index pages and allocation-management pages. Tags: `database` `schema` `table`,0,sql_server,table used size,,
144148
sqlserver.task.context_switches_count,gauge,,unit,,Number of scheduler context switches that this task has completed. Tags: 'scheduler_id',0,sql_server,context switch,,
145149
sqlserver.task.pending_io_byte_average,gauge,,byte,,Average byte count of I/Os that are performed by this task. Tags: 'scheduler_id',0,sql_server,task avg io byte,,
146150
sqlserver.task.pending_io_byte_count,gauge,,byte,,Total byte count of I/Os that are performed by this task. Tags: 'scheduler_id',0,sql_server,task io byte,,
@@ -154,5 +158,5 @@ sqlserver.transactions.longest_transaction_running_time,gauge,,second,,The time
154158
sqlserver.transactions.version_cleanup_rate,gauge,,kibibyte,second,The cleanup rate of the version store in tempdb. (Perf. Counter: `Transactions - Version Cleanup rate (KB/s)`),0,sql_server,version cleanup rate,,
155159
sqlserver.transactions.version_generation_rate,gauge,,kibibyte,second,The generation rate of the version store in tempdb. (Perf. Counter: `Transactions - Version Generation rate (KB/s)`),0,sql_server,version generation rate,,
156160
sqlserver.transactions.version_store_size,gauge,,kibibyte,,The size of the version store in tempdb. (Perf. Counter: `Transactions - Version Store Size (KB)`),0,sql_server,version store size,,
157-
sqlserver.xe.events_not_in_xml,gauge,,event,,"Number of generated events that are missing in the XML representation of the ring buffer. Tags: `session_name`",0,sql_server,xe events not in xml,,
158-
sqlserver.xe.session_status,gauge,,,,"Status of the node in a SQL Server failover cluster instance. Tags: `session_name`",0,sql_server,xe session status,,
161+
sqlserver.xe.events_not_in_xml,gauge,,event,,Number of generated events that are missing in the XML representation of the ring buffer. Tags: `session_name`,0,sql_server,xe events not in xml,,
162+
sqlserver.xe.session_status,gauge,,,,Status of the node in a SQL Server failover cluster instance. Tags: `session_name`,0,sql_server,xe session status,,

sqlserver/tests/common.py

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -22,6 +22,7 @@
2222
INSTANCE_METRICS,
2323
INSTANCE_METRICS_DATABASE_AO,
2424
INSTANCE_METRICS_DATABASE_SINGLE,
25+
TABLE_SIZE_METRICS,
2526
TASK_SCHEDULER_METRICS,
2627
TEMPDB_FILE_SPACE_USAGE_METRICS,
2728
)
@@ -97,6 +98,7 @@ def get_local_driver():
9798
DATABASE_METRICS,
9899
DATABASE_BACKUP_METRICS,
99100
TEMPDB_FILE_SPACE_USAGE_METRICS,
101+
TABLE_SIZE_METRICS,
100102
)
101103
]
102104
+ DATABASE_INDEX_METRICS

sqlserver/tests/conftest.py

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -115,6 +115,9 @@ def instance_docker(instance_docker_defaults):
115115
'master_files_metrics': {
116116
'enabled': True,
117117
},
118+
'table_size_metrics': {
119+
'enabled': True,
120+
},
118121
},
119122
'disable_generic_tags': True,
120123
}

sqlserver/tests/test_database_metrics.py

Lines changed: 58 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -32,6 +32,7 @@
3232
SqlserverPrimaryLogShippingMetrics,
3333
SqlserverSecondaryLogShippingMetrics,
3434
SqlserverServerStateMetrics,
35+
SqlserverTableSizeMetrics,
3536
SqlserverTempDBFileSpaceUsageMetrics,
3637
)
3738
from datadog_checks.sqlserver.utils import Database
@@ -920,7 +921,6 @@ def test_sqlserver_db_fragmentation_metrics(
920921
instance_docker_metrics['database_metrics']['db_fragmentation_metrics'][
921922
'collection_interval'
922923
] = db_fragmentation_metrics_interval
923-
print(instance_docker_metrics)
924924
mocked_results = [
925925
[
926926
('master', 'spt_fallback_db', 'dbo', 0, None, 0, 0.0, 0, 0.0),
@@ -1301,6 +1301,63 @@ def test_sqlserver_database_files_metrics(
13011301
aggregator.assert_metric(metric_name, value=metric_value, tags=expected_tags)
13021302

13031303

1304+
@pytest.mark.integration
1305+
@pytest.mark.usefixtures('dd_environment')
1306+
@pytest.mark.parametrize('include_table_size_metrics', [True, False])
1307+
def test_sqlserver_table_size_metrics(
1308+
aggregator,
1309+
dd_run_check,
1310+
init_config,
1311+
instance_docker_metrics,
1312+
include_table_size_metrics,
1313+
):
1314+
instance_docker_metrics['database_autodiscovery'] = True
1315+
instance_docker_metrics['database_metrics'] = {
1316+
'table_size_metrics': {'enabled': include_table_size_metrics},
1317+
}
1318+
1319+
mocked_results = [
1320+
('table1', 'dbo', 'master', 100, 1024, 500, 200),
1321+
('table2', 'dbo', 'master', 100, 1024, 500, 200),
1322+
('table3', 'dbo', 'master', 100, 1024, 500, 200),
1323+
('table4', 'dbo', 'datadog_test-1', 100, 1024, 500, 200),
1324+
]
1325+
1326+
sqlserver_check = SQLServer(CHECK_NAME, init_config, [instance_docker_metrics])
1327+
sqlserver_check.databases = {Database(db) for db in AUTODISCOVERY_DBS}
1328+
1329+
execute_query_handler_mocked = mock.MagicMock()
1330+
execute_query_handler_mocked.return_value = mocked_results
1331+
1332+
table_size_metrics = SqlserverTableSizeMetrics(
1333+
config=sqlserver_check._config,
1334+
new_query_executor=sqlserver_check._new_query_executor,
1335+
server_static_info=STATIC_SERVER_INFO,
1336+
execute_query_handler=execute_query_handler_mocked,
1337+
databases=AUTODISCOVERY_DBS,
1338+
)
1339+
1340+
sqlserver_check._database_metrics = [table_size_metrics]
1341+
1342+
dd_run_check(sqlserver_check)
1343+
1344+
if not include_table_size_metrics:
1345+
assert table_size_metrics.enabled is False
1346+
else:
1347+
tags = sqlserver_check._config.tags
1348+
for mock_row in mocked_results:
1349+
table_name, schema, database, *metric_values = mock_row
1350+
metrics = zip(table_size_metrics.metric_names()[0], metric_values)
1351+
expected_tags = [
1352+
f'table:{table_name}',
1353+
f'schema:{schema}',
1354+
f'database:{database}',
1355+
] + tags
1356+
# check that the aggregator got the mocked metrics
1357+
for metric_name, metric_value in metrics:
1358+
aggregator.assert_metric(metric_name, value=metric_value, tags=expected_tags)
1359+
1360+
13041361
@pytest.mark.integration
13051362
@pytest.mark.usefixtures('dd_environment')
13061363
@pytest.mark.parametrize('include_database_files_metrics', [True, False])

sqlserver/tests/test_integration.py

Lines changed: 39 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -20,6 +20,7 @@
2020
STATIC_INFO_ENGINE_EDITION,
2121
STATIC_INFO_MAJOR_VERSION,
2222
STATIC_INFO_VERSION,
23+
TABLE_SIZE_METRICS,
2324
)
2425

2526
from .common import (
@@ -452,7 +453,7 @@ def test_check_windows_defaults(aggregator, dd_run_check, init_config, instance_
452453
for mname in EXPECTED_DEFAULT_METRICS + CUSTOM_METRICS:
453454

454455
# These require extra setup to test
455-
if mname not in DATABASE_INDEX_METRICS:
456+
if mname not in DATABASE_INDEX_METRICS and mname not in [m[0] for m in TABLE_SIZE_METRICS]:
456457
aggregator.assert_metric(mname)
457458

458459
aggregator.assert_service_check('sqlserver.can_connect', status=SQLServer.OK)
@@ -486,6 +487,43 @@ def test_index_fragmentation_metrics(aggregator, dd_run_check, instance_docker,
486487
assert 'datadog_test-1' in seen_databases
487488

488489

490+
@pytest.mark.integration
491+
@pytest.mark.usefixtures('dd_environment')
492+
@pytest.mark.parametrize('database_autodiscovery', [True, False])
493+
def test_table_size_metrics(aggregator, dd_run_check, instance_docker, database_autodiscovery):
494+
instance_docker['database_autodiscovery'] = database_autodiscovery
495+
sqlserver_check = SQLServer(CHECK_NAME, {}, [instance_docker])
496+
dd_run_check(sqlserver_check)
497+
seen_databases = set()
498+
for m in aggregator.metrics("sqlserver.table.row_count"):
499+
tags_by_key = dict([t.split(':') for t in m.tags if not t.startswith('dd.internal')])
500+
seen_databases.add(tags_by_key['database'])
501+
assert tags_by_key['table'].lower() != 'none'
502+
assert tags_by_key['schema'].lower() != 'none'
503+
504+
for m in aggregator.metrics("sqlserver.table.data_size"):
505+
tags_by_key = dict([t.split(':') for t in m.tags if not t.startswith('dd.internal')])
506+
seen_databases.add(tags_by_key['database'])
507+
assert tags_by_key['table'].lower() != 'none'
508+
assert tags_by_key['schema'].lower() != 'none'
509+
510+
for m in aggregator.metrics("sqlserver.table.total_size"):
511+
tags_by_key = dict([t.split(':') for t in m.tags if not t.startswith('dd.internal')])
512+
seen_databases.add(tags_by_key['database'])
513+
assert tags_by_key['table'].lower() != 'none'
514+
assert tags_by_key['schema'].lower() != 'none'
515+
516+
for m in aggregator.metrics("sqlserver.table.used_size"):
517+
tags_by_key = dict([t.split(':') for t in m.tags if not t.startswith('dd.internal')])
518+
seen_databases.add(tags_by_key['database'])
519+
assert tags_by_key['table'].lower() != 'none'
520+
assert tags_by_key['schema'].lower() != 'none'
521+
522+
assert 'master' in seen_databases
523+
if database_autodiscovery:
524+
assert 'datadog_test-1' in seen_databases
525+
526+
489527
@pytest.mark.integration
490528
@pytest.mark.usefixtures('dd_environment')
491529
def test_custom_metrics_fraction_counters(aggregator, dd_run_check, instance_docker, caplog):

0 commit comments

Comments
 (0)