Blog Post

Does Query Store Pre-Allocate Space

,

I love the questions I get while I’m presenting because they force me to think and learn. The question in the title is one I received recently. The answer, now that I’m not standing in front of people, is easy. Of course the space is not pre-allocated. Query Store tables are just system tables. They have a limit on how big they can grow (100mb by default), but that space isn’t going to be pre-allocated in any way. The space will just get used as and when it’s needed, just like any other system table. However, don’t take my word for it, let’s prove that.

The Test

Testing whether or not enabling Query Store is straight forward. Here’s a query that should give us information rather quickly:

CREATE DATABASE QSTest;
GO
USE QSTest;
GO
SELECT df.name,
       CAST((df.size / 128.0) AS DECIMAL(15, 2)) AS SizeInMB,
       CAST(df.size / 128.0 - CAST(FILEPROPERTY(df.name, 'SpaceUsed') AS INT)
            / 128.0 AS DECIMAL(15, 2)) AS AvailableSpaceInMB
FROM sys.database_files AS df
LEFT OUTER JOIN sys.data_spaces AS ds
   ON df.data_space_id = ds.data_space_id;
GO
ALTER DATABASE QSTest SET QUERY_STORE = ON;
GO
SELECT df.name,
       CAST((df.size / 128.0) AS DECIMAL(15, 2)) AS SizeInMB,
       CAST(df.size / 128.0 - CAST(FILEPROPERTY(df.name, 'SpaceUsed') AS INT)
            / 128.0 AS DECIMAL(15, 2)) AS AvailableSpaceInMB
FROM sys.database_files AS df
LEFT OUTER JOIN sys.data_spaces AS ds
   ON df.data_space_id = ds.data_space_id;
GO

The results come back rather quickly:

No space allocate

There is no change. Well, not 100mb of pre-allocated space worth of change. You’re seeing queries starting to be written to the Query Store, including the query we ran to get the space of the database. What happens if we run a real query:

CREATE TABLE dbo.Test (  TestID INT IDENTITY
                            CONSTRAINT pkTest PRIMARY KEY CLUSTERED NOT NULL,
                         TestValue VARCHAR(50)
                      );
WITH Nums
AS (SELECT TOP (10000)
       ROW_NUMBER() OVER (ORDER BY (SELECT 1)) AS n
    FROM master.sys.all_columns ac1
    CROSS JOIN master.sys.all_columns ac2
   )
INSERT INTO dbo.Test (TestValue)
SELECT 'Value' + CAST(Nums.n AS VARCHAR(50))
FROM Nums;
SELECT *
FROM dbo.Test AS t
WHERE t.TestValue = 'Value4444';
SELECT df.name,
       CAST((df.size / 128.0) AS DECIMAL(15, 2)) AS SizeInMB,
       CAST(df.size / 128.0 - CAST(FILEPROPERTY(df.name, 'SpaceUsed') AS INT)
            / 128.0 AS DECIMAL(15, 2)) AS AvailableSpaceInMB
FROM sys.database_files AS df
LEFT OUTER JOIN sys.data_spaces AS ds
   ON df.data_space_id = ds.data_space_id;

The results look like this:

You can see that there has been a change in the space available, but that’s because of us creating a new table and data as well as other system tables recording information.

Does Query Store Allocate

Microsoft supplied a query to check the space available in Query Store:

SELECT actual_state_desc,
       desired_state_desc,
       current_storage_size_mb,
       max_storage_size_mb,
       readonly_reason
FROM sys.database_query_store_options;

We’ll see this allocation within Query Store:

 

Don’t despair. It’s working. There just isn’t a MB worth of data yet. We can validate that the query is there by running this:

SELECT qsq.query_id,
       qsqt.query_sql_text
FROM sys.query_store_query AS qsq
JOIN sys.query_store_query_text AS qsqt
   ON qsqt.query_text_id = qsq.query_text_id
WHERE qsqt.query_sql_text LIKE '%SELECT *%';

And our query is there:

I used the wild cards for the query because we had such a simple query that is went through Simple Parameterization. That means the T-SQL is stored differently within Query Store. You can use fn_stmt_sql_handle_from_sql_stmt for some types of parameterized queries.

Conclusion

Basically, Query Data Store information is system information and is treated as such. There’s no special allocation of space different from how other system tables are managed.

The post Does Query Store Pre-Allocate Space appeared first on Grant Fritchey.

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating