Query Store, Plan Forcing and Table Variables

This weekend I was in Stockholm in Sweden, talking Query Store and plan forcing with Steinar Anderson, when he mentioned the problems he had while forcing plans that had table variables in them.

Don’t panic. Of course you can force a plan with a table variable, most of the time. Steinar had a fairly focused problem. Before I go on to explain the issue, let me be really clear, Steinar figured out the issue all on his own. When he outlined the problem, I saw immediately what his conclusion was going to be. What’s spurring this blog post is that Steinar said he’d searched on the internet and no one had talked about the issue yet. So, let’s talk about it.

Plan Forcing With Table Variables

First up, let’s show that plan forcing does, in fact, work with table variables. Here’s a simple query using a table variable:

DECLARE @MyTableVar TABLE
(
    City VARCHAR(50)
);

INSERT INTO @MyTableVar
(
    City
)
VALUES
('London' -- City - varchar(50)
    );

SELECT a.AddressID,
       a.AddressLine1,
       a.City,
       sp.Name
FROM Person.Address AS a
    JOIN @MyTableVar AS mtv
        ON a.City = mtv.City
    JOIN Person.StateProvince AS sp
        ON sp.StateProvinceID = a.StateProvinceID;

We can retrieve the query and plan ids from the Query Store and force them:

DECLARE @QueryId INT,
        @PlanID INT;

SELECT @QueryId = qsq.query_id,
       @PlanID = qsp.plan_id
FROM sys.query_store_query AS qsq
    JOIN sys.query_store_query_text AS qsqt
        ON qsqt.query_text_id = qsq.query_text_id
    JOIN sys.query_store_plan AS qsp
        ON qsp.query_id = qsq.query_id
WHERE qsqt.query_sql_text LIKE 'SELECT a.AddressID,%';

EXEC sys.sp_query_store_force_plan @QueryId, @PlanID;

NOTE: I can only do this because I’m working from a clear Query Store. If you’ve run other queries that start with ‘SELECT a.AddressID,’ then this won’t work and you have to get more specific.

Regardless, if we then re-run the original script and then either look at the properties for the first operator of the plan (which will show Use Plan = True), or we query the query store, we can tell that the plan forcing worked with a table variable. Here’s the code that can tell you:

SELECT query_id,
       plan_id,
       is_forced_plan,
       force_failure_count,
       last_force_failure_reason_desc
FROM sys.query_store_plan
WHERE is_forced_plan = 1;

The output on my system looked like this:

So, where does the problem come up?

Failed Plan Forcing

We’re going to modify the original script, just a little. I’m going to make the column in the table variable a primary key as follows:

DECLARE @MyTableVar TABLE
(
    City VARCHAR(50) PRIMARY KEY
);

INSERT INTO @MyTableVar
(
    City
)
VALUES
('London' -- City - varchar(50)
    );

SELECT a.AddressID,
       a.AddressLine1,
       a.City,
       sp.Name
FROM Person.Address AS a
    JOIN @MyTableVar AS mtv
        ON a.City = mtv.City
    JOIN Person.StateProvince AS sp
        ON sp.StateProvinceID = a.StateProvinceID;

Now, I need to look at the query store to identify if a new query has been created, a new plan, or what, so we’ll modify the other query too:

SELECT qsq.query_id,
       qsq.query_hash,
       CAST(qsp.query_plan AS XML) AS QueryPlan,
	   qsp.plan_id,
	   qsp.query_plan_hash,
       qsqt.query_sql_text
FROM sys.query_store_query AS qsq
    JOIN sys.query_store_plan AS qsp
        ON qsp.query_id = qsq.query_id
    JOIN sys.query_store_query_text AS qsqt
        ON qsqt.query_text_id = qsq.query_text_id
WHERE qsqt.query_sql_text LIKE 'SELECT a.AddressID,%';

The results are as follows:

You can see that, although we haven’t, in any way, modified the query in question, the Query Store thinks it has a new query and a new plan. I’ll explain why in a minute. First, let’s try forcing the plan:

EXEC sys.sp_query_store_force_plan 7,2;

With that in place, let’s rerun the query with the primary key and then check Query Store to see if the plan was forced successfully or not:

Ooops! The plan forcing failed and the reason is NO_INDEX. But that can’t be right. We created the primary key. It’s right there in the script. However, notice that we’re relying on default names for the primary key. That gets generated, new, each time taht table variable is created. Meaning, you can’t force the plan because the plan you’re attempting to force is invalid because it has a different primary key.

Conclusion

Steinar is explaining this to me and I suddenly say, “But you’re going to get a different key name.” Steinar just smiled. Yeah, he was way ahead of me. Any way, one of the keys to successfully using plan forcing is the understanding that you can only force a valid plan. Changes to object names, like using default key names, will lead to failures like this.


If you want to learn more about Query Store, I have some upcoming events. You only have another week to get signed up in Poland, so get on that:

SQL Day, May 13, 2019, Wroclaw, Poland
SQLSaturday Columbus Precon, June 7 2019, Columbus OH

2 thoughts on “Query Store, Plan Forcing and Table Variables

Please let me know what you think about this article or any questions:

This site uses Akismet to reduce spam. Learn how your comment data is processed.