DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Refcards Trend Reports Events Over 2 million developers have joined DZone. Join Today! Thanks for visiting DZone today,
Edit Profile Manage Email Subscriptions Moderation Admin Console How to Post to DZone Article Submission Guidelines
View Profile
Sign Out
Refcards
Trend Reports
Events
Zones
Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Partner Zones AWS Cloud
by AWS Developer Relations
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Partner Zones
AWS Cloud
by AWS Developer Relations
Securing Your Software Supply Chain with JFrog and Azure
Register Today

Trending

  • Cucumber Selenium Tutorial: A Comprehensive Guide With Examples and Best Practices
  • Breaking Down the Monolith
  • Integrate Cucumber in Playwright With Java
  • Why I Prefer Trunk-Based Development

Trending

  • Cucumber Selenium Tutorial: A Comprehensive Guide With Examples and Best Practices
  • Breaking Down the Monolith
  • Integrate Cucumber in Playwright With Java
  • Why I Prefer Trunk-Based Development
  1. DZone
  2. Data Engineering
  3. Databases
  4. Does Query Store Pre-Allocate Space?

Does Query Store Pre-Allocate Space?

If you're wondering whether Query Store pre-allocates space for its tables, wait no more! It doesn't. Query Store tables are just system tables.

Grant Fritchey user avatar by
Grant Fritchey
·
Feb. 08, 17 · Tutorial
Like (4)
Save
Tweet
Share
3.23K Views

Join the DZone community and get the full member experience.

Join For Free

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 straightforward. 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:

image title

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:

image title

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.

Database Space (architecture)

Published at DZone with permission of Grant Fritchey, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

Trending

  • Cucumber Selenium Tutorial: A Comprehensive Guide With Examples and Best Practices
  • Breaking Down the Monolith
  • Integrate Cucumber in Playwright With Java
  • Why I Prefer Trunk-Based Development

Comments

Partner Resources

X

ABOUT US

  • About DZone
  • Send feedback
  • Careers
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 600 Park Offices Drive
  • Suite 300
  • Durham, NC 27709
  • support@dzone.com

Let's be friends: