When I was writing my post Capture the most expensive queries across your SQL Server using Query Store a question crossed my mind:
Query Store is a configuration that is enabled per database, and the plans and stats for queries executed in that database are stored in the database itself. So what does query store do when a query spans more than one database?
Does it record the execution stats in all databases involved or does it store them in one based on some criteria (e.g. the one where the most work occurs)? Or does it somehow proportion them out between the databases?
This was relevant as it crossed my mind that if it records them in multiple database then my query in the above post could be double counting.
Time to test and find out.
I created three databases, Fred, Bert and Ernie. Then a table called Fred in database Fred, and a table called Bert in database Bert. In table Fred I created a bunch of records, then in table Bert I created a much bigger bunch of records:
DROP DATABASE IF EXISTS Fred; DROP DATABASE IF EXISTS Bert; DROP DATABASE IF EXISTS Ernie; CREATE DATABASE Fred; CREATE DATABASE Bert; CREATE DATABASE Ernie; USE Fred; CREATE TABLE dbo.Fred(Id INT IDENTITY(1,1) PRIMARY KEY CLUSTERED, FredText NVARCHAR(500)); INSERT INTO dbo.Fred(FredText) SELECT a.name + b.name FROM sys.objects a, sys.objects b; USE Bert; CREATE TABLE dbo.Bert(Id INT IDENTITY(1,1) PRIMARY KEY CLUSTERED, BertText NVARCHAR(500)); INSERT INTO dbo.Bert(BertText) SELECT a.name + b.name + c.name FROM sys.objects a, sys.objects b, sys.objects c;
Then I turned on Query Store for all three databases:
USE MASTER; ALTER DATABASE Fred SET query_store = ON; ALTER DATABASE Bert SET query_store = ON; ALTER DATABASE Ernie SET query_store = ON;
Once that was done I concocted a horrible query that was bound to be horrendously slow – so I knew it would be easy to find when I queried the Query Store runtime stats:
SET STATISTICS IO ON SELECT TOP 100000 * FROM Fred.dbo.Fred f INNER JOIN Bert.dbo.Bert b ON b.BertText LIKE '%' + f.FredText + '%';
I turned STATISTICS IO on so I could see how much work was happening in each database.
I ran the query first in a query window pointing at the Fred database, then I ran my query store query from the previous post (Capture the most expensive queries across your SQL Server using Query Store) to see what had been captured. I made it slightly easier for myself by adding an additional where clause to the cursor so that it only looked at these databases:
--Cursor to step through the databases DECLARE curDatabases CURSOR FAST_FORWARD FOR SELECT [name] FROM sys.databases WHERE is_query_store_on = 1 AND name IN ('Fred','Bert','Ernie');
I cleared down Query Store for all the databases:
USE MASTER; ALTER DATABASE Fred SET QUERY_STORE CLEAR; ALTER DATABASE Bert SET QUERY_STORE CLEAR; ALTER DATABASE Ernie SET QUERY_STORE CLEAR;
Then I repeated these steps for Bert and Ernie.
The Statistics IO for the query (regardless of which database context I had set) was as follows:
Table ‘Bert’. Scan count 24, logical reads 5095742, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table ‘Fred’. Scan count 25, logical reads 50, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
Table ‘Worktable’. Scan count 0, logical reads 0, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.
So you can see most of the work occurs in the Bert database, a little in Fred, and none in Ernie.
Now let’s see what query store captured when I ran the query pointing at database Fred:
And pointing at database Bert:
And pointing at database Ernie:
You can see that the figures get recorded against whichever database you are pointing at – regardless of where the data being accessed resides. I left the “TotalLogicalReads %” in the above screen shots so you can see I’m not hiding anything.
This has a few implications. First, I’m happy because it means my “Expensive queries” script isn’t double counting.
Second though, as you can’t turn on query store on in any of the system databases, you won’t be able to capture details for any queries executed with those as the context. That includes ad-hoc queries where the user may connect to master, but execute queries against your other databases.
Fortunately (because Query Store would be pretty pointless if it did) this doesn’t apply to stored procedures.
I’m going to wrap my horrible query into a stored procedure, and deploy it into database Ernie:
USE Ernie; CREATE PROCEDURE dbo.Horrible AS BEGIN SELECT TOP 100000 * FROM Fred.dbo.Fred f INNER JOIN Bert.dbo.Bert b ON b.BertText LIKE '%' + f.FredText + '%'; END;
Now I clear my Query Stores for the three database one last time. Then I’ll called the stored procedure from database Fred:
USE Fred; EXEC Ernie.dbo.Horrible;
Here’s what I get from query store now:
So, Query Store logs the execution against database Ernie – where the stored procedure resides, rather than Fred – where it was called from, or Bert – where most of the work was done.
I hope you’ll trust me enough on that that I don’t have to demonstrate all the other combinations!