Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Added kill session option to close sessions quickly #104

Open
wants to merge 1 commit into
base: master
Choose a base branch
from
Open
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
99 changes: 59 additions & 40 deletions sp_WhoIsActive.sql
Original file line number Diff line number Diff line change
Expand Up @@ -75,6 +75,10 @@ ALTER PROC dbo.sp_WhoIsActive
--Get average time for past runs of an active query
--(based on the combination of plan handle, sql handle, and offset)
@get_avg_time BIT = 0,

--Get session id for kill
@get_kill_session BIT = 0,


--Get additional non-performance-related information about the session or request
--text_size, language, date_format, date_first, quoted_identifier, arithabort, ansi_null_dflt_on,
Expand Down Expand Up @@ -158,6 +162,10 @@ OUTPUT COLUMNS
Formatted/Non: [session_id] [smallint] NOT NULL
Session ID (a.k.a. SPID)

Formatted: [kill session_id] [varchar](15) NULL
Non-Formatted: [kill session_id] [varchar](15) NULL
(Requires @get_kill_session option)

Formatted: [dd hh:mm:ss.mss] [varchar](15) NULL
Non-Formatted: <not returned>
For an active request, time the query has been running
Expand Down Expand Up @@ -435,6 +443,7 @@ BEGIN;
OR @get_task_info IS NULL
OR @get_locks IS NULL
OR @get_avg_time IS NULL
OR @get_kill_session IS NULL
OR @get_additional_info IS NULL
OR @find_block_leaders IS NULL
OR @delta_interval IS NULL
Expand All @@ -448,37 +457,37 @@ BEGIN;
RAISERROR('Input parameters cannot be NULL', 16, 1);
RETURN;
END;

IF @filter_type NOT IN ('session', 'program', 'database', 'login', 'host')
BEGIN;
RAISERROR('Valid filter types are: session, program, database, login, host', 16, 1);
RETURN;
END;

IF @filter_type = 'session' AND @filter LIKE '%[^0123456789]%'
BEGIN;
RAISERROR('Session filters must be valid integers', 16, 1);
RETURN;
END;

IF @not_filter_type NOT IN ('session', 'program', 'database', 'login', 'host')
BEGIN;
RAISERROR('Valid filter types are: session, program, database, login, host', 16, 1);
RETURN;
END;

IF @not_filter_type = 'session' AND @not_filter LIKE '%[^0123456789]%'
BEGIN;
RAISERROR('Session filters must be valid integers', 16, 1);
RETURN;
END;

IF @show_sleeping_spids NOT IN (0, 1, 2)
BEGIN;
RAISERROR('Valid values for @show_sleeping_spids are: 0, 1, or 2', 16, 1);
RETURN;
END;

IF @get_plans NOT IN (0, 1, 2)
BEGIN;
RAISERROR('Valid values for @get_plans are: 0, 1, or 2', 16, 1);
Expand All @@ -496,7 +505,7 @@ BEGIN;
RAISERROR('Valid values for @format_output are: 0, 1, or 2', 16, 1);
RETURN;
END;

IF @get_memory_info = 1 AND NOT EXISTS (SELECT * FROM sys.all_objects WHERE name = 'resource_governor_resource_pools')
BEGIN;
RAISERROR('@get_memory_info is not available for SQL Server 2005.', 16, 1);
Expand Down Expand Up @@ -716,7 +725,7 @@ BEGIN;
ORDER BY
param_group,
group_order;

WITH
a0 AS
(SELECT 1 AS n UNION ALL SELECT 1),
Expand Down Expand Up @@ -913,6 +922,9 @@ BEGIN;
JOIN
(
SELECT '[session_id]' AS column_name, 1 AS default_order
UNION ALL
SELECT '[kill_session_id]', 200
WHERE @get_kill_session = 1
UNION ALL
SELECT '[dd hh:mm:ss.mss]', 2
WHERE
Expand Down Expand Up @@ -964,7 +976,7 @@ BEGIN;
UNION ALL
SELECT '[physical_io_delta]', 17
WHERE
@delta_interval > 0
@delta_interval > 0
AND @get_task_info = 2
UNION ALL
SELECT '[reads_delta]', 18
Expand Down Expand Up @@ -1100,13 +1112,13 @@ BEGIN;
1,
''
);

IF COALESCE(RTRIM(@output_column_list), '') = ''
BEGIN;
RAISERROR('No valid column matches found in @output_column_list or no columns remain due to selected options.', 16, 1);
RETURN;
END;

IF @destination_table <> ''
BEGIN;
SET @destination_table =
Expand All @@ -1116,7 +1128,7 @@ BEGIN;
COALESCE(QUOTENAME(PARSENAME(@destination_table, 2)) + '.', '') +
--table
COALESCE(QUOTENAME(PARSENAME(@destination_table, 1)), '');

IF COALESCE(RTRIM(@destination_table), '') = ''
BEGIN;
RAISERROR('Destination table not properly formatted.', 16, 1);
Expand Down Expand Up @@ -1370,7 +1382,7 @@ BEGIN;

--Used for the delta pull
REDO:;

IF
@get_locks = 1
AND @recursion = 1
Expand Down Expand Up @@ -1793,7 +1805,7 @@ BEGIN;
CREATE STATISTICS s_principal_name ON #locks (principal_name)
WITH SAMPLE 0 ROWS, NORECOMPUTE;
END;

DECLARE
@sql VARCHAR(MAX),
@sql_n NVARCHAR(MAX),
Expand Down Expand Up @@ -2830,15 +2842,15 @@ BEGIN;
(
SELECT TOP(@i)
(
SELECT TOP(@i)
SELECT TOP(@i)
x.request_time,
x.grant_time,
x.wait_time_ms,
x.requested_memory_kb,
x.requested_memory_kb,
x.mg_granted_memory_kb AS granted_memory_kb,
x.mg_used_memory_kb AS used_memory_kb,
x.max_used_memory_kb,
x.ideal_memory_kb,
x.ideal_memory_kb,
x.required_memory_kb,
x.queue_id,
x.wait_order,
Expand All @@ -2865,7 +2877,7 @@ BEGIN;
TYPE
),
(
SELECT TOP(@i)
SELECT TOP(@i)
x.wg_name AS name,
x.request_max_memory_grant_percent,
x.request_max_cpu_time_sec,
Expand All @@ -2876,7 +2888,7 @@ BEGIN;
TYPE
),
(
SELECT TOP(@i)
SELECT TOP(@i)
x.rp_name AS name,
x.min_memory_percent,
x.max_memory_percent,
Expand All @@ -2891,7 +2903,7 @@ BEGIN;
FOR XML
PATH(''memory_info''),
TYPE
)
)
'
ELSE
'NULL '
Expand Down Expand Up @@ -3773,7 +3785,7 @@ BEGIN;
open_tran_count,
sql_handle,
statement_start_offset,
statement_end_offset,
statement_end_offset,
sql_text,
plan_handle,
blocking_session_id,
Expand Down Expand Up @@ -3802,7 +3814,7 @@ BEGIN;
OR @output_column_list LIKE '%|[tran_log_writes|]%' ESCAPE '|'
OR @output_column_list LIKE '%|[implicit_tran|]%' ESCAPE '|'
)
BEGIN;
BEGIN;
DECLARE @i INT;
SET @i = 2147483647;

Expand Down Expand Up @@ -3955,9 +3967,9 @@ BEGIN;
WHERE
s1.transaction_id = s_tran.transaction_id
AND s1.recursion = 1

UNION ALL

SELECT TOP(1)
s2.session_id,
s2.request_id
Expand Down Expand Up @@ -3989,7 +4001,7 @@ BEGIN;
END;

--Variables for text and plan collection
DECLARE
DECLARE
@session_id SMALLINT,
@request_id INT,
@sql_handle VARBINARY(64),
Expand Down Expand Up @@ -4100,9 +4112,9 @@ BEGIN;
text,
0 AS row_num
FROM sys.dm_exec_sql_text(@sql_handle)

UNION ALL

SELECT
NULL,
1 AS row_num
Expand Down Expand Up @@ -4589,7 +4601,7 @@ BEGIN;
WHERE
l.database_name = @database_name
OPTION (KEEPFIXED PLAN); ';

EXEC sp_executesql
@sql_n,
N'@database_name sysname',
Expand Down Expand Up @@ -4830,7 +4842,7 @@ BEGIN;
WITH SAMPLE 0 ROWS, NORECOMPUTE;
CREATE STATISTICS s_query_error ON #blocked_requests (query_error)
WITH SAMPLE 0 ROWS, NORECOMPUTE;

INSERT #blocked_requests
(
session_id,
Expand Down Expand Up @@ -4869,20 +4881,20 @@ BEGIN;
OR t.hobt_id IS NOT NULL
OR t.schema_node IS NOT NULL
);

DECLARE blocks_cursor
CURSOR LOCAL FAST_FORWARD
FOR
SELECT DISTINCT
database_name
FROM #blocked_requests;

OPEN blocks_cursor;

FETCH NEXT FROM blocks_cursor
INTO
@database_name;

WHILE @@FETCH_STATUS = 0
BEGIN;
BEGIN TRY;
Expand Down Expand Up @@ -4925,7 +4937,7 @@ BEGIN;
s.schema_id = COALESCE(o.schema_id, b.schema_id)
WHERE
b.database_name = @database_name; ';

EXEC sp_executesql
@sql_n,
N'@database_name sysname',
Expand Down Expand Up @@ -4959,10 +4971,10 @@ BEGIN;
INTO
@database_name;
END;

CLOSE blocks_cursor;
DEALLOCATE blocks_cursor;

UPDATE s
SET
additional_info.modify
Expand Down Expand Up @@ -5073,7 +5085,7 @@ BEGIN;
s.session_id = @session_id
AND s.recursion = 1
OPTION (KEEPFIXED PLAN);

UPDATE s
SET
additional_info.modify
Expand All @@ -5091,7 +5103,7 @@ BEGIN;
BEGIN CATCH;
DECLARE @msdb_error_message NVARCHAR(256);
SET @msdb_error_message = ERROR_MESSAGE();

UPDATE s
SET
additional_info.modify
Expand Down Expand Up @@ -5122,7 +5134,7 @@ BEGIN;
WHERE
s.recursion = 1
OPTION (KEEPFIXED PLAN);

OPEN agent_cursor;

FETCH NEXT FROM agent_cursor
Expand All @@ -5148,7 +5160,7 @@ BEGIN;
CLOSE agent_cursor;
DEALLOCATE agent_cursor;
END;

IF
@delta_interval > 0
AND @recursion <> 1
Expand Down Expand Up @@ -5216,6 +5228,13 @@ BEGIN;
(
SELECT
session_id, ' +
-- kill [session_id]
CASE
WHEN @get_kill_session=1 THEN
'''kill '' + cast(session_id as varchar(10)) AS [kill_session_id], '
ELSE
''
END +
--[dd hh:mm:ss.mss]
CASE
WHEN @format_output IN (1, 2) THEN
Expand Down