sys.database_query_store_options (Transact-SQL)

THIS TOPIC APPLIES TO: yesSQL Server (starting with 2016)yesAzure SQL DatabasenoAzure SQL Data Warehouse noParallel Data Warehouse

Returns the Query Store options for this database.

Applies to: SQL Server ( SQL Server 2016 through SQL Server 2017), SQL Database.

Column name Data type Description
desired_state smallint Indicates the desired operation mode of Query Store, explicitly set by user.
0 = OFF
1 = READ_ONLY
2 = READ_WRITE
desired_state_desc nvarchar(64) Textual description of the desired operation mode of Query Store:
OFF
READ_ONLY
READ_WRITE
actual_state smallint Indicates the operation mode of Query Store. In addition to list of desired states required by the user, actual state can be an error state.
0 = OFF
1 = READ_ONLY
2 = READ_WRITE
3 = ERROR
actual_state_desc nvarchar(64) Textual description of the actual operation mode of Query Store.
OFF
READ_ONLY
READ_WRITE
ERROR

There are situations when actual state is different from the desired state:

Query Store may operate in read-only mode even if read-write was specified by the user. For example, that might happen if the database is in read-only mode or if Query Store size exceeded the quota.

Extremely rarely, Query Store can end up in ERROR state because of internal errors. If this happens, Query Store could be recovered by executing sp_query_store_consistency_check stored procedure within the affected database.
readonly_reason int When the desired_state_desc is READ_WRITE and the actual_state_desc is READ_ONLY, readonly_reason returns a bit map to indicate why the Query Store is in readonly mode.

1 – database is in read-only mode

2 – database is in single-user mode

4 – database is in emergency mode

8 – database is secondary replica (applies to Always On and Azure SQL Database geo-replication). This value can be effectively observed only on readable secondary replicas

65536 – the Query Store has reached the size limit set by the MAX_STORAGE_SIZE_MB option.

131072 - The number of different statements in Query Store has reached the internal memory limit. Consider removing queries that you do not need or upgrading to a higher service tier to enable transferring Query Store to read-write mode.
Only applies to SQL Database.

262144 – Size of in-memory items waiting to be persisted on disk has reached the internal memory limit. Query Store will be in read-only mode temporarily until the in-memory items are persisted on disk.
Only applies to SQL Database.

524288 – Database has reached disk size limit. Query Store is part of user database, so if there is no more available space for a database, that means that Query Store cannot grow further anymore.
Only applies to SQL Database.

To switch the Query Store operations mode back to read-write, see Verify Query Store is Collecting Query Data Continuously section of Best Practice with the Query Store.
current_storage_size_mb bigint Size of Query Store on disk in megabytes.
flush_interval_seconds bigint Defines period for regular flushing of Query Store data to disk. Default value is 900 (15 min).

Change by using the ALTER DATABASE <database> SET QUERY_STORE (DATA_FLUSH_INTERVAL_SECONDS = <interval>) statement.
interval_length_minutes bigint The statistics aggregation interval. Arbitrary values are not allowed . Use one of the following: 1, 5, 10, 15, 30, 60, and 1440 minutes. The default value is 60 minutes.
max_storage_size_mb bigint Maximum disk size for the Query Store. Default value is 100 MB.
For SQL Database Premium edition, default is 1Gb and for SQL Database Basic edition, default is 10Mb.

Change by using the ALTER DATABASE <database> SET QUERY_STORE (MAX_STORAGE_SIZE_MB = <size>) statement.
stale_query_threshold_days bigint Number of days that queries with no policy settings are kept in Query Store. Default value is 30. Set to 0 to disable the retention policy.
For SQL Database Basic edition, default is 7 days.

Change by using the ALTER DATABASE <database> SET QUERY_STORE ( CLEANUP_POLICY = ( STALE_QUERY_THRESHOLD_DAYS = <value> ) ) statement.
max_plans_per_query bigint Limits the maximum number of stored plans. Default value is 200. If the maximum value is reached, Query Store stops capturing new plans for that query. Setting to 0 removes the limitation with regards to the number of captured plans.

Change by using the ALTER DATABASE<database> SET QUERY_STORE (MAX_PLANS_PER_QUERY = <n>) statement.
query_capture_mode smallint The currently active query capture mode:

1 = ALL - all queries are captured. This is the default configuration value for SQL Server ( SQL Server 2016 through SQL Server 2017).

2 = AUTO - capture relevant queries based on execution count and resource consumption. This is the default configuration value for SQL Database.

3 = NONE - stop capturing new queries. Query Store will continue to collect compile and runtime statistics for queries that were captured already. Use this configuration cautiously since you may miss to capture important queries.
query_capture_mode_desc nvarchar(60) Textual description of the actual capture mode of Query Store:

ALL (default for SQL Server 2016)

AUTO (default for SQL Database)

NONE
size_based_cleanup_mode smallint Controls whether cleanup will be automatically activated when total amount of data gets close to maximum size:

1 = OFF – size based cleanup won’t be automatically activated.

2 = AUTO - size based cleanup will be automatically activated when size on disk reaches 90% of max_storage_size_mb. This is the default configuration value.

Size based cleanup removes the least expensive and oldest queries first. It stops at approximately 80% of max_storage_size_mb.
size_based_cleanup_mode_desc smallint Textual description of the actual size-based cleanup mode of Query Store:

OFF

AUTO (default)
wait_stats_capture_mode smallint Controls whether Query Store performs capture of wait statistics:

0 = OFF

1 = ON
wait_stats_mode_capture_desc nvarchar(60) Textual description of the actual wait statistics capture mode:

OFF

ON (default)

Permissions

Requires the VIEW DATABASE STATE permission.

See Also

sys.query_context_settings (Transact-SQL)
sys.query_store_plan (Transact-SQL)
sys.query_store_query (Transact-SQL)
sys.query_store_query_text (Transact-SQL)
sys.query_store_runtime_stats (Transact-SQL)
sys.query_store_wait_stats (Transact-SQL)
sys.query_store_runtime_stats_interval (Transact-SQL)
Monitoring Performance By Using the Query Store
Catalog Views (Transact-SQL)
sys.fn_stmt_sql_handle_from_sql_stmt (Transact-SQL)
Query Store Stored Procedures (Transact-SQL)