Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

#293 Support for @OutputServerName in sp_BlitzCache #419

Closed
wants to merge 4 commits into from
Closed
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
288 changes: 195 additions & 93 deletions sp_BlitzCache.sql
Original file line number Diff line number Diff line change
Expand Up @@ -191,7 +191,8 @@ Known limitations of this version:
excluded by default.
- @IgnoreQueryHashes and @OnlyQueryHashes require a CSV list of hashes
with no spaces between the hash values.
- @OutputServerName is not functional yet.
- @OutputServerName is functional, but query plans will return as NVARCHAR(MAX)
rather than XML, and the summary table will not be stored.

Unknown limitations of this version:
- May or may not be vulnerable to the wick effect.
Expand Down Expand Up @@ -794,7 +795,8 @@ IF @SortOrder NOT IN ('cpu', 'avg cpu', 'reads', 'avg reads', 'writes', 'avg wri
'compiles', 'memory grant', 'avg memory grant')
SET @SortOrder = 'cpu';

SELECT @OutputDatabaseName = QUOTENAME(@OutputDatabaseName),
SELECT @OutputServerName = QUOTENAME(@OutputServerName),
@OutputDatabaseName = QUOTENAME(@OutputDatabaseName),
@OutputSchemaName = QUOTENAME(@OutputSchemaName),
@OutputTableName = QUOTENAME(@OutputTableName);

Expand Down Expand Up @@ -2096,9 +2098,59 @@ SET Warnings = SUBSTRING(


Results:
IF @OutputDatabaseName IS NOT NULL
AND @OutputSchemaName IS NOT NULL
AND @OutputTableName IS NOT NULL
/* Checks if @OutputServerName is populated with a valid linked server, and that the database name specified is valid */
DECLARE @ValidOutputServer BIT
DECLARE @ValidOutputLocation BIT
DECLARE @LinkedServerDBCheck NVARCHAR(2000)
DECLARE @ValidLinkedServerDB INT
DECLARE @tmpdbchk table (cnt int)
IF @OutputServerName IS NOT NULL
BEGIN
IF EXISTS (SELECT server_id FROM sys.servers WHERE QUOTENAME([name]) = @OutputServerName)
BEGIN
SET @LinkedServerDBCheck = 'SELECT 1 WHERE EXISTS (SELECT * FROM '+@OutputServerName+'.master.sys.databases WHERE QUOTENAME([name]) = '''+@OutputDatabaseName+''')'
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Does this work if someone only has permissions to a single database, but not to master.sys.databases? I think generally in linked server situations, the cross-server account users don't have a lot of permissions.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

As long as they are in the Public role it should be fine. If the DBA/Vendor has removed all of the precreated roles for their own, the linked server account needs to have VIEW ANY DATABASE permission.

From the docs on sys.databases:

By default, the public role has the VIEW ANY DATABASE permission, allowing all logins to see database information. To block a login from the ability to detect a database, REVOKE the VIEW ANY DATABASE permission from public, or DENY the VIEW ANY DATABASE permission for individual logins.

INSERT INTO @tmpdbchk EXEC sys.sp_executesql @LinkedServerDBCheck
SET @ValidLinkedServerDB = (SELECT COUNT(*) FROM @tmpdbchk)
IF (@ValidLinkedServerDB > 0)
BEGIN
SET @ValidOutputServer = 1
SET @ValidOutputLocation = 1
END
ELSE
RAISERROR('The specified database was not found on the output server', 16, 0)
END
ELSE
BEGIN
RAISERROR('The specified output server was not found', 16, 0)
END
END
ELSE
BEGIN
IF @OutputDatabaseName IS NOT NULL
AND @OutputSchemaName IS NOT NULL
AND @OutputTableName IS NOT NULL
AND EXISTS ( SELECT *
FROM sys.databases
WHERE QUOTENAME([name]) = @OutputDatabaseName)
BEGIN
SET @ValidOutputLocation = 1
END
ELSE IF @OutputDatabaseName IS NOT NULL
AND @OutputSchemaName IS NOT NULL
AND @OutputTableName IS NOT NULL
AND NOT EXISTS ( SELECT *
FROM sys.databases
WHERE QUOTENAME([name]) = @OutputDatabaseName)
BEGIN
RAISERROR('The specified output database was not found on this server', 16, 0)
END
ELSE
BEGIN
SET @ValidOutputLocation = 0
END
END

IF @ValidOutputLocation = 1
BEGIN
RAISERROR('Writing results to table.', 0, 1) WITH NOWAIT;

Expand All @@ -2119,42 +2171,42 @@ BEGIN
+ @OutputSchemaName + '.'
+ @OutputTableName
+ N'(ID bigint NOT NULL IDENTITY(1,1),
ServerName nvarchar(256),
ServerName NVARCHAR(256),
CheckDate DATETIMEOFFSET,
Version nvarchar(256),
QueryType nvarchar(256),
Warnings varchar(max),
Version NVARCHAR(256),
QueryType NVARCHAR(256),
Warnings varchar(MAX),
DatabaseName sysname,
SerialDesiredMemory float,
SerialRequiredMemory float,
AverageCPU bigint,
TotalCPU bigint,
PercentCPUByType money,
CPUWeight money,
AverageDuration bigint,
TotalDuration bigint,
DurationWeight money,
PercentDurationByType money,
AverageReads bigint,
TotalReads bigint,
ReadWeight money,
PercentReadsByType money,
AverageWrites bigint,
TotalWrites bigint,
WriteWeight money,
PercentWritesByType money,
ExecutionCount bigint,
ExecutionWeight money,
PercentExecutionsByType money,' + N'
ExecutionsPerMinute money,
PlanCreationTime datetime,
LastExecutionTime datetime,
PlanHandle varbinary(64),
SerialDesiredMemory FLOAT,
SerialRequiredMemory FLOAT,
AverageCPU BIGINT,
TotalCPU BIGINT,
PercentCPUByType MONEY,
CPUWeight MONEY,
AverageDuration BIGINT,
TotalDuration BIGINT,
DurationWeight MONEY,
PercentDurationByType MONEY,
AverageReads BIGINT,
TotalReads BIGINT,
ReadWeight MONEY,
PercentReadsByType MONEY,
AverageWrites BIGINT,
TotalWrites BIGINT,
WriteWeight MONEY,
PercentWritesByType MONEY,
ExecutionCount BIGINT,
ExecutionWeight MONEY,
PercentExecutionsByType MONEY,' + N'
ExecutionsPerMinute MONEY,
PlanCreationTime DATETIME,
LastExecutionTime DATETIME,
PlanHandle VARBINARY(64),
[Remove Plan Handle From Cache] AS
CASE WHEN [PlanHandle] IS NOT NULL
THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [PlanHandle], 1) + '');''
ELSE ''N/A'' END,
SqlHandle varbinary(64),
SqlHandle VARBINARY(64),
[Remove SQL Handle From Cache] AS
CASE WHEN [SqlHandle] IS NOT NULL
THEN ''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [SqlHandle], 1) + '');''
Expand All @@ -2163,72 +2215,122 @@ BEGIN
CASE WHEN [SqlHandle] IS NOT NULL
THEN ''EXEC sp_BlitzCache @OnlySqlHandles = '''''' + CONVERT(VARCHAR(128), [SqlHandle], 1) + ''''''; ''
ELSE ''N/A'' END,
QueryHash binary(8),
QueryHash BINARY(8),
[Query Hash More Info] AS
CASE WHEN [QueryHash] IS NOT NULL
THEN ''EXEC sp_BlitzCache @OnlyQueryHashes = '''''' + CONVERT(VARCHAR(32), [QueryHash], 1) + ''''''; ''
ELSE ''N/A'' END,
QueryPlanHash binary(8),
StatementStartOffset int,
StatementEndOffset int,
MinReturnedRows bigint,
MaxReturnedRows bigint,
AverageReturnedRows money,
TotalReturnedRows bigint,
QueryText nvarchar(max),
QueryPlan xml,
NumberOfPlans int,
NumberOfDistinctPlans int,
MinGrantKB BIGINT,
MaxGrantKB BIGINT,
MinUsedGrantKB BIGINT,
MaxUsedGrantKB BIGINT,
PercentMemoryGrantUsed MONEY,
AvgMaxMemoryGrant MONEY,
QueryPlanHash BINARY(8),
StatementStartOffset INT,
StatementEndOffset INT,
MinReturnedRows BIGINT,
MAXReturnedRows BIGINT,
AverageReturnedRows MONEY,
TotalReturnedRows BIGINT,
QueryText NVARCHAR(MAX),
QueryPlan XML,
NumberOfPlans INT,
NumberOfDistinctPlans INT,
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Uh oh - looks like maybe this was started from an older version, and it didn't have all of the current fields. Can you add the ones from lines 2182-2187 in the last version, and test that?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Sure thing!

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

OK, just update the issue when that code has been added. (Just went in and checked and it still wasn't there, so noting in here in case you were missing that.)

CONSTRAINT [PK_' +CAST(NEWID() AS NCHAR(36)) + '] PRIMARY KEY CLUSTERED(ID))';

EXEC sp_executesql @insert_sql ;


SET @insert_sql =N' IF EXISTS(SELECT * FROM '
+ @OutputDatabaseName
+ N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = '''
+ @OutputSchemaName + N''') '
+ 'INSERT '
+ @OutputDatabaseName + '.'
+ @OutputSchemaName + '.'
+ @OutputTableName
+ N' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, '
+ N' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, '
+ N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, '
+ N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant) '
+ N'SELECT TOP (@Top) '
+ QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), N'''') + N', SYSDATETIMEOFFSET(),'
+ QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') AS NVARCHAR(128)), N'''') + ', '
+ N' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, '
+ N' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, '
+ N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, '
+ N' SerialRequiredMemory, SerialDesiredMemory, MinGrantKB, MaxGrantKB, MinUsedGrantKB, MaxUsedGrantKB, PercentMemoryGrantUsed, AvgMaxMemoryGrant '
+ N' FROM ##bou_BlitzCacheProcs '
IF @ValidOutputServer = 1
BEGIN
SET @insert_sql = REPLACE(@insert_sql,''''+@OutputSchemaName+'''',''''''+@OutputSchemaName+'''''')
SET @insert_sql = REPLACE(@insert_sql,''''+@OutputTableName+'''',''''''+@OutputTableName+'''''')
SET @insert_sql = REPLACE(@insert_sql,'''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [PlanHandle], 1) + '');''','''''DBCC FREEPROCCACHE ('''' + QUOTENAME(CONVERT(VARCHAR(128), [PlanHandle], 1), CHAR(39)) + '''');''''')
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Dumb question - what are we search/replacing this part for? (I'm guessing you found something neat during testing, but if there's an easier way to fix it than doing search/replace, I'm totally down with that - replacing in long strings can be pretty slow.)

Copy link
Contributor Author

@hariscodes hariscodes Sep 29, 2016

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Since I have to use sp_executesql on the other box:

EXEC('EXEC('''+@insert_sql+''') AT ' + @OutputServerName);

...I end up needing extra single-quotes in the dynamic SQL string to make it function.

For the Plan Handles and the Query Hashes, it's the same problem. Without the correct number of single-quotes I end up inserting Plan Handle/Query Hash with a pair of single quotes around it into the output table rather than the code itself.

EDIT: Was using brain upside down when I wrote this the first time...

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I should also note that I did it this way for code reuse; and that performance was never an issue here since the insert_sql string is not insanely long or anything. If we were updating a ton of strings it would probably be an issue though.

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Nah, you don't want to do that - let's not try to execute SQL on other servers. (I can see that being a security nightmare.)

SET @insert_sql = REPLACE(@insert_sql,'''DBCC FREEPROCCACHE ('' + CONVERT(VARCHAR(128), [SqlHandle], 1) + '');''','''''DBCC FREEPROCCACHE ('''' + QUOTENAME(CONVERT(VARCHAR(128), [SqlHandle], 1), CHAR(39)) + '''');''''')
SET @insert_sql = REPLACE(@insert_sql,'''EXEC sp_BlitzCache @OnlySqlHandles = '''''' + CONVERT(VARCHAR(128), [SqlHandle], 1) + ''''''; ''','''''EXEC sp_BlitzCache @OnlySqlHandles = '''' + QUOTENAME(CONVERT(VARCHAR(128), [SqlHandle], 1), CHAR(39)) + ''''; ''''')
SET @insert_sql = REPLACE(@insert_sql,'''EXEC sp_BlitzCache @OnlyQueryHashes = '''''' + CONVERT(VARCHAR(32), [QueryHash], 1) + ''''''; ''','''''EXEC sp_BlitzCache @OnlyQueryHashes = '''' + QUOTENAME(CONVERT(VARCHAR(32), [QueryHash], 1), CHAR(39)) + ''''; ''''')
SET @insert_sql = REPLACE(@insert_sql,'N/A','''N/A''')
SET @insert_sql = REPLACE(@insert_sql,'XML','[NVARCHAR](MAX)')
EXEC('EXEC('''+@insert_sql+''') AT ' + @OutputServerName);
END
ELSE
BEGIN
EXEC sp_executesql @insert_sql;
END

IF @ValidOutputServer = 1
BEGIN
SET @insert_sql =N' IF EXISTS(SELECT * FROM '
+ @OutputServerName + '.'
+ @OutputDatabaseName
+ N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = '''
+ @OutputSchemaName + N''') '
+ 'INSERT '
+ @OutputServerName + '.'
+ @OutputDatabaseName + '.'
+ @OutputSchemaName + '.'
+ @OutputTableName
+ N' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, '
+ N' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, '
+ N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, '
+ N' SerialRequiredMemory, SerialDesiredMemory) '
+ N'SELECT TOP '+CONVERT(VARCHAR,@Top)+' '
+ QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), N'''') + N', SYSDATETIMEOFFSET(),'
+ QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') as nvarchar(128)), N'''') + ', '
+ N' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, '
+ N' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, '
+ N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, CONVERT(NVARCHAR(MAX),QueryPlan), NumberOfPlans, NumberOfDistinctPlans, Warnings, '
+ N' SerialRequiredMemory, SerialDesiredMemory '
+ N' FROM ##bou_BlitzCacheProcs '

SELECT @insert_sql += N' ORDER BY ' + CASE @SortOrder WHEN 'cpu' THEN N' TotalCPU '
WHEN 'reads' THEN N' TotalReads '
WHEN 'writes' THEN N' TotalWrites '
WHEN 'duration' THEN N' TotalDuration '
WHEN 'executions' THEN N' ExecutionCount '
WHEN 'compiles' THEN N' PlanCreationTime '
WHEN 'memory grant' THEN N' MaxGrantKB'
WHEN 'avg cpu' THEN N' AverageCPU'
WHEN 'avg reads' THEN N' AverageReads'
WHEN 'avg writes' THEN N' AverageWrites'
WHEN 'avg duration' THEN N' AverageDuration'
WHEN 'avg executions' THEN N' ExecutionsPerMinute'
WHEN 'avg memory grant' THEN N' AvgMaxMemoryGrant'
END + N' DESC '

SET @insert_sql += N' OPTION (RECOMPILE) ; '
SELECT @insert_sql += N' ORDER BY ' + CASE @SortOrder WHEN 'cpu' THEN ' TotalCPU '
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Should we still be doing an order by in the insert, come to think of it?

WHEN 'reads' THEN ' TotalReads '
WHEN 'writes' THEN ' TotalWrites '
WHEN 'duration' THEN ' TotalDuration '
WHEN 'executions' THEN ' ExecutionCount '
WHEN 'compiles' THEN ' PlanCreationTime '
WHEN 'avg cpu' THEN 'AverageCPU'
WHEN 'avg reads' THEN 'AverageReads'
WHEN 'avg writes' THEN 'AverageWrites'
WHEN 'avg duration' THEN 'AverageDuration'
WHEN 'avg executions' THEN 'ExecutionsPerMinute'
END + N' DESC '


EXEC sp_executesql @insert_sql, N'@Top INT', @Top;
END
ELSE
BEGIN
SET @insert_sql =N' IF EXISTS(SELECT * FROM '
+ @OutputDatabaseName
+ N'.INFORMATION_SCHEMA.SCHEMATA WHERE QUOTENAME(SCHEMA_NAME) = '''
+ @OutputSchemaName + N''') '
+ 'INSERT '
+ @OutputDatabaseName + '.'
+ @OutputSchemaName + '.'
+ @OutputTableName
+ N' (ServerName, CheckDate, Version, QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, CPUWeight, AverageDuration, TotalDuration, DurationWeight, PercentDurationByType, AverageReads, TotalReads, ReadWeight, PercentReadsByType, '
+ N' AverageWrites, TotalWrites, WriteWeight, PercentWritesByType, ExecutionCount, ExecutionWeight, PercentExecutionsByType, '
+ N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, '
+ N' SerialRequiredMemory, SerialDesiredMemory) '
+ N'SELECT TOP (@Top) '
+ QUOTENAME(CAST(SERVERPROPERTY('ServerName') AS NVARCHAR(128)), N'''') + N', SYSDATETIMEOFFSET(),'
+ QUOTENAME(CAST(SERVERPROPERTY('ProductVersion') as nvarchar(128)), N'''') + ', '
+ N' QueryType, DatabaseName, AverageCPU, TotalCPU, PercentCPUByType, PercentCPU, AverageDuration, TotalDuration, PercentDuration, PercentDurationByType, AverageReads, TotalReads, PercentReads, PercentReadsByType, '
+ N' AverageWrites, TotalWrites, PercentWrites, PercentWritesByType, ExecutionCount, PercentExecutions, PercentExecutionsByType, '
+ N' ExecutionsPerMinute, PlanCreationTime, LastExecutionTime, PlanHandle, SqlHandle, QueryHash, StatementStartOffset, StatementEndOffset, MinReturnedRows, MaxReturnedRows, AverageReturnedRows, TotalReturnedRows, QueryText, QueryPlan, NumberOfPlans, NumberOfDistinctPlans, Warnings, '
+ N' SerialRequiredMemory, SerialDesiredMemory '
+ N' FROM ##bou_BlitzCacheProcs '

SELECT @insert_sql += N' ORDER BY ' + CASE @SortOrder WHEN 'cpu' THEN ' TotalCPU '
WHEN 'reads' THEN ' TotalReads '
WHEN 'writes' THEN ' TotalWrites '
WHEN 'duration' THEN ' TotalDuration '
WHEN 'executions' THEN ' ExecutionCount '
WHEN 'compiles' THEN ' PlanCreationTime '
WHEN 'avg cpu' THEN 'AverageCPU'
WHEN 'avg reads' THEN 'AverageReads'
WHEN 'avg writes' THEN 'AverageWrites'
WHEN 'avg duration' THEN 'AverageDuration'
WHEN 'avg executions' THEN 'ExecutionsPerMinute'
END + N' DESC '

SET @insert_sql += N' OPTION (RECOMPILE) ; '

EXEC sp_executesql @insert_sql, N'@Top INT', @Top;
EXEC sp_executesql @insert_sql, N'@Top INT', @Top;
END

RETURN
END
Expand Down