sys.dm_os_threads (Transact-SQL)
Returns a list of all SQL Server Operating System threads that are running under the SQL Server process.
Column name |
Data type |
Description |
---|---|---|
thread_address |
varbinary(8) |
Memory address (Primary Key) of the thread. |
started_by_sqlservr |
bit |
Indicates the thread initiator. 1 = SQL Server started the thread. 0 = Another component started the thread, such as an extended stored procedure from within SQL Server. |
os_thread_id |
int |
ID of the thread that is assigned by the operating system. |
status |
int |
Internal status flag. |
instruction_address |
varbinary(8) |
Address of the instruction that is currently being executed. |
creation_time |
datetime |
Time when this thread was created. |
kernel_time |
bigint |
Amount of kernel time that is used by this thread. |
usermode_time |
bigint |
Amount of user time that is used by this thread. |
stack_base_address |
varbinary(8) |
Memory address of the highest stack address for this thread. |
stack_end_address |
varbinary(8) |
Memory address of the lowest stack address of this thread. |
stack_bytes_committed |
int |
Number of bytes that are committed in the stack. |
stack_bytes_used |
int |
Number of bytes that are actively being used on the thread. |
affinity |
bigint |
CPU mask on which this thread is supposed to be running. This depends on the value in sp_configureaffinity mask configuration option. |
locale |
int |
Cached locale LCID for the thread. |
priority |
int |
Priority value of this thread. |
token |
varbinary(8) |
Cached impersonation token handle for the thread. |
is_impersonating |
int |
Indicates whether this thread is using Win32 impersonation. 1 = The thread is using security credentials that are different from the default of the process. This indicates that the thread is impersonating an entity other than the one that created the process. |
is_waiting_on_loader_lock |
int |
Operating system status of whether the thread is waiting on the loader lock. |
fiber_data |
varbinary(8) |
Current Win32 fiber that is running on the thread. This is only applicable when SQL Server is configured for lightweight pooling. |
thread_handle |
varbinary(8) |
Internal use only. |
event_handle |
varbinary(8) |
Internal use only. |
scheduler_address |
varbinary(8) |
Memory address of the scheduler that is associated with this thread. For more information, see sys.dm_os_schedulers (Transact-SQL). |
worker_address |
varbinary(8) |
Memory address of the worker that is bound to this thread. For more information, see sys.dm_os_workers (Transact-SQL). |
fiber_context_address |
varbinary(8) |
Internal fiber context address. This is only applicable when SQL Server is configured for lightweight pooling. |
self_address |
varbinary(8) |
Internal consistency pointer. |
Permissions
Requires VIEW SERVER STATE permission on the server.
Examples
Upon startup, SQL Server starts threads and then associates workers with those threads. However, external components, such as an extended stored procedure, can start threads under the SQL Server process. SQL Server has no control of these threads. sys.dm_os_threads can provide information about rogue threads that consume resources in the SQL Server process.
The following query is used to find workers, along with time used for execution, that are running threads not started by SQL Server.
Note
For conciseness, the following query uses an asterisk (*) in the SELECT statement. You should avoid using the asterisk (*), especially against catalog views, dynamic management views, and system table-valued functions. Future upgrades and releases of MicrosoftSQL Server may add columns and change the order of columns to these views and functions. These changes might break applications that expect a particular order and number of columns.
SELECT *
FROM sys.dm_os_threads
WHERE started_by_sqlservr = 0;