Plan guides are some strange things, and can be very high risk. This post does not have the intention to get all you fine people to implement plan guides everywhere, it should be one of the last resort options in your toolkit. You will not directly see the query’s being adapted by it, meaning that troubleshooting this will be way harder. The first part will create some data and some tests before going deeper into it.
CREATE TABLE DBO.TABLE1( ID INT IDENTITY(1,1), VALUE NVARCHAR(255));
CREATE TABLE DBO.TABLE2( ID INT IDENTITY(1,1), TABLE1ID INT, VALUE INT);
SET NOCOUNT ON;
DECLARE @I INT = 1
WHILE @I < 10000
BEGIN
INSERT INTO DBO.TABLE1(VALUE)
VALUES('PLAN GUIDE DEMO')
INSERT INTO DBO.TABLE2(TABLE1ID,VALUE)
VALUES(@I,@I)
INSERT INTO DBO.TABLE2(TABLE1ID,VALUE)
VALUES(5,5)
SET @I += 1
END
--CLUSTERED INDEXES
CREATE CLUSTERED INDEX CX_TABLE1_ID
on dbo.TABLE1(ID)
CREATE CLUSTERED INDEX CX_TABLE2_ID
on dbo.TABLE2(ID)
-- SEEK NC INDEX
CREATE INDEX IX_TABLE2_VALUE_TABLE1ID
on dbo.TABLE2(Value,TABLE1ID)
Query’s our application sends to the server:
EXEC SP_EXECUTESQL N'SELECT * FROM DBO.TABLE1 T1 INNER JOIN DBO.TABLE2 T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3)',N'@P1 int, @P2 int, @P3 int', @P1 = 4, @P2 = 5, @P3=6
Returns 10002 ROWS
EXEC SP_EXECUTESQL N'SELECT * FROM DBO.TABLE1 T1 INNER JOIN DBO.TABLE2 T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3)',N'@P1 int, @P2 int, @P3 int', @P1 = 7, @P2 = 8, @P3=9
– Returns 3 ROWS
Oh-oh, we got parameter sniffing.
EXEC SP_EXECUTESQL N'SELECT * FROM DBO.TABLE1 T1 INNER JOIN DBO.TABLE2 T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3) OPTION(RECOMPILE)',N'@P1 int, @P2 int, @P3 int', @P1 = 4, @P2 = 5, @P3=6
EXEC SP_EXECUTESQL N'SELECT * FROM DBO.TABLE1 T1 INNER JOIN DBO.TABLE2 T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3) OPTION(RECOMPILE)',N'@P1 int, @P2 int, @P3 int', @P1 = 7, @P2 = 8, @P3=9
That’s better
But you can’t alter the application code no matter what, and all the other options where explored.
Remember that you need to create it In the database where the query is executed.
So for example, if a query like this is happening:
USE MASTER
GO
EXEC SP_EXECUTESQL N'SELECT * FROM [MY_TEST].[DBO].[TABLE1] T1 INNER JOIN [MY_TEST].[DBO].[TABLE2] T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3)',N'@P1 int, @P2 int, @P3 int', @P1 = 4, @P2 = 5, @P3=6
EXEC SP_EXECUTESQL N'SELECT * FROM [MY_TEST].[DBO].[TABLE1] T1 INNER JOIN [MY_TEST].[DBO].[TABLE2] T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3)',N'@P1 int, @P2 int, @P3 int', @P1 = 7, @P2 = 8, @P3=9
The plan guide will have to be created in the Master database, unfortunately.
@Name: the name you choose for the plan guide, can be found in sys.plan_guides
@stmt: the whole statement, without the Parameter definition or values. ANY SPACES OR OTHER CHARACTERS HERE WILL MAKE THE PLAN GUIDE INVALID
@Type:
TEMPLATE exists if you for example don’t want to apply FORCED PARAMETERIZATION on all the queries when enabling this at the database level OR VICE VERSA.
You will have to use sp_get_query_template to find the parameterized forms of the query.
@module_or_batch: Can be NULL, or the Object name or the batch text. If it is NULL then and the Type = SQL, the value will be set to the same value in @stmt.
@params = exact parameters used in the query, only for type = SQL or TEMPLATE
@hints= the hints you want to add to the query.
@hints overrides the behavior of the existing options clause, more on that in example 3
sp_create_plan_guide
@name = N'PLAN_GUIDE_DEMO',
@stmt = N'SELECT * FROM DBO.TABLE1 T1 INNER JOIN DBO.TABLE2 T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3)',
@type = N'SQL',
@module_or_batch = NULL,
@params = '@p1 int,@p2 int,@p3 int',
@hints = N'OPTION (RECOMPILE)';
-- IT IS NOT WORKING???
EXEC SP_EXECUTESQL N'SELECT * FROM DBO.TABLE1 T1 INNER JOIN DBO.TABLE2 T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3)',N'@P1 int, @P2 int, @P3 int', @P1 = 4, @P2 = 5, @P3=6
EXEC SP_EXECUTESQL N'SELECT * FROM DBO.TABLE1 T1 INNER JOIN DBO.TABLE2 T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3)',N'@P1 int, @P2 int, @P3 int', @P1 = 7, @P2 = 8, @P3=9
“For plan guides that specify @type = ‘SQL’ or @type = ‘TEMPLATE’ to successfully match a query, the values for batch_text and @parameter_name data_type [,…n ] must be provided in exactly the same format as their counterparts submitted by the application. “
https://docs.microsoft.com/en-us/sql/relational-databases/system-stored-procedures/sp-create-plan-guide-transact-sql?view=sql-server-2017#plan-guide-matching-requirements
First , drop the existing false plan guide:
-- Drop the plan guide
EXEC sp_control_plan_guide N'DROP', N'PLAN_GUIDE_DEMO2';
GO
-- THIS WORKS:
sp_create_plan_guide
@name = N'PLAN_GUIDE_DEMO',
@stmt = N'SELECT * FROM DBO.TABLE1 T1 INNER JOIN DBO.TABLE2 T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3)',
@type = N'SQL',
@module_or_batch = NULL,
@params = '@P1 int, @P2 int, @P3 int', -- THE PARAMETER LIST ALSO NEEDS TO MATCH
@hints = N'OPTION (RECOMPILE)';
EXEC SP_EXECUTESQL N'SELECT * FROM DBO.TABLE1 T1 INNER JOIN DBO.TABLE2 T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3)',N'@P1 int, @P2 int, @P3 int', @P1 = 4, @P2 = 5, @P3=6
EXEC SP_EXECUTESQL N'SELECT * FROM DBO.TABLE1 T1 INNER JOIN DBO.TABLE2 T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3)',N'@P1 int, @P2 int, @P3 int', @P1 = 7, @P2 = 8, @P3=9
Plan 1:
Plan 2:
@hints overrides the behavior of the existing options clause, more on that in example 3
EXEC SP_EXECUTESQL N'SELECT * FROM [MY_TEST].[DBO].[TABLE1] T1 INNER JOIN [MY_TEST].[DBO].[TABLE2] T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3) OPTION(LOOP JOIN)',N'@P1 int, @P2 int, @P3 int', @P1 = 4, @P2 = 5, @P3=6
EXEC SP_EXECUTESQL N'SELECT * FROM [MY_TEST].[DBO].[TABLE1] T1 INNER JOIN [MY_TEST].[DBO].[TABLE2] T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3) OPTION(LOOP JOIN)',N'@P1 int, @P2 int, @P3 int', @P1 = 7, @P2 = 8, @P3=9
– Nested loop join on the entire plan.
Create the plan guide with option(recompile)
sp_create_plan_guide
@name = N'PLAN_GUIDE_DEMO',
@stmt = N'SELECT * FROM [MY_TEST].[DBO].[TABLE1] T1 INNER JOIN [MY_TEST].[DBO].[TABLE2] T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3) OPTION(LOOP JOIN)', -- Hele bovenstaande query.
@type = N'SQL',
@module_or_batch = NULL,
@params = '@P1 int, @P2 int, @P3 int', -- THE PARAMETER LIST ALSO NEEDS TO MATCH
@hints = N'OPTION (RECOMPILE)';
Try again:
EXEC SP_EXECUTESQL N'SELECT * FROM [MY_TEST].[DBO].[TABLE1] T1 INNER JOIN [MY_TEST].[DBO].[TABLE2] T2 ON T1.ID = T2.TABLE1ID WHERE T2.VALUE IN (@P1,@P2,@P3) OPTION(LOOP JOIN)',N'@P1 int, @P2 int, @P3 int', @P1 = 4, @P2 = 5, @P3=6
Bye bye nested loop forcing.
EXEC sp_control_plan_guide N'DROP ALL';
GO
Thanks for reading, and stay tuned for part 2, where I will talk about OBJECT and TEMPLATE TYPES.
© 2023 Kohera
Crafted by
© 2022 Kohera
Crafted by
Cookie | Duration | Description |
---|---|---|
ARRAffinity | session | ARRAffinity cookie is set by Azure app service, and allows the service to choose the right instance established by a user to deliver subsequent requests made by that user. |
ARRAffinitySameSite | session | This cookie is set by Windows Azure cloud, and is used for load balancing to make sure the visitor page requests are routed to the same server in any browsing session. |
cookielawinfo-checkbox-advertisement | 1 year | Set by the GDPR Cookie Consent plugin, this cookie records the user consent for the cookies in the "Advertisement" category. |
cookielawinfo-checkbox-analytics | 11 months | This cookie is set by GDPR Cookie Consent plugin. The cookie is used to store the user consent for the cookies in the category "Analytics". |
cookielawinfo-checkbox-functional | 11 months | The cookie is set by GDPR cookie consent to record the user consent for the cookies in the category "Functional". |
cookielawinfo-checkbox-necessary | 11 months | This cookie is set by GDPR Cookie Consent plugin. The cookies is used to store the user consent for the cookies in the category "Necessary". |
cookielawinfo-checkbox-others | 11 months | This cookie is set by GDPR Cookie Consent plugin. The cookie is used to store the user consent for the cookies in the category "Other. |
cookielawinfo-checkbox-performance | 11 months | This cookie is set by GDPR Cookie Consent plugin. The cookie is used to store the user consent for the cookies in the category "Performance". |
CookieLawInfoConsent | 1 year | CookieYes sets this cookie to record the default button state of the corresponding category and the status of CCPA. It works only in coordination with the primary cookie. |
elementor | never | The website's WordPress theme uses this cookie. It allows the website owner to implement or change the website's content in real-time. |
viewed_cookie_policy | 11 months | The cookie is set by the GDPR Cookie Consent plugin and is used to store whether or not user has consented to the use of cookies. It does not store any personal data. |
Cookie | Duration | Description |
---|---|---|
__cf_bm | 30 minutes | Cloudflare set the cookie to support Cloudflare Bot Management. |
pll_language | 1 year | Polylang sets this cookie to remember the language the user selects when returning to the website and get the language information when unavailable in another way. |
Cookie | Duration | Description |
---|---|---|
_ga | 1 year 1 month 4 days | Google Analytics sets this cookie to calculate visitor, session and campaign data and track site usage for the site's analytics report. The cookie stores information anonymously and assigns a randomly generated number to recognise unique visitors. |
_ga_* | 1 year 1 month 4 days | Google Analytics sets this cookie to store and count page views. |
_gat_gtag_UA_* | 1 minute | Google Analytics sets this cookie to store a unique user ID. |
_gid | 1 day | Google Analytics sets this cookie to store information on how visitors use a website while also creating an analytics report of the website's performance. Some of the collected data includes the number of visitors, their source, and the pages they visit anonymously. |
ai_session | 30 minutes | This is a unique anonymous session identifier cookie set by Microsoft Application Insights software to gather statistical usage and telemetry data for apps built on the Azure cloud platform. |
CONSENT | 2 years | YouTube sets this cookie via embedded YouTube videos and registers anonymous statistical data. |
vuid | 1 year 1 month 4 days | Vimeo installs this cookie to collect tracking information by setting a unique ID to embed videos on the website. |
Cookie | Duration | Description |
---|---|---|
ai_user | 1 year | Microsoft Azure sets this cookie as a unique user identifier cookie, enabling counting of the number of users accessing the application over time. |
VISITOR_INFO1_LIVE | 5 months 27 days | YouTube sets this cookie to measure bandwidth, determining whether the user gets the new or old player interface. |
YSC | session | Youtube sets this cookie to track the views of embedded videos on Youtube pages. |
yt-remote-connected-devices | never | YouTube sets this cookie to store the user's video preferences using embedded YouTube videos. |
yt-remote-device-id | never | YouTube sets this cookie to store the user's video preferences using embedded YouTube videos. |
yt.innertube::nextId | never | YouTube sets this cookie to register a unique ID to store data on what videos from YouTube the user has seen. |
yt.innertube::requests | never | YouTube sets this cookie to register a unique ID to store data on what videos from YouTube the user has seen. |
Cookie | Duration | Description |
---|---|---|
WFESessionId | session | No description available. |