Skip to content

Commit

Permalink
ObjectExecutionStats - replace database_id with database_name
Browse files Browse the repository at this point in the history
This fixes an issue in AzureDB where the database_id/DB_ID might not be consistent. Capturing database_name and using that instead of database_id to join to dbo.Databases.
  • Loading branch information
DavidWiseman committed Sep 15, 2024
1 parent 9a3abce commit 13b866b
Show file tree
Hide file tree
Showing 7 changed files with 137 additions and 62 deletions.
6 changes: 5 additions & 1 deletion DBADash/DBImporter.cs
Original file line number Diff line number Diff line change
Expand Up @@ -280,6 +280,10 @@ private void UpgradeDS()
}
}
}
if (data.Tables.Contains("ObjectExecutionStats") && !data.Tables["ObjectExecutionStats"]!.Columns.Contains("database_name"))
{
data.Tables["ObjectExecutionStats"].TableName = "ObjectExecutionStatsLegacy"; // Call ObjectExecutionStatsLegacy_Upd which will add the database_name column and call ObjectExecutionStats_Upd
}
}

private readonly HashSet<string> tablesToProcess = new()
Expand All @@ -294,7 +298,7 @@ private void UpgradeDS()
"Jobs", "JobHistory", "AvailabilityReplicas", "AvailabilityGroups", "JobSteps",
"DatabaseQueryStoreOptions", "ResourceGovernorConfiguration", "AzureDBResourceGovernance",
"RunningQueries", "QueryText", "QueryPlans", "InternalPerformanceCounters", "MemoryUsage",
"SessionWaits", "IdentityColumns", "RunningJobs", "TableSize", "ServerServices"
"SessionWaits", "IdentityColumns", "RunningJobs", "TableSize", "ServerServices","ObjectExecutionStatsLegacy"
};

public void Update()
Expand Down
3 changes: 3 additions & 0 deletions DBADash/SQL/SQLObjectExecutionStats.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@ BEGIN
SET @SQL = N'
SELECT object_id,
database_id,
' + CASE WHEN @IsAzure=1 THEN 'DB_NAME()' ELSE 'DB_NAME(database_id)' END + 'AS database_name,
ISNULL(OBJECT_NAME(object_id, database_id),''{object_id:'' + CAST(object_id AS SYSNAME) + ''}'') object_name,
total_worker_time,
total_elapsed_time,
Expand All @@ -26,6 +27,7 @@ BEGIN
SET @SQL = @SQL + 'UNION ALL
SELECT object_id,
database_id,
' + CASE WHEN @IsAzure=1 THEN 'DB_NAME()' ELSE 'DB_NAME(database_id)' END + 'AS database_name,
ISNULL(OBJECT_NAME(object_id, database_id),''{object_id:'' + CAST(object_id AS SYSNAME) + ''}'') object_name,
total_worker_time,
total_elapsed_time,
Expand All @@ -46,6 +48,7 @@ BEGIN
SET @SQL = @SQL + 'UNION ALL
SELECT object_id,
database_id,
' + CASE WHEN @IsAzure=1 THEN 'DB_NAME()' ELSE 'DB_NAME(database_id)' END + 'AS database_name,
ISNULL(OBJECT_NAME(object_id, database_id),''{object_id:'' + CAST(object_id AS SYSNAME) + ''}'') object_name,
total_worker_time,
total_elapsed_time,
Expand Down
2 changes: 2 additions & 0 deletions DBADashDB/DBADashDB.sqlproj
Original file line number Diff line number Diff line change
Expand Up @@ -741,6 +741,8 @@
<Build Include="dbo\Tables\ServerServices.sql" />
<Build Include="dbo\User Defined Types\ServerServices.sql" />
<Build Include="dbo\Stored Procedures\ServerServices_Get.sql" />
<Build Include="dbo\Stored Procedures\ObjectExecutionStatsLegacy_Upd.sql" />
<Build Include="dbo\User Defined Types\ObjectExecutionStats.sql" />
</ItemGroup>
<ItemGroup>
<PostDeploy Include="Script.PostDeployment1.sql" />
Expand Down
30 changes: 15 additions & 15 deletions DBADashDB/Staging/Tables/ObjectExecutionStats.sql
Original file line number Diff line number Diff line change
@@ -1,16 +1,16 @@
CREATE TABLE [Staging].[ObjectExecutionStats] (
[InstanceID] INT NOT NULL,
[object_id] INT NOT NULL,
[database_id] INT NOT NULL,
[object_name] NVARCHAR (128) NULL,
[total_worker_time] BIGINT NOT NULL,
[total_elapsed_time] BIGINT NOT NULL,
[total_logical_reads] BIGINT NOT NULL,
[total_logical_writes] BIGINT NOT NULL,
[total_physical_reads] BIGINT NOT NULL,
[cached_time] DATETIME NOT NULL,
[execution_count] BIGINT NOT NULL,
[current_time_utc] DATETIME2 (3) NOT NULL,
CONSTRAINT [PK_Staging_ObjectExecutionStats] PRIMARY KEY CLUSTERED ([InstanceID] ASC, [object_id] ASC, [database_id] ASC, [cached_time] ASC)
CREATE TABLE Staging.ObjectExecutionStats (
InstanceID INT NOT NULL,
object_id INT NOT NULL,
database_id INT NOT NULL,
database_name NVARCHAR(128) NOT NULL CONSTRAINT DF_Staging_ObjectExecutionStats_database_name DEFAULT(CAST(NEWID() AS NVARCHAR(128))),
object_name NVARCHAR(128) NULL,
total_worker_time BIGINT NOT NULL,
total_elapsed_time BIGINT NOT NULL,
total_logical_reads BIGINT NOT NULL,
total_logical_writes BIGINT NOT NULL,
total_physical_reads BIGINT NOT NULL,
cached_time DATETIME NOT NULL,
execution_count BIGINT NOT NULL,
current_time_utc DATETIME2(3) NOT NULL,
CONSTRAINT PK_Staging_ObjectExecutionStats PRIMARY KEY CLUSTERED (InstanceID ASC, object_id ASC, database_name ASC, cached_time ASC)
);

43 changes: 43 additions & 0 deletions DBADashDB/dbo/Stored Procedures/ObjectExecutionStatsLegacy_Upd.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
CREATE PROC dbo.ObjectExecutionStatsLegacy_Upd(
@ObjectExecutionStatsLegacy dbo.ProcStats READONLY,
@InstanceID INT,
@SnapshotDate DATETIME2(3)
)
AS
DECLARE @ObjectExecutionStats dbo.ObjectExecutionStats
INSERT INTO @ObjectExecutionStats(
object_id,
database_id,
database_name,
object_name,
total_worker_time,
total_elapsed_time,
total_logical_reads,
total_logical_writes,
total_physical_reads,
cached_time,
execution_count,
current_time_utc,
type,
schema_name)
SELECT T.object_id,
T.database_id,
D.name,
T.object_name,
T.total_worker_time,
T.total_elapsed_time,
T.total_logical_reads,
T.total_logical_writes,
T.total_physical_reads,
T.cached_time,
T.execution_count,
T.current_time_utc,
T.type,
T.schema_name
FROM @ObjectExecutionStatsLegacy T
JOIN dbo.Databases D ON T.database_id = D.database_id AND D.InstanceID=@InstanceID
WHERE D.IsActive=1

EXEC dbo.ObjectExecutionStats_Upd @ObjectExecutionStats=@ObjectExecutionStats,
@InstanceID = @InstanceID,
@SnapshotDate = @SnapshotDate
99 changes: 53 additions & 46 deletions DBADashDB/dbo/Stored Procedures/ObjectExecutionStats_Upd.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
CREATE PROC dbo.ObjectExecutionStats_Upd(
@ObjectExecutionStats dbo.ProcStats READONLY,
@ObjectExecutionStats dbo.ObjectExecutionStats READONLY,
@InstanceID INT,
@SnapshotDate DATETIME2(3)
)
Expand Down Expand Up @@ -50,7 +50,7 @@ SELECT d.DatabaseID,
t.schema_name,
CAST(1 AS BIT)
FROM @ObjectExecutionStats t
JOIN dbo.Databases d ON t.database_id = d.database_id AND D.InstanceID=@InstanceID
JOIN dbo.Databases d ON t.database_name = d.name AND D.InstanceID=@InstanceID
WHERE D.IsActive=1
AND NOT EXISTS(SELECT 1
FROM dbo.DBObjects O
Expand All @@ -69,7 +69,7 @@ UPDATE O
SET O.IsActive=1,
O.object_id = t.object_id
FROM @ObjectExecutionStats t
JOIN dbo.Databases d ON t.database_id = d.database_id AND D.InstanceID=@InstanceID
JOIN dbo.Databases d ON t.database_name = d.name AND D.InstanceID=@InstanceID
JOIN dbo.DBObjects O ON O.DatabaseID = d.DatabaseID
AND O.ObjectName = t.object_name
AND O.ObjectType = t.type
Expand Down Expand Up @@ -97,7 +97,7 @@ WITH t AS (
END) AS IsCompile
FROM @ObjectExecutionStats a
LEFT JOIN Staging.ObjectExecutionStats b ON a.object_id = b.object_id
AND a.database_id = b.database_id
AND a.database_name = b.database_name
AND a.cached_time = b.cached_time
AND b.InstanceID = @InstanceID
AND a.current_time_utc > b.current_time_utc
Expand All @@ -108,7 +108,7 @@ WITH t AS (
AND a.total_logical_writes>= b.total_logical_writes
AND a.total_physical_reads>= b.total_physical_reads
AND a.execution_count>= b.execution_count
JOIN dbo.Databases d ON a.database_id = d.database_id AND D.InstanceID=@InstanceID
JOIN dbo.Databases d ON a.database_name = d.name AND D.InstanceID=@InstanceID
JOIN dbo.DBObjects O ON a.object_name = O.ObjectName AND a.schema_name = O.SchemaName AND O.DatabaseID = d.DatabaseID AND O.ObjectType = a.type
WHERE D.IsActive=1
AND (a.cached_time> DATEADD(s,-70,a.current_time_utc) OR b.object_id IS NOT NULL) -- recently cached or we can calculate diff from staging table
Expand Down Expand Up @@ -241,50 +241,57 @@ WHERE NOT EXISTS(SELECT 1
DELETE Staging.ObjectExecutionStats WHERE InstanceID=@InstanceID;

WITH T AS (
-- handle infrequent dupes on object_id,cached_time,database_id
SELECT @InstanceID as InstanceID
,[object_id]
,[database_id]
,[object_name]
,[total_worker_time]
,[total_elapsed_time]
,[total_logical_reads]
,[total_logical_writes]
,[total_physical_reads]
,[cached_time]
,[execution_count]
,[current_time_utc],
ROW_NUMBER() OVER(PARTITION BY object_id,cached_time,database_id ORDER BY total_elapsed_time DESC) rnum
FROM @ObjectExecutionStats
-- handle infrequent dupes on object_id,cached_time,database_name
SELECT @InstanceID AS InstanceID,
object_id,
database_id,
database_name,
object_name,
total_worker_time,
total_elapsed_time,
total_logical_reads,
total_logical_writes,
total_physical_reads,
cached_time,
execution_count,
current_time_utc,
ROW_NUMBER() OVER (PARTITION BY object_id,
cached_time,
database_name
ORDER BY total_elapsed_time DESC
) rnum
FROM @ObjectExecutionStats
)
INSERT INTO Staging.ObjectExecutionStats(
InstanceID
,[object_id]
,[database_id]
,[object_name]
,[total_worker_time]
,[total_elapsed_time]
,[total_logical_reads]
,[total_logical_writes]
,[total_physical_reads]
,[cached_time]
,[execution_count]
,[current_time_utc])
SELECT InstanceID
,[object_id]
,[database_id]
,[object_name]
,[total_worker_time]
,[total_elapsed_time]
,[total_logical_reads]
,[total_logical_writes]
,[total_physical_reads]
,[cached_time]
,[execution_count]
,[current_time_utc]
InstanceID,
object_id,
database_id,
database_name,
object_name,
total_worker_time,
total_elapsed_time,
total_logical_reads,
total_logical_writes,
total_physical_reads,
cached_time,
execution_count,
current_time_utc
)
SELECT T.InstanceID,
object_id,
database_id,
database_name,
object_name,
total_worker_time,
total_elapsed_time,
total_logical_reads,
total_logical_writes,
total_physical_reads,
cached_time,
execution_count,
current_time_utc
FROM T
WHERE rnum=1;

WHERE T.rnum = 1;

EXEC dbo.CollectionDates_Upd @InstanceID = @InstanceID,
@Reference = @Ref,
Expand Down
16 changes: 16 additions & 0 deletions DBADashDB/dbo/User Defined Types/ObjectExecutionStats.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
CREATE TYPE dbo.ObjectExecutionStats AS TABLE (
object_id INT NOT NULL,
database_id INT NOT NULL,
database_name NVARCHAR(128) NULL,
object_name NVARCHAR(128) NULL,
total_worker_time BIGINT NOT NULL,
total_elapsed_time BIGINT NOT NULL,
total_logical_reads BIGINT NOT NULL,
total_logical_writes BIGINT NOT NULL,
total_physical_reads BIGINT NOT NULL,
cached_time DATETIME NULL,
execution_count BIGINT NOT NULL,
current_time_utc DATETIME2(3) NOT NULL,
type CHAR(2) NULL,
schema_name NVARCHAR(128) NULL
);

0 comments on commit 13b866b

Please sign in to comment.