sys.dm_exec_sql_text (Transact-SQL)
Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance
Returns the text of the SQL batch that is identified by the specified sql_handle. This table-valued function replaces the system function fn_get_sql.
Syntax
sys.dm_exec_sql_text(sql_handle | plan_handle)
Arguments
sql_handle
Is a token that uniquely identifies a batch that has executed or is currently executing. sql_handle is varbinary(64).
The sql_handle can be obtained from the following dynamic management objects:
plan_handle
Is a token that uniquely identifies a query execution plan for a batch that has executed and its plan resides in the plan cache, or is currently executing. plan_handle is varbinary(64).
The plan_handle can be obtained from the following dynamic management objects:
Table Returned
Column name | Data type | Description |
---|---|---|
dbid | smallint | ID of database. For static SQL in a stored procedure, the ID of the database containing the stored procedure. Null otherwise. |
objectid | int | ID of object. Is NULL for ad hoc and prepared SQL statements. |
number | smallint | For a numbered stored procedure, this column returns the number of the stored procedure. For more information, see sys.numbered_procedures (Transact-SQL). Is NULL for ad hoc and prepared SQL statements. |
encrypted | bit | 1 = SQL text is encrypted. 0 = SQL text is not encrypted. |
text | nvarchar(max ) | Text of the SQL query. Is NULL for encrypted objects. |
Permissions
Requires VIEW SERVER STATE
permission on the server.
Permissions for SQL Server 2022 and later
Requires VIEW SERVER PERFORMANCE STATE permission on the server.
Remarks
For ad hoc queries, the SQL handles are hash values based on the SQL text being submitted to the server, and can originate from any database.
For database objects such as stored procedures, triggers or functions, the SQL handles are derived from the database ID, object ID, and object number.
Plan handle is a hash value derived from the compiled plan of the entire batch.
Note
dbid cannot be determined from sql_handle for ad hoc queries. To determine dbid for ad hoc queries, use plan_handle instead.
Examples
A. Conceptual Example
The following is a basic example to illustrate passing a sql_handle either directly or with CROSS APPLY.
Create activity.
Execute the following T-SQL in a new query window in SQL Server Management Studio.-- Identify current spid (session_id) SELECT @@SPID; GO -- Create activity WAITFOR DELAY '00:02:00';
Using CROSS APPLY.
The sql_handle from sys.dm_exec_requests will be passed to sys.dm_exec_sql_text using CROSS APPLY. Open a new query window and pass the spid identified in step 1. In this example the spid happens to be59
.SELECT t.* FROM sys.dm_exec_requests AS r CROSS APPLY sys.dm_exec_sql_text(r.sql_handle) AS t WHERE session_id = 59 -- modify this value with your actual spid
Passing sql_handle directly.
Acquire the sql_handle from sys.dm_exec_requests. Then, pass the sql_handle directly to sys.dm_exec_sql_text. Open a new query window and pass the spid identified in step 1 to sys.dm_exec_requests. In this example the spid happens to be59
. Then pass the returned sql_handle as an argument to sys.dm_exec_sql_text.-- acquire sql_handle SELECT sql_handle FROM sys.dm_exec_requests WHERE session_id = 59 -- modify this value with your actual spid -- pass sql_handle to sys.dm_exec_sql_text SELECT * FROM sys.dm_exec_sql_text(0x01000600B74C2A1300D2582A2100000000000000000000000000000000000000000000000000000000000000) -- modify this value with your actual sql_handle
B. Obtain information about the top five queries by average CPU time
The following example returns the text of the SQL statement and average CPU time for the top five queries.
SELECT TOP 5 total_worker_time/execution_count AS [Avg CPU Time],
SUBSTRING(st.text, (qs.statement_start_offset/2)+1,
((CASE qs.statement_end_offset
WHEN -1 THEN DATALENGTH(st.text)
ELSE qs.statement_end_offset
END - qs.statement_start_offset)/2) + 1) AS statement_text
FROM sys.dm_exec_query_stats AS qs
CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS st
ORDER BY total_worker_time/execution_count DESC;
C. Provide batch-execution statistics
The following example returns the text of SQL queries that are being executed in batches and provides statistical information about them.
SELECT s2.dbid,
s1.sql_handle,
(SELECT TOP 1 SUBSTRING(s2.text,statement_start_offset / 2+1 ,
( (CASE WHEN statement_end_offset = -1
THEN (LEN(CONVERT(nvarchar(max),s2.text)) * 2)
ELSE statement_end_offset END) - statement_start_offset) / 2+1)) AS sql_statement,
execution_count,
plan_generation_num,
last_execution_time,
total_worker_time,
last_worker_time,
min_worker_time,
max_worker_time,
total_physical_reads,
last_physical_reads,
min_physical_reads,
max_physical_reads,
total_logical_writes,
last_logical_writes,
min_logical_writes,
max_logical_writes
FROM sys.dm_exec_query_stats AS s1
CROSS APPLY sys.dm_exec_sql_text(sql_handle) AS s2
WHERE s2.objectid is null
ORDER BY s1.sql_handle, s1.statement_start_offset, s1.statement_end_offset;
See also
Dynamic Management Views and Functions (Transact-SQL)
Execution Related Dynamic Management Views and Functions (Transact-SQL)
sys.dm_exec_query_stats (Transact-SQL)
sys.dm_exec_requests (Transact-SQL)
sys.dm_exec_cursors (Transact-SQL)
sys.dm_exec_xml_handles (Transact-SQL)
sys.dm_exec_query_memory_grants (Transact-SQL)
Using APPLY
sys.dm_exec_text_query_plan (Transact-SQL)