For our event SQL Server 2016 in September, I am studying the new functionality Query Store.
My colleague David Barbarin have written few months ago about Query Store and how it’s working.
Simple SELECT Query
To begin, I execute a simple SELECT on a table with 3 different methods:
1 2 3 | SELECT * FROM QS_test; exec sp_executesql N 'SELECT * FROM QS_test' EXEC sp_GetQS_test; |
The “sp_GetQS_test” is a stored procedure with the select statement.
I created a little query with specific DMVs for Query Store to analyze the query:
1 2 3 4 5 6 7 8 9 | SELECT qsqt.query_text_id,qsqt.query_sql_text,qsq.query_id,qsq.query_hash, qsq.query_parameterization_type_desc,qsq.initial_compile_start_time, qsq.last_compile_start_time,qsq.last_execution_time,qsq.avg_compile_duration, qsp.query_id,qsp.plan_id,qsrs.execution_type_desc FROM sys.query_store_query_text qsqt inner join sys.query_store_query qsq on qsq.query_text_id=qsqt.query_text_id inner join sys.query_store_plan qsp on qsp.query_id=qsq.query_id inner join sys.query_store_runtime_stats qsrs on qsrs.plan_id=qsp.plan_id WHERE query_sql_text= 'SELECT * FROM QS_test' ; |
As you can see in the result, all 3 queries are present with the same query text (‘SELECT * FROM QS_test’) in the query store.
SELECT Query with a Where clause
I continue my test with a select and a where clause:
1 | SELECT * FROM QS_test WHERE rid=5 |
I run my query to find the query in the query store:
And, Oh surprise, no query found! The query does not appear in the query store….
I rerun my query without the where clause to see if I find something:
The result give me a query written differently:
(@1 tinyint)SELECT * FROM [QS_test] WHERE [rid]=@1
This query goes through a parametrization and to retrieve this information we use a new function in SQL Server 2016: fn_stmt_sql_handle_from_sql_stmt
Function sys.fn_stmt_sql_handle_from_sql_stmt
This function give us the SQL handle for the query
After, I add the function in my query to find it in the Query Store:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 | SELECT qsqt.query_text_id,qsqt.query_sql_text,qsq.query_id,qsq.query_hash, qsq.query_parameterization_type_desc,qsq.initial_compile_start_time,qsq.last_compile_start_time, qsq.last_execution_time,qsq.avg_compile_duration,qsp.query_id,qsp.plan_id,qsrs.execution_type_desc FROM sys.query_store_query_text qsqt inner join sys.query_store_query qsq on qsq.query_text_id=qsqt.query_text_id inner join sys.query_store_plan qsp on qsp.query_id=qsq.query_id inner join sys.query_store_runtime_stats qsrs on qsrs.plan_id=qsp.plan_id CROSS APPLY sys.fn_stmt_sql_handle_from_sql_stmt( 'SELECT * FROM QS_test WHERE rid=5' , NULL ) fsshfss WHERE qsqt.statement_sql_handle=fsshfss.statement_sql_handle; |
It’s done, I retrieve the query thanks to this new function.
You can notice that I use the statement_sql_handle column and not the query_sql_text column in the clause where.
I have tested with query_sql_text column and you can see here the error that I get…
The query_sql_text from the function is SQL_Latin1_General_CP1_CI_AS and both my database and my instance are using French_CI_AS. This is not hopeless…
Then, if you want to use the query with query_sql_text, you just need just to precise the collation with the keyword COLLATE