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

Add SQL 2022 RTM PSPO parsing #3176

Merged
merged 4 commits into from
Dec 13, 2022
Merged

Conversation

codykonior
Copy link
Contributor

@codykonior codykonior commented Nov 22, 2022

In SQL 2022 RTM when plan sensitive parameter optimization is in use, the query text for statements will be appended with (at least) one of two strings that contain the ObjectID of the parent stored procedure:

SELECT TOP 10000 *, dbo.UsersByReputation_Function(@Reputation) AS ReputationPlusOne  FROM dbo.Users  WHERE Reputation=@Reputation  ORDER BY DisplayName  OPTION ( PLAN PER VALUE(ObjectID = 1205579333, QueryVariantID = 2, predicate_range([StackOverflow2013].[dbo].[Users].[Reputation] = @Reputation, 100.0, 1000000.0)), USE HINT('DISABLE_TSQL_SCALAR_UDF_INLINING'))

SELECT TOP 10000 *  FROM dbo.Users  WHERE Reputation=@Reputation  ORDER BY DisplayName option (PLAN PER VALUE(ObjectID = 1157579162, QueryVariantID = 2, predicate_range([StackOverflow2013].[dbo].[Users].[Reputation] = @Reputation, 100.0, 1000000.0)))

This PR strips out spaces around quotes and equals and checks the query text for "OPTION(PLAN PER VALUE(ObjectID=", then pulls the corresponding name from the plan cache if it contains the database id and object id.

You can test this on the StackOverflow2013 medium size database. The code below is a modified version of the test code from PSPO: How SQL Server 2022 Tries to Fix Parameter Sniffing

ALTER DATABASE CURRENT SET COMPATIBILITY_LEVEL = 160; /* 2022 */
GO
EXEC DropIndexes;
GO
CREATE INDEX Reputation ON dbo.Users(Reputation)
GO
CREATE OR ALTER PROCEDURE dbo.usp_UsersByReputation
  @Reputation int
AS
SELECT TOP 10000 *
FROM dbo.Users
WHERE Reputation=@Reputation
ORDER BY DisplayName;
GO
/*
This is another silly test procedure that calls a dummy function. This was during testing
to see if PSPO was needed for the functions section of the sp_BlitzCache code, but it
doesn't seem necessary. However it did expose the weird case of having spaces around
parenthesis and equals signs, so I've kept it in as a good test.
*/
CREATE OR ALTER PROCEDURE dbo.usp_UsersByReputation_Function
  @Reputation int
AS
SELECT TOP 10000 *, dbo.UsersByReputation_Function(@Reputation) AS ReputationPlusOne
FROM dbo.Users
WHERE Reputation=@Reputation
ORDER BY DisplayName
OPTION (USE HINT('DISABLE_TSQL_SCALAR_UDF_INLINING'));
GO
CREATE OR ALTER FUNCTION dbo.UsersByReputation_Function (@Reputation INT)
RETURNS INT
AS
BEGIN
		RETURN	((SELECT TOP 1 Reputation FROM dbo.Users) + @Reputation + 1);
END
GO

/* Clear and populate the cache */
DBCC FREEPROCCACHE
GO
EXEC dbo.usp_UsersByReputation @Reputation = 2;
GO 5
EXEC dbo.usp_UsersByReputation_Function @Reputation = 2
GO 5

/* Before */
EXEC dbo.sp_BlitzCache 

image

Then compare the output after applying the PR.

/* After */
EXEC dbo.sp_BlitzCache 

image

@codykonior codykonior changed the title Add SQL 2022 PSPO parsing Add SQL 2022 RTM PSPO parsing Nov 22, 2022
@erikdarlingdata
Copy link
Contributor

@codykonior this looks good -- but can you use TRY_CAST instead of TRY_CONVERT? We've had a number of issues with TRY_CONVERT throwing errors in databases in lower compat levels, that TRY_CAST works fine with.

Copy link
Member

@BrentOzar BrentOzar left a comment

Choose a reason for hiding this comment

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

This is awesome! Thanks for the pull request. Merging into the dev branch, will be in the December release with credit to you in the release notes.

@BrentOzar BrentOzar merged commit 976a44c into BrentOzarULTD:dev Dec 13, 2022
@BrentOzar BrentOzar added this to the 2022-12 Release milestone Dec 13, 2022
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Projects
None yet
Development

Successfully merging this pull request may close these issues.

3 participants