From 1090a5d824186de12a35385179970d8c618dd3f3 Mon Sep 17 00:00:00 2001 From: Aaron Bertrand Date: Thu, 2 Oct 2025 12:26:17 -0400 Subject: [PATCH] Update SQLInstance.Databases.cs The important changes here are for performance, but there are other benefits as well. Looping/cursor to execute DBCC per database is expensive, as are two #temp tables used to hold/pass results. This is pronounced on servers with a large number of databases. The sysadmin requirement of the DBCC call is prohibitive (and as shown in issue 306 means those without sysadmin get 0s). Since 2016 SP2, we've been able to extract VLF information from a single function call instead of looping over DBCC checks. The function only requires VIEW SERVER STATE, which is more likely to be granted in a lot of environments. This commit checks for those lower permissions and, if we are 2016 SP2+, performs a single call that eliminates the cursor, both temp tables, and the sysadmin requirement. If the object check fails (< 2016 SP2), OR the permissions check fails, then they fall through to the existing cursor/#temp table solution. That still may be an issue if permissions are inadequate, but it doesn't deviate from the current behavior (VLFs full of 0s). I also changed the cursor to a cursor variable, which can have better default performance and also doesn't need close/deallocate. --- .../Data/SQL/SQLInstance.Databases.cs | 57 ++++++++++++------- 1 file changed, 37 insertions(+), 20 deletions(-) diff --git a/src/Opserver.Core/Data/SQL/SQLInstance.Databases.cs b/src/Opserver.Core/Data/SQL/SQLInstance.Databases.cs index 59b8f150..70fdd08d 100644 --- a/src/Opserver.Core/Data/SQL/SQLInstance.Databases.cs +++ b/src/Opserver.Core/Data/SQL/SQLInstance.Databases.cs @@ -794,20 +794,39 @@ public class DatabaseVLF : ISQLVersioned public int VLFCount { get; internal set; } internal const string FetchSQL = @" -Create Table #VLFCounts (DatabaseId int, DatabaseName sysname, VLFCount int); -Create Table #vlfTemp ( +IF OBJECT_ID(N'sys.dm_db_log_info') IS NOT NULL + AND HAS_PERMS_BY_NAME(null,null,N'VIEW SERVER STATE') = 1 +BEGIN; + WITH ValidDBs(DatabaseId, DatabaseName) AS + ( + Select db.database_id, db.name From sys.databases db + Left Join sys.database_mirroring m ON db.database_id = m.database_id + Where db.state <> 6 + and ( db.state <> 1 + or ( m.mirroring_role = 2 and m.mirroring_state = 4 ) + ) + ) + SELECT db.DatabaseId, + db.DatabaseName, + VLFCount = COUNT(f.vlf_begin_offset) + FROM ValidDBs AS db + CROSS APPLY sys.dm_db_log_info(db.DatabaseId) AS f + GROUP BY db.DatabaseId, db.DatabaseName; +END +ELSE +BEGIN + Create Table #VLFCounts (DatabaseId int, DatabaseName sysname, VLFCount int); + Create Table #vlfTemp ( RecoveryUnitId int, FileId int, FileSize nvarchar(255), - StartOffset nvarchar(255), - FSeqNo nvarchar(255), + @@ -804,36 +827,35 @@ FSeqNo nvarchar(255), Status int, Parity int, CreateLSN nvarchar(255) -); - -Declare @dbId int, @dbName sysname; -Declare dbs Cursor Local Fast_Forward For ( + ); + Declare @dbId int, @dbName sysname, @dbs cursor; + SET @dbs = Cursor Local Fast_Forward For ( Select db.database_id, db.name From sys.databases db Left Join sys.database_mirroring m ON db.database_id = m.database_id Where db.state <> 6 @@ -815,25 +834,23 @@ Where db.state <> 6 or ( m.mirroring_role = 2 and m.mirroring_state = 4 ) ) ); -Open dbs; -Fetch Next From dbs Into @dbId, @dbName; -While @@FETCH_STATUS = 0 -Begin + Open @dbs; + Fetch Next From @dbs Into @dbId, @dbName; + While @@FETCH_STATUS = 0 + Begin IF IS_SRVROLEMEMBER ('sysadmin') = 1 Insert Into #vlfTemp Exec('DBCC LOGINFO(''' + @dbName + ''') WITH NO_INFOMSGS'); Insert Into #VLFCounts (DatabaseId, DatabaseName, VLFCount) Values (@dbId, @dbName, @@ROWCOUNT); Truncate Table #vlfTemp; - Fetch Next From dbs Into @dbId, @dbName; -End -Close dbs; -Deallocate dbs; - -Select * From #VLFCounts; + Fetch Next From @dbs Into @dbId, @dbName; + End -Drop Table #VLFCounts; -Drop Table #vlfTemp;"; + Select * From #VLFCounts; + Drop Table #VLFCounts; + Drop Table #vlfTemp; +END"; public string GetFetchSQL(in SQLServerEngine e) {