Skip to content

Commit c97fed5

Browse files
authored
Add files via upload
1 parent 8bdaa8e commit c97fed5

8 files changed

+1108
-0
lines changed

SSDB.Check_Index_Fragmentation.sql

Lines changed: 29 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,29 @@
1+
/*--------------------------------------------------------------------------------------------------------------------------------+
2+
| Purpose: How to Check Index Fragmentation on Indexes in a Database
3+
| Note: SQLCmdMode Script
4+
+--------------------------------------------------------------------------------------------------------------------------------*/
5+
6+
SELECT
7+
'Schema' = dbschemas.[name]
8+
, 'Table' = dbtables.[name]
9+
, 'Index' = dbindexes.[name]
10+
, indexstats.avg_fragmentation_in_percent
11+
, indexstats.page_count
12+
, SqlScript =
13+
CASE
14+
WHEN indexstats.avg_fragmentation_in_percent > 30 THEN 'ALTER INDEX [' + dbindexes.[name] + '] ON [' + dbschemas.[name] + '].[' + dbtables.[name] + '] REBUILD WITH (ONLINE = ON)'
15+
WHEN indexstats.avg_fragmentation_in_percent > 5 AND indexstats.avg_fragmentation_in_percent < 30 THEN 'ALTER INDEX [' + dbindexes.[name] + '] ON [' + dbschemas.[name] + '].[' + dbtables.[name] + '] REORGANIZE'
16+
ELSE NULL
17+
END
18+
FROM
19+
sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL, NULL, NULL) AS indexstats
20+
INNER JOIN sys.tables dbtables on dbtables.[object_id] = indexstats.[object_id]
21+
INNER JOIN sys.schemas dbschemas on dbtables.[schema_id] = dbschemas.[schema_id]
22+
INNER JOIN sys.indexes AS dbindexes ON dbindexes.[object_id] = indexstats.[object_id] AND indexstats.index_id = dbindexes.index_id
23+
WHERE
24+
1=1
25+
AND indexstats.database_id = DB_ID()
26+
AND dbindexes.[name] IS NOT NULL
27+
--AND dbindexes.[name] = 'IX_IndexName'
28+
ORDER BY
29+
indexstats.avg_fragmentation_in_percent desc

SSDB.Create_Database_Backup.sql

Lines changed: 78 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,78 @@
1+
/*--------------------------------------------------------------------------------------------------------------------------------+
2+
| Purpose: Create a backup of a database
3+
| Example: EXEC admin.Create_Database_Backup 'db1'
4+
+--------------------------------------------------------------------------------------------------------------------------------*/
5+
6+
:setvar _server "Server1"
7+
:setvar _user "***username***"
8+
:setvar _password "***password***"
9+
:setvar _database "master"
10+
:connect $(_server) -U $(_user) -P $(_password)
11+
12+
USE [$(_database)];
13+
GO
14+
15+
CREATE PROCEDURE [admin].[Create_Database_Backup]
16+
(
17+
@DatabaseName VARCHAR(50)
18+
)
19+
AS
20+
BEGIN
21+
22+
PRINT '====================================================================='
23+
PRINT 'set the name of the database...'
24+
PRINT '====================================================================='
25+
DECLARE @SourceDB VARCHAR(50)
26+
SET @SourceDB = @DatabaseName --DB_NAME()
27+
28+
PRINT '====================================================================='
29+
PRINT 'get user name...'
30+
PRINT '====================================================================='
31+
DECLARE @BackupUser VARCHAR(255)
32+
SET @BackupUser = (substring(suser_sname(),charindex('\',suser_sname())+(1),len(suser_sname())-charindex('\',suser_sname())))
33+
34+
PRINT '====================================================================='
35+
PRINT 'get current date and time...'
36+
PRINT '====================================================================='
37+
DECLARE @DateStamp VARCHAR(20)
38+
SET @DateStamp = '_' + CONVERT(VARCHAR(20),GetDate(),112) + '_' + REPLACE(CONVERT(VARCHAR(20),GetDate(),108),':','')
39+
40+
PRINT '====================================================================='
41+
PRINT 'set database backup path...'
42+
PRINT '====================================================================='
43+
DECLARE @TargetPath VARCHAR(255)
44+
-- TO DO: Standardize the backup folder location for all servers
45+
IF @@SERVERNAME = 'Server1' SET @TargetPath = 'C:\Temp\'
46+
47+
PRINT '====================================================================='
48+
PRINT 'set the backup file name...'
49+
PRINT '====================================================================='
50+
SET @TargetPath = @TargetPath + @SourceDB + @DateStamp + '_' + @BackupUser + '.bak'''
51+
PRINT @TargetPath
52+
53+
PRINT '====================================================================='
54+
PRINT 'backup the database...'
55+
PRINT '====================================================================='
56+
IF EXISTS(SELECT NAME FROM sys.databases where name = @SourceDB)
57+
BEGIN
58+
DECLARE @BACKUP_SQL VARCHAR(MAX)
59+
SET @BACKUP_SQL =
60+
'BACKUP DATABASE ' + @SourceDB + '
61+
TO DISK = ''' + @TargetPath + '
62+
WITH FORMAT,
63+
MEDIANAME = ''' + @BackupUser + ''',
64+
NAME = ''' + @SourceDB + @DateStamp + ''''
65+
66+
PRINT @BACKUP_SQL
67+
EXEC (@BACKUP_SQL)
68+
END
69+
PRINT '====================================================================='
70+
PRINT 'Finished!'
71+
PRINT '====================================================================='
72+
73+
END
74+
75+
76+
GO
77+
78+

SSDB.Restore_Database_Backup.sql

Lines changed: 109 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,109 @@
1+
/*--------------------------------------------------------------------------------------------------------------------------------+
2+
| Purpose: Restore a backup of a database
3+
| Example: EXEC admin.Restore_Database_Backup 'db1_20130619_073701_firstname.lastname.bak', 'db1_Backup'
4+
+--------------------------------------------------------------------------------------------------------------------------------*/
5+
6+
:setvar _server "Server1"
7+
:setvar _user "***username***"
8+
:setvar _password "***password***"
9+
:setvar _database "master"
10+
:connect $(_server) -U $(_user) -P $(_password)
11+
12+
USE [$(_database)];
13+
GO
14+
15+
CREATE PROCEDURE [admin].[Restore_Database_Backup]
16+
(
17+
@FileName VARCHAR(255)
18+
, @DatabaseName VARCHAR(50)
19+
)
20+
AS
21+
BEGIN
22+
23+
PRINT '====================================================================='
24+
PRINT 'set the name and path for the restore...'
25+
PRINT '====================================================================='
26+
DECLARE @BackupFile VARCHAR(200)
27+
DECLARE @DataFile VARCHAR(200)
28+
-- TO DO: Standardize the backup folder location for all servers
29+
IF @@SERVERNAME = 'Server1' SET @BackupFile = 'C:\Temp\' + @FileName
30+
31+
PRINT '====================================================================='
32+
PRINT 'set the data path for sql server...'
33+
PRINT '====================================================================='
34+
35+
SELECT @DataFile = SUBSTRING(physical_name, 1, CHARINDEX(N'master.mdf', LOWER(physical_name)) - 1)
36+
FROM master.sys.master_files
37+
WHERE database_id = 1 AND file_id = 1
38+
39+
PRINT '====================================================================='
40+
PRINT 'get the logical names from the backup file...'
41+
PRINT '====================================================================='
42+
DECLARE @Table TABLE (
43+
[LogicalName] varchar(128)
44+
, [PhysicalName] varchar(128)
45+
, [Type] varchar
46+
, [FileGroupName] varchar(128)
47+
, [Size] varchar(128)
48+
, [MaxSize] varchar(128)
49+
, [FileId]varchar(128)
50+
, [CreateLSN]varchar(128)
51+
, [DropLSN]varchar(128)
52+
, [UniqueId]varchar(128)
53+
, [ReadOnlyLSN]varchar(128)
54+
, [ReadWriteLSN]varchar(128)
55+
, [BackupSizeInBytes]varchar(128)
56+
, [SourceBlockSize]varchar(128)
57+
, [FileGroupId]varchar(128)
58+
, [LogGroupGUID]varchar(128)
59+
, [DifferentialBaseLSN]varchar(128)
60+
, [DifferentialBaseGUID]varchar(128)
61+
, [IsReadOnly]varchar(128)
62+
, [IsPresent]varchar(128)
63+
, [TDEThumbprint]varchar(128)
64+
)
65+
66+
DECLARE @LogicalNameData varchar(128)
67+
DECLARE @LogicalNameLog varchar(128)
68+
INSERT INTO @table EXEC('RESTORE FILELISTONLY FROM DISK=''' + @BackupFile + '''')
69+
70+
SET @LogicalNameData=(SELECT LogicalName FROM @Table WHERE Type='D')
71+
SET @LogicalNameLog=(SELECT LogicalName FROM @Table WHERE Type='L')
72+
73+
PRINT '====================================================================='
74+
PRINT 'Restore the Database starting with a file from a Full Backup...'
75+
PRINT '====================================================================='
76+
BEGIN
77+
DECLARE @RESTORE_SQL VARCHAR(MAX)
78+
SET @RESTORE_SQL =
79+
'RESTORE DATABASE ' + @DatabaseName + '
80+
FROM DISK = ''' + @BackupFile + '''
81+
WITH
82+
RECOVERY
83+
, STATS = 10
84+
, MOVE ''' + @LogicalNameData + ''' TO ''' + @DataFile + @DatabaseName + '.mdf''
85+
, MOVE ''' + @LogicalNameLog + ''' TO ''' + @DataFile + @DatabaseName + '.ldf'''
86+
PRINT @RESTORE_SQL
87+
EXEC (@RESTORE_SQL)
88+
END
89+
90+
PRINT '====================================================================='
91+
PRINT 'Update owner of the database to standard...'
92+
PRINT '====================================================================='
93+
BEGIN
94+
DECLARE @OWNER_SQL VARCHAR(MAX)
95+
SET @OWNER_SQL = 'ALTER AUTHORIZATION ON DATABASE::' + @DatabaseName + ' TO sa;'
96+
PRINT @OWNER_SQL
97+
EXEC (@OWNER_SQL)
98+
END
99+
100+
PRINT '====================================================================='
101+
PRINT 'Finished!'
102+
PRINT '====================================================================='
103+
104+
END
105+
106+
107+
GO
108+
109+

SSRS.Report_Execution.sql

Lines changed: 111 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,111 @@
1+
/*'------------------------------------------------------------------------------------------------------------------
2+
| Purpose: To search the reporting services execution log
3+
| Note: SQLCmdMode Script
4+
'--------------------------------------------------------------------------------------------------------------------
5+
*/
6+
7+
DECLARE @LogStatus AS VARCHAR(50)
8+
DECLARE @ReportFolder AS VARCHAR(450)
9+
DECLARE @ReportName AS VARCHAR(450)
10+
DECLARE @UserName AS VARCHAR(260)
11+
DECLARE @GroupByColumn AS VARCHAR(50)
12+
DECLARE @StartDate AS DATETIME
13+
DECLARE @EndDate AS DATETIME
14+
15+
SET @LogStatus = '<ALL>'
16+
SET @ReportFolder = '...A Report Folder Name...'
17+
SET @ReportName = '<ALL>'
18+
SET @UserName = '<ALL>'
19+
SET @GroupByColumn = 'Report Folder'
20+
SET @StartDate = NULL
21+
SET @EndDate = NULL
22+
23+
:setvar _server "Server1"
24+
:setvar _user "***username***"
25+
:setvar _password "***password***"
26+
:setvar _database "ReportServer"
27+
:connect $(_server) -U $(_user) -P $(_password)
28+
29+
USE [$(_database)];
30+
GO
31+
32+
33+
;WITH
34+
report_execution_log
35+
AS
36+
(
37+
SELECT
38+
el.*
39+
, SimpleUserName = RIGHT(el.UserName,(LEN(el.UserName)-CHARINDEX('\',el.UserName)))
40+
, TimeStartDate = CONVERT(DATETIME, CONVERT(VARCHAR(11),el.TimeStart,13))
41+
, TotalSecondsFormat = CONVERT(CHAR(8),DATEADD(ms,(el.TimeDataRetrieval + el.TimeProcessing + el.TimeRendering),0),108)
42+
, TimeDataRetrievalFormat = CONVERT(CHAR(8),DATEADD(ms,el.TimeDataRetrieval,0),108)
43+
, TimeProcessingFormat = CONVERT(CHAR(8),DATEADD(ms,el.TimeProcessing,0),108)
44+
, TimeRenderingFormat = CONVERT(CHAR(8),DATEADD(ms,el.TimeRendering,0),108)
45+
, OrderbyDateFormat = CAST(TimeStart AS DATETIME)
46+
FROM
47+
ReportServer.dbo.ExecutionLog el
48+
)
49+
,
50+
report_catalog
51+
AS
52+
(
53+
SELECT
54+
c.ItemID
55+
, c.CreatedById
56+
, c.ModifiedById
57+
, c.[Type]
58+
, c.Name
59+
, c.[Path]
60+
, c.[Description]
61+
, c.Parameter
62+
, ReportCreationDate = CONVERT(DATETIME, CONVERT(VARCHAR(11), c.CreationDate, 13))
63+
, ReportModifiedDate = CONVERT(DATETIME, CONVERT(VARCHAR(11), c.ModifiedDate, 13))
64+
, ReportFolder =
65+
CASE
66+
WHEN c.Path = '/' + c.Name THEN ''
67+
ELSE SUBSTRING(c.Path, 2, Len(c.Path)-Len(c.Name)-2)
68+
END
69+
, ReportPath = c.[Path]
70+
, UrlPath = 'http://' + Host_Name() + '/Reports/Pages/Folder.aspx?ItemPath=%2f'
71+
, ReportDefinition = CONVERT(VARCHAR(MAX),CONVERT(VARBINARY(MAX),c.content))
72+
FROM
73+
dbo.Catalog AS c
74+
WHERE c.Type = 2
75+
)
76+
SELECT
77+
GroupBy1 = CASE
78+
WHEN @GroupByColumn = 'Report Name' THEN c.Name
79+
WHEN @GroupByColumn = 'Report Folder' THEN c.ReportFolder
80+
WHEN @GroupByColumn = 'User Id' THEN el.SimpleUserName
81+
ELSE '<N/A>' END
82+
, c.[Path]
83+
, c.ReportFolder
84+
, c.Name
85+
, URL_ReportFolder = c.UrlPath + c.ReportFolder + '&ViewMode=List'
86+
, URL_Report = c.UrlPath + c.ReportFolder + '%2f' + c.Name
87+
, URL_Report_Filtered = 'http://' + Host_Name() + '/ReportServer/ReportServer?/' + c.ReportFolder + '%2f' + c.Name + '&rs:Command=Render&' + CONVERT(VARCHAR(2000), el.Parameters)
88+
, UserName = el.SimpleUserName
89+
, el.Status
90+
, el.TimeStart
91+
, el.[RowCount]
92+
, el.ByteCount
93+
, el.Format
94+
, el.[Parameters]
95+
, TotalSeconds = el.TotalSecondsFormat
96+
, TimeDataRetrieval = el.TimeDataRetrievalFormat
97+
, TimeProcessing = el.TimeProcessingFormat
98+
, TimeRendering = el.TimeRenderingFormat
99+
, OrderbyDate = el.OrderbyDateFormat
100+
FROM
101+
report_catalog c
102+
LEFT JOIN report_execution_log el ON el.ReportID = c.ItemID
103+
WHERE
104+
1=1
105+
AND c.Name NOT IN('Report Execution Log') -- whatever the name of this report is...
106+
AND (@StartDate IS NULL OR el.TimeStartDate >= @StartDate)
107+
AND (@EndDate IS NULL OR el.TimeStartDate <= @EndDate)
108+
AND ('<ALL>' IN(@UserName) OR el.SimpleUserName IN(@UserName))
109+
AND ('<ALL>' IN(@LogStatus) OR el.[Status] IN(@LogStatus))
110+
AND ('<ALL>' IN(@ReportFolder) OR c.ReportFolder IN(@ReportFolder))
111+
AND ('<ALL>' IN(@ReportName) OR c.Name IN(@ReportName))

0 commit comments

Comments
 (0)