Skip to content

Commit ddfa12c

Browse files
committed
Capture sys.database metrics
Optional capture of user database count, databases added & removed - as part of Databases collection. Using name as the natural key for Databases instead of database_id - which might work better for monitoring contained AGs, database restores and re-creations. Logic added to handle renames. Rename operations, deletes and re-creation captured in DB Options history. Added deleted databases system report. #1532
1 parent c49b69e commit ddfa12c

17 files changed

+789
-438
lines changed

DBADash/DBImporter.cs

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -177,6 +177,10 @@ private void UpgradeDS()
177177
dtDB.Columns.Add("is_temporal_history_retention_enabled", typeof(bool));
178178
dtDB.Columns.Add("is_optimized_locking_on", typeof(bool));
179179
}
180+
if(!dtDB.Columns.Contains("service_broker_guid"))
181+
{
182+
dtDB.Columns.Add("service_broker_guid", typeof(Guid));
183+
}
180184
}
181185
if (data.Tables.Contains("Backups"))
182186
{

DBADash/SQL/SQLDatabases.sql

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -75,6 +75,7 @@
7575
is_memory_optimized_enabled BIT NULL,
7676
is_temporal_history_retention_enabled BIT NULL,
7777
is_optimized_locking_on BIT NULL,
78+
service_broker_guid UNIQUEIDENTIFIER NULL
7879
);
7980

8081
SELECT *
@@ -177,7 +178,8 @@ SELECT name,
177178
is_event_stream_enabled,
178179
is_memory_optimized_enabled,
179180
is_temporal_history_retention_enabled,
180-
is_optimized_locking_on
181+
is_optimized_locking_on,
182+
service_broker_guid
181183
FROM #sysdb
182184

183185
DROP TABLE #sysdb

DBADashDB/DBADashDB.sqlproj

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -838,6 +838,8 @@
838838
<Build Include="dbo\Functions\ParseInstanceMetadata.sql" />
839839
<Build Include="dbo\Functions\GetInstanceMetadataTags.sql" />
840840
<Build Include="dbo\Stored Procedures\InstanceMetadata_Get.sql" />
841+
<Build Include="dbo\Functions\DatabaseSettingsUnpivot_Get.sql" />
842+
<Build Include="dbo\Stored Procedures\DeletedDatabases_Get.sql" />
841843
</ItemGroup>
842844
<ItemGroup>
843845
<PostDeploy Include="Script.PostDeployment1.sql" />

DBADashDB/Script.PostDeployment1.sql

Lines changed: 5 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1977,7 +1977,6 @@ WHERE NOT EXISTS(
19771977
AND C.instance_name = VirtualCounters.instance_name
19781978
)
19791979

1980-
19811980
INSERT INTO dbo.RepositoryMetricsConfig(
19821981
InstanceID,
19831982
MetricName,
@@ -2016,7 +2015,11 @@ FROM (VALUES -- AG aggregate
20162015
-- Slow Queries
20172016
('Abort Count',1,0,'SlowQueries'),
20182017
('Error Count',1,0,'SlowQueries'),
2019-
('Total Queries',1,0,'SlowQueries')
2018+
('Total Queries',1,0,'SlowQueries'),
2019+
-- Databases
2020+
('Count of User Databases',1,0,'Databases'),
2021+
('Databases Created',1,0,'Databases'),
2022+
('Databases Dropped',1,0,'Databases')
20202023
) M(MetricName,IsAggregate,IsEnabled,MetricType)
20212024
WHERE NOT EXISTS(
20222025
SELECT 1

DBADashDB/Script.PreDeployment1.sql

Lines changed: 19 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -52,3 +52,22 @@ BEGIN
5252
SET is_snapshot=0
5353
WHERE is_snapshot IS NULL
5454
END
55+
IF OBJECT_ID('dbo.RepositoryMetricsConfig') IS NOT NULL
56+
BEGIN
57+
IF NOT EXISTS(
58+
SELECT 1
59+
FROM dbo.RepositoryMetricsConfig
60+
WHERE MetricType = 'Databases'
61+
)
62+
BEGIN
63+
UPDATE D1
64+
SET D1.name = CONCAT(LEFT(D1.name,91),' ',NEWID())
65+
FROM dbo.Databases D1
66+
WHERE IsActive=0
67+
AND EXISTS(SELECT 1
68+
FROM dbo.Databases D2
69+
WHERE D1.name = D2.name
70+
AND D2.DatabaseID <> D1.DatabaseID
71+
)
72+
END
73+
END
Lines changed: 158 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,158 @@
1+
CREATE FUNCTION dbo.DatabaseSettingsUnpivot_Get(@InstanceID INT)
2+
RETURNS TABLE
3+
AS
4+
RETURN
5+
WITH DB AS (
6+
SELECT DatabaseID,
7+
CAST(owner_sid AS SQL_VARIANT) AS owner_sid,
8+
CAST(compatibility_level AS SQL_VARIANT) AS compatibility_level,
9+
CAST(collation_name AS SQL_VARIANT) AS collation_name,
10+
CAST(user_access AS SQL_VARIANT) AS user_access,
11+
CAST(is_read_only AS SQL_VARIANT) AS is_read_only,
12+
CAST(is_auto_close_on AS SQL_VARIANT) AS is_auto_close_on,
13+
CAST(is_auto_shrink_on AS SQL_VARIANT) AS is_auto_shrink_on,
14+
CAST(state AS SQL_VARIANT) AS state,
15+
CAST(is_in_standby AS SQL_VARIANT) AS is_in_standby,
16+
CAST(is_cleanly_shutdown AS SQL_VARIANT) AS is_cleanly_shutdown,
17+
CAST(is_supplemental_logging_enabled AS SQL_VARIANT) AS is_supplemental_logging_enabled,
18+
CAST(snapshot_isolation_state AS SQL_VARIANT) AS snapshot_isolation_state,
19+
CAST(is_read_committed_snapshot_on AS SQL_VARIANT) AS is_read_committed_snapshot_on,
20+
CAST(recovery_model AS SQL_VARIANT) AS recovery_model,
21+
CAST(page_verify_option AS SQL_VARIANT) AS page_verify_option,
22+
CAST(is_auto_create_stats_on AS SQL_VARIANT) AS is_auto_create_stats_on,
23+
CAST(is_auto_create_stats_incremental_on AS SQL_VARIANT) AS is_auto_create_stats_incremental_on,
24+
CAST(is_auto_update_stats_on AS SQL_VARIANT) AS is_auto_update_stats_on,
25+
CAST(is_auto_update_stats_async_on AS SQL_VARIANT) AS is_auto_update_stats_async_on,
26+
CAST(is_ansi_null_default_on AS SQL_VARIANT) AS is_ansi_null_default_on,
27+
CAST(is_ansi_nulls_on AS SQL_VARIANT) AS is_ansi_nulls_on,
28+
CAST(is_ansi_padding_on AS SQL_VARIANT) AS is_ansi_padding_on,
29+
CAST(is_ansi_warnings_on AS SQL_VARIANT) AS is_ansi_warnings_on,
30+
CAST(is_arithabort_on AS SQL_VARIANT) AS is_arithabort_on,
31+
CAST(is_concat_null_yields_null_on AS SQL_VARIANT) AS is_concat_null_yields_null_on,
32+
CAST(is_numeric_roundabort_on AS SQL_VARIANT) AS is_numeric_roundabort_on,
33+
CAST(is_quoted_identifier_on AS SQL_VARIANT) AS is_quoted_identifier_on,
34+
CAST(is_recursive_triggers_on AS SQL_VARIANT) AS is_recursive_triggers_on,
35+
CAST(is_cursor_close_on_commit_on AS SQL_VARIANT) AS is_cursor_close_on_commit_on,
36+
CAST(is_local_cursor_default AS SQL_VARIANT) AS is_local_cursor_default,
37+
CAST(is_fulltext_enabled AS SQL_VARIANT) AS is_fulltext_enabled,
38+
CAST(is_trustworthy_on AS SQL_VARIANT) AS is_trustworthy_on,
39+
CAST(is_db_chaining_on AS SQL_VARIANT) AS is_db_chaining_on,
40+
CAST(is_parameterization_forced AS SQL_VARIANT) AS is_parameterization_forced,
41+
CAST(is_master_key_encrypted_by_server AS SQL_VARIANT) AS is_master_key_encrypted_by_server,
42+
CAST(is_query_store_on AS SQL_VARIANT) AS is_query_store_on,
43+
CAST(is_published AS SQL_VARIANT) AS is_published,
44+
CAST(is_subscribed AS SQL_VARIANT) AS is_subscribed,
45+
CAST(is_merge_published AS SQL_VARIANT) AS is_merge_published,
46+
CAST(is_distributor AS SQL_VARIANT) AS is_distributor,
47+
CAST(is_sync_with_backup AS SQL_VARIANT) AS is_sync_with_backup,
48+
CAST(is_broker_enabled AS SQL_VARIANT) AS is_broker_enabled,
49+
CAST(is_date_correlation_on AS SQL_VARIANT) AS is_date_correlation_on,
50+
CAST(is_cdc_enabled AS SQL_VARIANT) AS is_cdc_enabled,
51+
CAST(is_encrypted AS SQL_VARIANT) AS is_encrypted,
52+
CAST(is_honor_broker_priority_on AS SQL_VARIANT) AS is_honor_broker_priority_on,
53+
CAST(replica_id AS SQL_VARIANT) AS replica_id,
54+
CAST(group_database_id AS SQL_VARIANT) AS group_database_id,
55+
CAST(resource_pool_id AS SQL_VARIANT) AS resource_pool_id,
56+
CAST(default_language_lcid AS SQL_VARIANT) AS default_language_lcid,
57+
CAST(default_language_name AS SQL_VARIANT) AS default_language_name,
58+
CAST(default_fulltext_language_lcid AS SQL_VARIANT) AS default_fulltext_language_lcid,
59+
CAST(default_fulltext_language_name AS SQL_VARIANT) AS default_fulltext_language_name,
60+
CAST(is_nested_triggers_on AS SQL_VARIANT) AS is_nested_triggers_on,
61+
CAST(is_transform_noise_words_on AS SQL_VARIANT) AS is_transform_noise_words_on,
62+
CAST(two_digit_year_cutoff AS SQL_VARIANT) AS two_digit_year_cutoff,
63+
CAST(containment AS SQL_VARIANT) AS containment,
64+
CAST(target_recovery_time_in_seconds AS SQL_VARIANT) AS target_recovery_time_in_seconds,
65+
CAST(delayed_durability AS SQL_VARIANT) AS delayed_durability,
66+
CAST(is_memory_optimized_elevate_to_snapshot_on AS SQL_VARIANT) AS is_memory_optimized_elevate_to_snapshot_on,
67+
CAST(is_federation_member AS SQL_VARIANT) AS is_federation_member,
68+
CAST(is_remote_data_archive_enabled AS SQL_VARIANT) AS is_remote_data_archive_enabled,
69+
CAST(is_mixed_page_allocation_on AS SQL_VARIANT) AS is_mixed_page_allocation_on,
70+
CAST(IsActive AS SQL_VARIANT) AS IsActive,
71+
CAST(is_ledger_on AS SQL_VARIANT) AS is_ledger_on,
72+
CAST(catalog_collation_type AS SQL_VARIANT) AS catalog_collation_type,
73+
CAST(is_accelerated_database_recovery_on AS SQL_VARIANT) AS is_accelerated_database_recovery_on,
74+
CAST(is_change_feed_enabled AS SQL_VARIANT) AS is_change_feed_enabled,
75+
CAST(is_event_stream_enabled AS SQL_VARIANT) AS is_event_stream_enabled,
76+
CAST(is_memory_optimized_enabled AS SQL_VARIANT) AS is_memory_optimized_enabled,
77+
CAST(is_temporal_history_retention_enabled AS SQL_VARIANT) AS is_temporal_history_retention_enabled,
78+
CAST(is_optimized_locking_on AS SQL_VARIANT) AS is_optimized_locking_on
79+
FROM dbo.Databases
80+
WHERE InstanceID = @InstanceID
81+
)
82+
SELECT DatabaseID,
83+
Setting,
84+
Value,
85+
CAST(is_in_standby AS BIT) AS is_in_standby
86+
FROM DB
87+
UNPIVOT(Value FOR Setting IN(
88+
owner_sid,
89+
compatibility_level,
90+
collation_name,
91+
user_access,
92+
is_read_only,
93+
is_auto_close_on,
94+
is_auto_shrink_on,
95+
state,
96+
is_cleanly_shutdown,
97+
is_supplemental_logging_enabled,
98+
snapshot_isolation_state,
99+
is_read_committed_snapshot_on,
100+
recovery_model,
101+
page_verify_option,
102+
is_auto_create_stats_on,
103+
is_auto_create_stats_incremental_on,
104+
is_auto_update_stats_on,
105+
is_auto_update_stats_async_on,
106+
is_ansi_null_default_on,
107+
is_ansi_nulls_on,
108+
is_ansi_padding_on,
109+
is_ansi_warnings_on,
110+
is_arithabort_on,
111+
is_concat_null_yields_null_on,
112+
is_numeric_roundabort_on,
113+
is_quoted_identifier_on,
114+
is_recursive_triggers_on,
115+
is_cursor_close_on_commit_on,
116+
is_local_cursor_default,
117+
is_fulltext_enabled,
118+
is_trustworthy_on,
119+
is_db_chaining_on,
120+
is_parameterization_forced,
121+
is_master_key_encrypted_by_server,
122+
is_query_store_on,
123+
is_published,
124+
is_subscribed,
125+
is_merge_published,
126+
is_distributor,
127+
is_sync_with_backup,
128+
is_broker_enabled,
129+
is_date_correlation_on,
130+
is_cdc_enabled,
131+
is_encrypted,
132+
is_honor_broker_priority_on,
133+
replica_id,
134+
group_database_id,
135+
resource_pool_id,
136+
default_language_lcid,
137+
default_language_name,
138+
default_fulltext_language_lcid,
139+
default_fulltext_language_name,
140+
is_nested_triggers_on,
141+
is_transform_noise_words_on,
142+
two_digit_year_cutoff,
143+
containment,
144+
target_recovery_time_in_seconds,
145+
delayed_durability,
146+
is_memory_optimized_elevate_to_snapshot_on,
147+
is_federation_member,
148+
is_remote_data_archive_enabled,
149+
is_mixed_page_allocation_on,
150+
is_ledger_on,
151+
catalog_collation_type,
152+
is_accelerated_database_recovery_on,
153+
is_change_feed_enabled,
154+
is_event_stream_enabled,
155+
is_memory_optimized_enabled,
156+
is_temporal_history_retention_enabled,
157+
is_optimized_locking_on)
158+
) AS upvt

DBADashDB/dbo/Stored Procedures/DBSummary_Get.sql

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@
44
)
55
AS
66
SELECT I.InstanceGroupName AS Instance,
7+
CASE WHEN COUNT(DISTINCT D.InstanceID) = 1 THEN MAX(D.InstanceID) ELSE NULL END AS InstanceID,
78
SUM(CASE WHEN D.page_verify_option<>2 THEN 1 ELSE 0 END) as [Page Verify Not Optimal],
89
SUM(CASE WHEN D.is_auto_close_on =1 THEN 1 ELSE 0 END) as [Auto Close],
910
SUM(CASE WHEN D.is_auto_shrink_on =1 THEN 1 ELSE 0 END) as [Auto Shrink],

0 commit comments

Comments
 (0)