Skip to content
GitLab
Menu
Projects
Groups
Snippets
Loading...
Help
Help
Support
Community forum
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in
Toggle navigation
Menu
Open sidebar
dwentzel
SQLScripts
Commits
1c1cc95a
Commit
1c1cc95a
authored
Mar 05, 2014
by
dwentzel
Browse files
added sysjobhistory purge
parent
4fe8bf93
Changes
8
Expand all
Hide whitespace changes
Inline
Side-by-side
README.txt
View file @
1c1cc95a
...
...
@@ -19,4 +19,9 @@ CreateSnapshot.sql : http://www.davewentzel.com/content/automatic-database-snaps
creates a database snapshot and provides you with the commands to restore the db back to the
snapshot. This is great when testing some code (not in prod) where transaction control may
not be possible (such as testing service broker features). This will allow you to quickly
"roll back" any changes.
\ No newline at end of file
"roll back" any changes.
sysjobhistoryPurge : http://www.davewentzel.com/content/blocking-and-contention-sysjobhistory. A utility that
customizes what gets purged via sysjobhistory. Allows far more flexibility than what Microsoft
provides natively. Also, the purge is "smart" and will not cause blocking and concurrency
problems on instances with many, frequent SQL Agent jobs. Includes tsqlt unit tests.
\ No newline at end of file
sysjobhistoryPurge/DBA_PM_Addin_sysjobhistory_purge.sfu_dbo_sproc.sql
0 → 100644
View file @
1c1cc95a
if
exists
(
select
*
from
sysobjects
where
id
=
object_id
(
'DBA_PM_Addin_sysjobhistory_purge'
)
and
sysstat
&
0
xf
=
4
)
DROP
procedure
dbo
.
DBA_PM_Addin_sysjobhistory_purge
GO
CREATE
PROCEDURE
DBA_PM_Addin_sysjobhistory_purge
@
job_id
UNIQUEIDENTIFIER
AS
BEGIN
SET
NOCOUNT
ON
DECLARE
@
ConfigValueText
DATETIME
DECLARE
@
ConfigValueInt
INT
DECLARE
@
now
DATETIME
SELECT
@
now
=
GETDATE
()
SELECT
@
ConfigValueText
=
COALESCE
(
ConfigValueText
,
'1/1/1980'
)
FROM
DBA_PM_Config
WHERE
ConfigSetting
=
'LastSysJobHistoryPurgeRun'
SELECT
@
ConfigValueInt
=
COALESCE
(
ConfigValueInt
,
24
)
FROM
DBA_PM_Config
WHERE
ConfigSetting
=
'DBA_PM_Addin_sysjobhistory_purge'
if
datediff
(
hh
,
COALESCE
(
@
ConfigValueText
,
'1/1/1980'
),
@
now
)
>
@
ConfigValueInt
BEGIN
--call the driver which handles cycling through the list of jobs and calling the purge procedure.
--it also sets the Agent sysjobhistory to unlimited. We do this in a subproc to make TSQLT testing easier
--since this proc handles the scaffolding around how SFU works...and we don't want to have to work around the SFU scheduler
--to get the TSQLT tests to work.
EXEC
DBA_PM_sysjobhistory_driver
--now update the config table to reflect a successful run
UPDATE
DBA_PM_Config
SET
ConfigValueText
=
convert
(
varchar
(
100
),
@
now
)
WHERE
ConfigSetting
=
'LastSysJobHistoryPurgeRun'
END
;
END
;
GO
sysjobhistoryPurge/DBA_PM_sp_jobhistory_row_limiter.sfu_dbo_sproc.sql
0 → 100644
View file @
1c1cc95a
/*
this is more or less a copy of MS-provided sp_jobhistory_row_limiter.
we have merely changed the logic to find the config data in our config table vs the registry
and to handle looping through deletes smartly.
no TABLOCKX
tests are in DBA_PM_sysjobhistory_driver_Tests.sfu_dbo_test.sql
*/
if
exists
(
select
*
from
sysobjects
where
id
=
object_id
(
'DBA_PM_sp_jobhistory_row_limiter'
)
and
sysstat
&
0
xf
=
4
)
DROP
procedure
dbo
.
DBA_PM_sp_jobhistory_row_limiter
GO
CREATE
PROCEDURE
DBA_PM_sp_jobhistory_row_limiter
@
job_id
UNIQUEIDENTIFIER
AS
BEGIN
SET
DEADLOCK_PRIORITY
LOW
DECLARE
@
NumDaysToRetain
INT
DECLARE
@
NumFailureDaysToRetain
INT
DECLARE
@
LastDayToRetain
INT
DECLARE
@
LastFailureDayToRetain
INT
DECLARE
@
RowsDeleted
INT
SET
NOCOUNT
ON
-- Get the NumDaysToRetain and NumFailureDaysToRetain
-- FailSafe: maintain 30 days.
SELECT
--j.* , c_byJob.*, c_ByCat.* , c_Default.*
@
NumDaysToRetain
=
COALESCE
(
c_byJob
.
NumDaysToRetain
,
c_byCat
.
NumDaysToRetain
,
c_Default
.
NumDaysToRetain
,
30
)
,
@
NumFailureDaysToRetain
=
COALESCE
(
c_byJob
.
NumFailureDaysToRetain
,
c_byCat
.
NumFailureDaysToRetain
,
c_Default
.
NumFailureDaysToRetain
,
30
)
FROM
v_sysjobs
j
LEFT
JOIN
DBA_PM_sysjobhistory_config
c_byJob
--first we prefer to JOIN first by JobName
ON
j
.
JobName
=
c_byJob
.
JobName
LEFT
JOIN
DBA_PM_sysjobhistory_config
c_byCat
--next we prefer to JOIN first by Category
ON
j
.
CategoryName
=
c_byCat
.
CategoryName
CROSS
JOIN
DBA_PM_sysjobhistory_config
c_Default
--last, get me the defaults.
WHERE
j
.
job_id
=
@
job_id
AND
c_Default
.
JobName
=
'(default)'
AND
c_Default
.
CategoryName
=
'(default)'
--get the actual date of the most recent rows that we wish to maintain.
--convert that to an INT so it works with msdb..sysjobhistory
SELECT
@
LastDayToRetain
=
CONVERT
(
int
,
CONVERT
(
varchar
(
200
),(
GETDATE
()
-
@
NumDaysToRetain
),
112
))
SELECT
@
LastFailureDayToRetain
=
CONVERT
(
int
,
CONVERT
(
varchar
(
200
),(
GETDATE
()
-
@
NumFailureDaysToRetain
),
112
))
--DELETE sysjobhistory rows in a loop, keep going until we have nothing left to delete
SELECT
@
RowsDeleted
=
1
WHILE
(
@
RowsDeleted
<>
0
)
BEGIN
--handle SUCCESS case
BEGIN
TRAN
DELETE
TOP
(
1000
)
FROM
v_sysjobhistory
WITH
(
READPAST
)
WHERE
job_id
=
@
job_id
AND
run_status
IN
(
1
,
2
,
3
)
--Succeeded, Retry, and Canceled. I view all of these as successes.
AND
run_date
<
@
LastDayToRetain
SELECT
@
RowsDeleted
=
@@
ROWCOUNT
;
--PRINT 'SUCCESS rows deleted: ' + convert(varchar(200),@RowsDeleted)
COMMIT
--handle FAILURE case
BEGIN
TRAN
DELETE
TOP
(
1000
)
FROM
v_sysjobhistory
WITH
(
READPAST
)
WHERE
job_id
=
@
job_id
AND
run_status
IN
(
0
)
--Failure
AND
run_date
<
@
LastFailureDayToRetain
COMMIT
SELECT
@
RowsDeleted
=
CASE
WHEN
@@
ROWCOUNT
=
0
THEN
@
RowsDeleted
ELSE
@@
ROWCOUNT
END
--PRINT 'FAILURE rows deleted (or successes from above): ' + convert(varchar(200),@RowsDeleted)
--catch your breath
--WAITFOR DELAY '00:00:01'
END
RETURN
(
0
)
-- Success
END
\ No newline at end of file
sysjobhistoryPurge/DBA_PM_sysjobhistory_config_tbl.sql
0 → 100644
View file @
1c1cc95a
IF
NOT
EXISTS
(
select
*
from
sys
.
objects
WHERE
name
=
'DBA_PM_sysjobhistory_config'
)
BEGIN
CREATE
TABLE
DBA_PM_sysjobhistory_config
(
JobName
varchar
(
256
),
--(name of the job for this retention setting)
CategoryName
varchar
(
256
),
--(only JobName or CategoryName should be completed)
NumDaysToRetain
int
,
--(number of days to retain for this entry)
NumFailureDaysToRetain
int
--(number of days to retain for failure entries)
);
END
GO
IF
EXISTS
(
select
*
from
sys
.
objects
WHERE
name
=
'v_sysjobs'
)
BEGIN
DROP
VIEW
v_sysjobs
END
;
GO
CREATE
VIEW
v_sysjobs
AS
SELECT
CASE
c
.
category_id
WHEN
0
THEN
NULL
ELSE
c
.
name
END
AS
CategoryName
,
j
.
job_id
AS
job_id
,
j
.
name
AS
JobName
FROM
msdb
..
sysjobs
j
JOIN
msdb
..
syscategories
c
ON
j
.
category_id
=
c
.
category_id
GO
IF
EXISTS
(
select
*
from
sys
.
objects
WHERE
name
=
'v_sysjobhistory'
)
BEGIN
DROP
VIEW
v_sysjobhistory
END
;
GO
CREATE
VIEW
v_sysjobhistory
AS
SELECT
instance_id
,
job_id
,
run_date
,
run_time
,
run_status
FROM
msdb
..
sysjobhistory
GO
sysjobhistoryPurge/DBA_PM_sysjobhistory_driver.sfu_dbo_sproc.sql
0 → 100644
View file @
1c1cc95a
if
exists
(
select
*
from
sysobjects
where
id
=
object_id
(
'DBA_PM_sysjobhistory_driver'
)
and
sysstat
&
0
xf
=
4
)
DROP
procedure
dbo
.
DBA_PM_sysjobhistory_driver
GO
CREATE
PROCEDURE
DBA_PM_sysjobhistory_driver
AS
BEGIN
SET
DEADLOCK_PRIORITY
LOW
DECLARE
@
job_id
uniqueidentifier
SET
NOCOUNT
ON
--first, blindly set SQLAgent sysjobhistory to unlimited. This shuts off sp_jobhistory_row_limiter
--which cuts down on waits and job blocking for larger customers.
EXEC
msdb
.
dbo
.
sp_set_sqlagent_properties
@
jobhistory_max_rows
=-
1
,
@
jobhistory_max_rows_per_job
=-
1
DECLARE
CURSER
CURSOR
FOR
SELECT
job_id
FROM
v_sysjobs
OPEN
CURSER
FETCH
NEXT
FROM
CURSER
INTO
@
job_id
WHILE
(
@@
FETCH_STATUS
=
0
)
BEGIN
--PRINT 'Running DBA_PM_sp_jobhistory_row_limiter for @job_id: ' + convert(varchar(200),@job_id)
EXEC
DBA_PM_sp_jobhistory_row_limiter
@
job_id
=
@
job_id
FETCH
NEXT
FROM
CURSER
INTO
@
job_id
END
CLOSE
CURSER
DEALLOCATE
CURSER
END
\ No newline at end of file
sysjobhistoryPurge/DBA_PM_sysjobhistory_driver_Tests.sfu_dbo_test.sql
0 → 100644
View file @
1c1cc95a
This diff is collapsed.
Click to expand it.
sysjobhistoryPurge/README.txt
0 → 100644
View file @
1c1cc95a
http://www.davewentzel.com/content/blocking-and-contention-sysjobhistory. A utility that
customizes what gets purged via sysjobhistory. Allows far more flexibility than what Microsoft
provides natively. Also, the purge is "smart" and will not cause blocking and concurrency
problems on instances with many, frequent SQL Agent jobs. Includes tsqlt unit tests.
\ No newline at end of file
sysjobhistoryPurge/seeddata.sql
0 → 100644
View file @
1c1cc95a
INSERT
INTO
#
DBA_PM_Config
(
ConfigSetting
,
ConfigValueText
,
ConfigValueInt
)
VALUES
(
'DBA_PM_Addin_sysjobhistory_purge'
,
'ConfigValueInt indicates Polling Interval (Hours)'
,
24
)
INSERT
INTO
#
DBA_PM_Config
(
ConfigSetting
,
ConfigValueText
,
ConfigValueInt
)
VALUES
(
'LastSysJobHistoryPurgeRun'
,
'1/1/1980'
,
NULL
)
IF
NOT
EXISTS
(
select
*
from
DBA_PM_sysjobhistory_config
)
BEGIN
--insert base seed data, but only if this is the first run of SFU installer
INSERT
INTO
DBA_PM_sysjobhistory_config
VALUES
(
NULL
,
'ETL'
,
1
,
90
)
INSERT
INTO
DBA_PM_sysjobhistory_config
VALUES
(
'(default)'
,
'(default)'
,
3
,
90
)
INSERT
INTO
DBA_PM_sysjobhistory_config
VALUES
(
NULL
,
'SFU TOOL'
,
1
,
90
)
END
;
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
.
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment