-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathSQLDocumenter.sql
3326 lines (2823 loc) · 154 KB
/
SQLDocumenter.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
USE tempdb
GO
IF CAST(SERVERPROPERTY('productversion') as varchar(2)) = '8.'
RAISERROR ('Version of SQL Server is not supported', 20, -1) with log;
GO
DECLARE
@DBName VARCHAR(128),
@Collation VARCHAR(50),
@ReportOnlyObjectNames TINYINT,
@CheckFunctionDependents TINYINT,
@Debug TINYINT;
SELECT @DBName = '<YOUR DATABASE NAME>',
@Collation = 'SQL_Latin1_General_CP1_CI_AS',
@ReportOnlyObjectNames = 0, /* 0/1 - That function allows to read only object names (for databases with thousands of objects) */
@CheckFunctionDependents = 0, /* 0/1 - Check for Function dependencies within Stored Procedures, Triggers and other functions */
@Debug = 0;
/********************************************************************************************************************************************************************************
#Description: Script Generates full documentation for a database
#Details:
#Contacts:
- Twitter: @SlavaSQL
- Blog: http://slavasql.blogspot.com/2013/11/stored-procedure-to-document-database.html
#Permissions: Requires at least to be a member of db_datareader role within the documented database
To perform full capacity documenting need to have also following permissions:
- VIEW DATABASE STATE (to see sizes of objects and list all tables)
- VIEW DEFINITION (To see all programmable objects)
- VIEW SERVER STATE (to see size of log file)
- To get Number of VLFs in the log file permissions have to be escalated to sysadmin role
#Tested on:
- 2016 Enterprise
- 2014 Enterprise
- 2012 Enterprise,Standard.
- 2008 R2 (SP1) Enterprise.
- 2005 Express.
#Execution:
- Procedure has to be executed under full administrative privileges
- Results of the procedure generate browsable HTML document
Script does not cover:
- function_order_columns;
- XML Schema types;
- FS = Assembly (CLR) scalar-function
- FT = Assembly (CLR) table-valued function
- IF = SQL inline table-valued function
- IT = Internal table
- PC = Assembly (CLR) stored-procedure
- PG = Plan guide
- R = Rule (old-style, stand-alone)
- RF = Replication-filter-procedure
- S = System base table
- SQ = Service queue
- TT = Table type
- TA = Assembly (CLR) DML trigger
- X = Extended stored procedure
# Procedure has not been tested with (yet):
- Columnstore indexes;
- Encrypted Code;
- filestream files/tables;
- Busy OLTP server;
- (a lot of other functionality)
# In Line:
* Index usage;
- Show that table/index is partitioned
- Search for synonym's usage.
- Hide/show lists of elements
- Add progress reporting for lists of objects bigger than 1000
- Add partitioning to statistics
- Table valued function columns
- Table valued function constraints
- Ext Properties of Functions' and Procedures' parameters.
- Synonym dependencies
- Usage of Objects from other databases.
BUG: List of Partitioned Objects has a lot of nulls.
* Move "FileGroup Name" before "Object Schema"
BUGs:
- Empty Lists of Partition functions and partition schemas
- Extended properties for parameters of stored procedures and functions are not visible
# Plans:
- user accounts;
- Spatial Indexes;
- run against linked server.
# Thanks to
Pinal Dave
Olaf Helper
#Parameters
1. @DBName (required) - database name
2. @CheckFunctionDependents - specify "1" if want to check possible function dependency (works slower)
3. @Debug - specify "1" if want to see all intermediate queries
#Example
-- Real results
DECLARE @i INT
EXEC @i = usp_Documenting_DB @DBName='TempDB'
PRINT CAST(@i AS VARCHAR)
-- Test
DECLARE @i INT
EXEC @i = usp_Documenting_DB @DBName='AdventureWorks', @Debug=1
PRINT CAST(@i AS VARCHAR)
#-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
#Cahnge History:
Vers. | Operator | Date | Action | Description
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
01.00 | Slava Murygin |2013-11-11| Creation | Initial Creation of the Stored Procedure
01.01 | Slava Murygin |2013-12-06| Fix Bug | In 2008 and earlier versions Free space in data file was calculated incorrectly (Q:0030).
01.02 | Slava Murygin |2014-01-05| Enhancement | Handle Multi-line Extended Properties (Q:0015). Added DB Schemas, Filegroups. Added showing Extended properties to all objects.
01.03 | Slava Murygin |2014-01-06| Enhancement | Show: Tables' triggers. Triggers' properties, Database Triggers. FK Reference. Table dependancy via FK.
01.04 | Slava Murygin |2014-01-07| Enhancement | Added Sever version Recognition. Show: Partition(ed) Functions, Objects, Schemas.
01.05 | Slava Murygin |2014-01-21| Enhancement | Added Error Handling. Changed to Simple script format
01.06 | Slava Murygin |2014-01-28| Fix Bug | Fix incorrect presenting of DB extended properties and Server version. Added collation issues handling.
01.07 | Slava Murygin |2014-02-05| Fix Bug | Allow script to run under server collation "SQL_AltDiction_Pref_CP850_CI_AS" + added immediate step completion.
01.08 | Slava Murygin |2014-02-05| Enhancement | Added availability to document only lists of objects (for DBs with thouthands of objects)
01.09 | Slava Murygin |2014-02-12| Enhancement | Added: hiding for object lists, Name of File Groups in the list of List of Partition Functions, table sizes.
01.10 | Slava Murygin |2014-02-12| Fix Bug | Handled Null Value in list of Partitioned objects. Exclude Diagram-Extended properies for views.
01.11 | Slava Murygin |2014-02-13| Enhancement | Added: Tables' Statistics Info; Show schema for "dependency" objects; Hiding on Objects' Details.
01.12 | Slava Murygin |2014-02-13| Enhancement | Added: DB Backups; # of VLFs;
01.13 | Slava Murygin |2014-02-15| Fix Bug | Handling of LogInf for V.2014; Not showing empty Patrition Schemas/Functions tables;
01.14 | Slava Murygin |2014-02-17| Fix Bug | Number of records in a table;
01.15 | Slava Murygin |2014-05-13| Fix Bug | DBCC LogInfo has 8 columns after SS2012;
01.16 | Slava Murygin |2014-05-16| Enhancement | Implemented Percentage tracker when @ReportOnlyObjectNames = 0 ;
01.17 | Slava Murygin |2014-05-17| Enhancement | Tuned some queries for better performance ;
01.18 | Slava Murygin |2014-05-21| Enhancement | Better handling of permission errors ;
01.19 | Slava Murygin |2014-05-21| Enhancement | DB Options; Filegroups to DB files' table; DB Logins' List; Tables' Comression;
01.20 | Slava Murygin |2014-05-21| Fix Bug | Filter cells in "Statistics" table was not handled properly;
01.21 | Slava Murygin |2014-05-21| Fix Bug | List of dependencies printed even if they are empty
01.22 | Slava Murygin |2014-05-25| Downgrading | Refubrished script to meet SQL 2005 criterias
01.23 | Slava Murygin |2018-01-28| Enhancement | Added support of SQL Server 2016
01.24 | Slava Murygin |2022-05-22| Enhancement | Added support of SQL Server 2017-19
01.25 | Slava Murygin |2024-05-16| Enhancement | Replaced use of DBCC LogInfo by "dm_db_log_info" for versions 2016+
#*******************************************************************************************************************************************************************************/
SET NOCOUNT ON
DECLARE @Results TABLE (ID INT IDENTITY(1,1), ResultRecord VARCHAR(MAX)); /* Table to collect ALL results*/
DECLARE @IntermediateResults VARCHAR(MAX); /* Used to store intermediate results before inserting into @Results table */
DECLARE @TempString NVARCHAR(MAX); /* Temporary String Variable. Mostly Used for SQL Queries */
DECLARE @Objects TABLE (
ID INT IDENTITY(1,1),
SchemaName VARCHAR(128),
SchemaID INT,
ObjectName VARCHAR(128),
ObjectID INT,
ParentObjectID INT,
Created_Dt DATETIME,
Modified_Dt DATETIME,
ObjectType CHAR(2),
ObjectType_Desc VARCHAR(60),
Ext_Property VARCHAR(MAX),
Reported TINYINT DEFAULT (0)
) ;
DECLARE @database_id INT; /* Researched Database ID */
DECLARE @object_id INT; /* Stores current Object ID */
DECLARE @SessionId CHAR(36) ; /* Unique ID for all temp objects within the SP*/
DECLARE @i INT; /* Usualy Counter */
DECLARE @TotalNumber INT, @CurrentNumber INT, @IncrementCount INT, @CntMessage VARCHAR(100); /* Set of Counters for percentage indicator */
DECLARE @10Percent INT, @5Percent INT, @NextMilestone INT; /* Percentage thresholds. if bigger than @5Percent then uses 1% threshold */
DECLARE @v TINYINT; /* UIndicate possible violations */
DECLARE @vt TABLE (ViolationID TINYINT, Violated INT DEFAULT 0);
DECLARE @OType_Desc nvarchar(128); /* Store Object Type Description */
DECLARE @OType char(2); /* Store Object Type */
DECLARE @ObjStats TABLE(StatID INT IDENTITY(1,1), ObjectTypeDesc NVARCHAR(60), ObjectType CHAR(2), ObjCnt INT); /* Object statistics */
DECLARE @Dependent TABLE(ID INT IDENTITY(1,1), [Object_id] INT NOT NULL, [Schema_Name] VARCHAR(128), [Object_Name] VARCHAR(128), ObjectTypeDesc VARCHAR(60)); /* Used to determine functions' depent objects */
DECLARE @LogInfo TABLE (RecoveryUnitId BIGINT, FileId INT, FileSize BIGINT, StartOffset BIGINT, FSeqNo BIGINT, Status BIGINT, Parity BIGINT, CreateLSN NUMERIC(38), ID INT IDENTITY(1,1)); /* Used to calculate number of VLFs */
DECLARE @Obj_Name VARCHAR(128); /* Holds Object name*/
DECLARE @ServerVersion VARCHAR(15); /* Version of SQL Server this SP is Running on */
DECLARE @ServerRelease SMALLINT; /* Version of SQL Server this SP is Running on */
DECLARE @ErrorList VARCHAR(MAX); /* List of Errors during an Execution */
DECLARE @ErrorMessage VARCHAR(2048); /* Temporary Error Variable */
DECLARE @CurrentStep CHAR(4);
/* Set Defaults (Required by 2005)*/
SELECT @i = 0,
@SessionId = REPLACE(CAST(NewID() AS CHAR(36)),'-','_'),
@ErrorList = '',
@TotalNumber = 0,
@CurrentNumber = 0,
@IncrementCount = 0,
@10Percent = 1000,
@5Percent = 10000,
@NextMilestone = 0,
@v = 0;
/*0010 Verify if Database Exists */
SET @CurrentStep = '0010';
SELECT TOP 1 @database_id = database_id FROM master.sys.databases WHERE @DBName = name
IF IsNull(@database_id,0) = 0
BEGIN
RAISERROR('Database does not Exist',16,1)
GOTO END_of_SCRIPT
END
RAISERROR ('#0010 Finished', 0, 1) WITH NOWAIT;
/*0012 Verify if SQL Server Version */
SET @CurrentStep = '0012';
SELECT @ServerVersion = CAST(SERVERPROPERTY('productversion') as VARCHAR(15)),
@ServerRelease = CAST(LEFT(@ServerVersion, PATINDEX('%.%', @ServerVersion)-1) as SMALLINT) * 10,
@ServerVersion =
CASE @ServerRelease
WHEN 90 THEN '2005'
WHEN 100 THEN '2008'
WHEN 110 THEN '2012'
WHEN 120 THEN '2014'
WHEN 130 THEN '2016'
WHEN 140 THEN '2017'
WHEN 150 THEN '2019'
ELSE CAST(@ServerRelease AS VARCHAR)
END
PRINT 'SQL Server ' + @ServerVersion
IF @ServerVersion is Null
BEGIN
RAISERROR('This Version of SQL Server is not Supported',16,1)
GOTO END_of_SCRIPT
END
RAISERROR ('#0012 Finished', 0, 1) WITH NOWAIT;
/*0014 Insert Dummy Error Record */
SET @CurrentStep = '0014';
INSERT INTO @Results(ResultRecord) VALUES(@ErrorList);
RAISERROR ('#0014 Finished', 0, 1) WITH NOWAIT;
/*0015 Collecting Extended Properties */
SET @CurrentStep = '0015';
/* Create temporary table */
SET @TempString = 'CREATE TABLE ##Temp_extended_Properties_' + @SessionId +
'(class tinyint, major_id int, minor_id int, class_desc varchar(25), value VARCHAR(MAX), PRIMARY KEY (class,major_id,minor_id))'
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
EXECUTE (@TempString);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
RAISERROR (@ErrorMessage, 16, 0);
GOTO END_of_SCRIPT
END CATCH
/* Collect Extended Properties into temporary table */
SET @TempString = '
;WITH d AS (SELECT class, major_id, minor_id, class_desc FROM ' + @DBName + '.sys.extended_properties
GROUP BY class, major_id, minor_id, class_desc HAVING COUNT(*) > 1)
INSERT INTO ##Temp_extended_Properties_' + @SessionId + '(class, major_id, minor_id, class_desc, value)
SELECT d.class, d.major_id, d.minor_id, CAST(d.class_desc as varchar(25)),
REPLACE(
SUBSTRING ((
SELECT CHAR(255) + CASE Name WHEN ''MS_Description'' THEN '''' ELSE Name + N'': '' END + CAST(Value as VARCHAR(MAX))
FROM ' + @DBName + '.sys.extended_properties as e WHERE e.major_id = d.major_id and e.minor_id = d.minor_id and e.class = d.class
and Name not like ''MS_DiagramPane%''
FOR XML PATH ('''')
),2, 8000 ), CHAR(255), ''<BR>'')
FROM d
UNION
SELECT ep.class, ep.major_id, ep.minor_id, CAST(ep.class_desc as varchar(25)),
CASE Name WHEN ''MS_Description'' THEN '''' ELSE Name + N'': '' END + CAST(Value as VARCHAR(MAX)) COLLATE ' + @Collation + '
FROM ' + @DBName + '.sys.extended_properties as ep
LEFT JOIN d ON ep.major_id = d.major_id and ep.minor_id = d.minor_id and ep.class = d.class
WHERE d.class is Null;';
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
RAISERROR ('#0015 Finished', 0, 1) WITH NOWAIT;
/*0020 Collecting General Server Information */
SET @CurrentStep = '0020';
INSERT INTO @Results(ResultRecord) VALUES
('<html><head></head>');
INSERT INTO @Results(ResultRecord) VALUES
('<script language=javascript>');
INSERT INTO @Results(ResultRecord) VALUES
('function HideShowCode(hs,ObjectHS){if (hs==0) {document.getElementById(ObjectHS).style.display="none";} else {document.getElementById(ObjectHS).style.display="block";}}');
INSERT INTO @Results(ResultRecord) VALUES
('</script>');
INSERT INTO @Results(ResultRecord) VALUES
('<body><Center>' +
'<H1>Full Database Documentation</H1>' +
'<H2>For Database "' + @DBName + '" (Database ID = ' + CAST(@database_id as VARCHAR) + ' )</H2>');
SET @TempString = '
SELECT TOP 1 ''<TABLE><TR><TD VALIGN="TOP"><H3>DB Description: </H3></TD><TD><H4>'' + value + ''</H4></TD></TR></TABLE>''
FROM ##Temp_extended_Properties_' + @SessionId + '
WHERE class = 0;';
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @Results(ResultRecord) EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
INSERT INTO @Results(ResultRecord)
VALUES
('</Center><H3>SQL server Name "' + @@Servername + '"</H3>' +
'<B>SQL Server Version:</B><BR/><pre>' + REPLACE(@@VERSION,CHAR(10),'<BR>') + '</pre>' +
'<H2>Database Highlights:</H2>')
RAISERROR ('#0020 Finished', 0, 1) WITH NOWAIT;
/*0022 Collecting DB Options Information */
SET @CurrentStep = '0022';
INSERT INTO @Results(ResultRecord)
VALUES ('<table border=1 cellpadding=5 style="font-weight:bold;"><TR><TH>Database Option</TH><TH>Option''s Value</TH><TH>Database Option</TH><TH>Option''s Value</TH></TR>' ) ;
SET @TempString = '
SELECT
''<TR>'' +
''<TD>Database ID</TD><TD ALIGN="CENTER">'' + CAST(database_id as VARCHAR) + ''</TD>'' +
''<TD>Creation Date</TD><TD>'' + CONVERT(VARCHAR,create_date,120) + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>READ_ONLY</TD><TD ALIGN="CENTER">'' + CASE is_read_only WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>DB State</TD><TD>'' + state_desc + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>DB_ENCRYPTED</TD><TD ALIGN="CENTER">'' + CASE ' + CASE WHEN @ServerRelease >= 100 THEN 'is_encrypted' ELSE '0' END +
' WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>User Access</TD><TD>'' + user_access_desc COLLATE SQL_Latin1_General_CP1_CI_AS + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>AUTO_SHRINK</TD><TD ALIGN="CENTER">'' + CASE is_auto_shrink_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>DB recovery model</TD><TD>'' + recovery_model_desc + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>DB IN Standby</TD><TD ALIGN="CENTER">'' + CASE is_in_standby WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>DB Collation</TD><TD>'' + collation_name + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>ANSI_NULLS</TD><TD ALIGN="CENTER">'' + CASE is_ansi_nulls_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>AUTO_CREATE_STATISTICS</TD><TD>'' + CASE is_auto_create_stats_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>ANSI_NULL_DEFAULT</TD><TD ALIGN="CENTER">'' + CASE is_ansi_null_default_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>AUTO_UPDATE_STATISTICS</TD><TD>'' + CASE is_auto_update_stats_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>ANSI_WARNINGS</TD><TD ALIGN="CENTER">'' + CASE is_ansi_warnings_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>AUTO_UPDATE_STATISTICS_ASYNC</TD><TD>'' + CASE is_auto_update_stats_async_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>QUOTED_IDENTIFIER</TD><TD ALIGN="CENTER">'' + CASE is_quoted_identifier_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>READ_COMMITTED_SNAPSHOT</TD><TD>'' + CASE is_read_committed_snapshot_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>ANSI_PADDING</TD><TD ALIGN="CENTER">'' + CASE is_ansi_padding_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>ALLOW_SNAPSHOT_ISOLATION</TD><TD>'' + CASE snapshot_isolation_state WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>DB Is cleanly shutdown</TD><TD ALIGN="CENTER">'' + CASE is_cleanly_shutdown WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>FORCED_PARAMETRIZATION</TD><TD>'' + CASE is_parameterization_forced WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>FULL-TEXT</TD><TD ALIGN="CENTER">'' + CASE is_fulltext_enabled WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>CONCAT_NULL_YIELDS_NULL</TD><TD>'' + CASE is_concat_null_yields_null_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>SUPPLEMENTAL_LOGGING</TD><TD ALIGN="CENTER">'' + CASE is_supplemental_logging_enabled WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>Log Reuse</TD><TD>'' + log_reuse_wait_desc + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>RECURSIVE_TRIGGERS</TD><TD ALIGN="CENTER">'' + CASE is_recursive_triggers_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>DB_ENCRYPTED_MASTER_KEY</TD><TD>'' + CASE is_master_key_encrypted_by_server WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>CURSOR_DEFAULT</TD><TD ALIGN="CENTER">'' + CASE is_local_cursor_default WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>CURSOR_CLOSE_ON_COMMIT</TD><TD>'' + CASE is_cursor_close_on_commit_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>DB_BROKER</TD><TD ALIGN="CENTER">'' + CASE is_broker_enabled WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>HONOR_BROKER_PRIORITY</TD><TD>'' + CASE ' + CASE WHEN @ServerRelease >= 100 THEN 'is_honor_broker_priority_on' ELSE '0' END +
' WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>DB_CHAINING</TD><TD ALIGN="CENTER">'' + CASE is_db_chaining_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>REPLICATION_SUBSCRIPTION_DB</TD><TD>'' + CASE is_subscribed WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>ARITHABORT</TD><TD ALIGN="CENTER">'' + CASE is_arithabort_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>REPLICATION_PUBLICATION_DB</TD><TD>'' + CASE is_published WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>NUMERIC_ROUNDABORT</TD><TD ALIGN="CENTER">'' + CASE is_numeric_roundabort_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>MERGE_REPLICATION_PUBLICATION_DB</TD><TD>'' + CASE is_merge_published WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>TRUSTWORTHY</TD><TD ALIGN="CENTER">'' + CASE is_trustworthy_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>REPLICATION_DISTRIBUTION_DB</TD><TD>'' + CASE is_distributor WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>AUTO_CLOSE</TD><TD ALIGN="CENTER">'' + CASE is_auto_close_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>MARKED_FOR_REPLICATION_BACKUP_SYNC</TD><TD>'' + CASE is_sync_with_backup WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>CHANGE_DATA_CAPTURE</TD><TD ALIGN="CENTER">'' + CASE ' + CASE WHEN @ServerRelease >= 100 THEN 'is_cdc_enabled' ELSE '0' END +
' WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''<TD>PAGE_VERIFY</TD><TD style="color:'' + CASE page_verify_option_desc WHEN ''CHECKSUM'' THEN ''GREEN'' ELSE ''RED'' END + '';">'' + page_verify_option_desc + ''</TD>'' +
''</TR>'' +
''<TR>'' +
''<TD>COMPATIBILITY LEVEL</TD><TD ALIGN="CENTER" style="color:'' +
CASE WHEN compatibility_level < ' + CAST(@ServerRelease as VARCHAR) + ' THEN ''RED'' ELSE ''GREEN'' END + '';">'' +
CASE compatibility_level WHEN 80 THEN ''2000'' WHEN 90 THEN ''2005'' WHEN 100 THEN ''2008'' WHEN 110 THEN ''2012'' WHEN 120 THEN ''2014'' ELSE ''N/A'' END +
''</TD>'' +
''<TD>DATE_CORRELATION_OPTIMIZATION</TD><TD>'' + CASE is_date_correlation_on WHEN 0 THEN ''<FONT COLOR="BLUE">OFF</FONT>'' ELSE ''<FONT COLOR="GREEN">ON</FONT>'' END + ''</TD>'' +
''</TR>''
FROM sys.databases
WHERE name = ''' + @DBName + ''';';
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @Results(ResultRecord) EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
INSERT INTO @Results(ResultRecord) VALUES ('</TABLE>');
RAISERROR ('#0022 Finished', 0, 1) WITH NOWAIT;
/*0024 Collecting Information About Backups */
SET @CurrentStep = '0025';
INSERT INTO @Results(ResultRecord)
VALUES ('<H3>Database Backups:</H3>' +
'<Table border=1 cellpadding=5><TR><TH>Backup Type</TH><TH>Last time Taken</TH></TR>' ) ;
SET @TempString = '
;WITH t as (
SELECT ''D'' as BU_Type, ''Database'' as BU_Type_Description
UNION ALL SELECT ''I'', ''Differential database''
UNION ALL SELECT ''L'', ''Log''
UNION ALL SELECT ''F'', ''File or filegroup''
UNION ALL SELECT ''G'', ''Differential file''
UNION ALL SELECT ''P'', ''Partial''
UNION ALL SELECT ''Q'', ''Differential partial''
)
SELECT ''<TR><TD>'' + t.BU_Type_Description + ''</TD><TD>'' +
IsNull(CONVERT(VARCHAR,MAX(backup_finish_date),120),''Never'') + ''</TD></TR>''
FROM t LEFT JOIN msdb.dbo.backupset as b
ON t.BU_Type = b.type and b.Database_name = ''' + @DBName + '''
GROUP BY t.BU_Type_Description
ORDER BY t.BU_Type_Description;';
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @Results(ResultRecord) EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
INSERT INTO @Results(ResultRecord) VALUES ('</TABLE>');
RAISERROR ('#0021 Finished', 0, 1) WITH NOWAIT;
/*0025 Collecting General Information About File Groups */
SET @CurrentStep = '0025';
INSERT INTO @Results(ResultRecord)
VALUES ('<H3>Database Filegroups:</H3>' +
'<Table border=1 cellpadding=5><TR><TH>ID</TH><TH>Filegroup Name</TH><TH>FileGroup Type</TH><TH>Is Default</TH><TH>Used for<BR>full-text index</TH><TH>Is Read-Only</TH><TH>Files in<BR>Filegroup</TH><TH>Description</TH></TR>' ) ;
SET @TempString = '
;WITH CNT as (SELECT Groupid, COUNT(*) AS "Count" FROM ' + @DBName + '.sys.sysfiles GROUP BY Groupid)
SELECT ''<TR><TD align="CENTER">'' + CAST(fg.data_space_id as varchar) + ''</TD><TD>'' + fg.name COLLATE ' + @Collation + ' + ''</TD><TD>'' +
CASE [type]
WHEN ''FG'' THEN ''Filegroup''
WHEN ''PS'' THEN ''Partition scheme''
WHEN ''FD'' THEN ''FILESTREAM data filegroup''
END + ''</TD><TD align="CENTER">'' +
CASE is_default WHEN 1 THEN ''YES'' ELSE ''NO'' END + ''</TD><TD align="CENTER">'' + '
+ CASE WHEN @ServerVersion >= '2012' THEN 'CASE is_system WHEN 1 THEN ''YES'' ELSE ''NO'' END + '
ELSE '''N/A'' + ' END +
'''</TD><TD align="CENTER">'' +
CASE is_read_only WHEN 1 THEN ''YES'' ELSE ''NO'' END + ''</TD><TD align="CENTER">'' +
CAST(IsNull(CNT.[Count],0) as varchar) + ''</TD><TD>'' + IsNull(e.value,'' '') + ''</TD></TR>''
FROM ' + @DBName + '.sys.filegroups as fg
LEFT JOIN CNT ON CNT.Groupid = fg.data_space_id
LEFT JOIN ##Temp_extended_Properties_' + @SessionId + ' as e ON e.class = 20 and e.major_id = fg.data_space_id;';
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @Results(ResultRecord) EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
INSERT INTO @Results(ResultRecord)
VALUES ('</TABLE>');
RAISERROR ('#0025 Finished', 0, 1) WITH NOWAIT;
/*0030 Collecting General Information About Data Files */
SET @CurrentStep = '0030';
INSERT INTO @Results(ResultRecord) VALUES
('<H3>Database Files:</H3>');
INSERT INTO @Results(ResultRecord) VALUES
('<Table border=1 cellpadding=5><TR><TH>File<BR>ID</TH><TH>File Group</TH><TH>File Name</TH><TH>Physical Name</TH>');
INSERT INTO @Results(ResultRecord) VALUES
('<TH>Max File<BR>Size in GB</TH><TH>File<BR>Grow by</TH><TH>File Size<BR>in MB</TH><TH>Used Space<BR>in MB</TH><TH>Description</TH></TR> ' ) ;
SET @TempString =
'USE [' + @DBName + ']; SELECT ''<TR><TD ALIGN="CENTER">'' + CAST(file_id as VARCHAR) + ''</TD><TD>'' +
g.name COLLATE ' + @Collation + ' + ''</TD><TD>'' +
f.name COLLATE ' + @Collation + ' + ''</TD><TD>'' + f.physical_name + ''</TD><TD align="RIGHT">'' +
CASE WHEN f.max_size < 0 THEN ''Unlimited'' ELSE CAST(CAST(ROUND(f.max_size/ (1024. * 128.),3) AS DECIMAL(11,3)) AS VARCHAR) END
+ ''</TD><TD align="RIGHT">'' + CASE is_percent_growth WHEN 0 THEN CASE
WHEN f.growth < 128 THEN CAST(f.growth * 8 AS VARCHAR) + ''KB''
WHEN f.growth < 131072 THEN CAST(CAST(ROUND(f.growth /128.,3) AS DECIMAL(12,3)) AS VARCHAR) + ''MB''
ELSE CAST(CAST(ROUND(f.growth /131072.,3) AS DECIMAL(12,3)) AS VARCHAR) + ''GB'' END
ELSE CAST(f.growth AS VARCHAR) + ''%'' END + ''</TD><TD align="RIGHT">'' +
CAST(CAST(ROUND(f.size/128.,3) AS DECIMAL(11,3)) AS VARCHAR) + ''</TD><TD align="RIGHT">'' +
CAST(CAST(ROUND((FILEPROPERTY(f.name, ''SpaceUsed''))/128.,3) AS DECIMAL(11,3)) AS VARCHAR) + ''</TD><TD>'' + IsNull(e.value,'' '') + ''</TD></TR>''
FROM sys.database_files as f INNER JOIN sys.filegroups as g ON f.data_space_id = g.data_space_id
LEFT JOIN ##Temp_extended_Properties_' + @SessionId + ' as e ON e.class = 22 and e.major_id = f.file_id
WHERE f.type_desc != ''LOG''; ';
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @Results(ResultRecord) EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
RAISERROR ('#0030 Finished', 0, 1) WITH NOWAIT;
/*0040 Collecting General Information About Log Files */
SET @CurrentStep = '0040';
SET @TempString = CASE WHEN @ServerRelease < 130
THEN 'DBCC LogInfo(''' + @DBName + ''');'
ELSE 'SELECT 0, 0, 0, 0, 0, 0, 0 FROM sys.dm_db_log_info(' + CAST(@database_id as VARCHAR(10)) + ')' END
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
IF @ServerVersion = 2012
INSERT INTO @LogInfo(RecoveryUnitId, FileId, FileSize, StartOffset, FSeqNo, Status, Parity, CreateLSN)
EXEC (@TempString);
ELSE
INSERT INTO @LogInfo(FileId, FileSize, StartOffset, FSeqNo, Status, Parity, CreateLSN)
EXEC (@TempString);
SET @i = @@IDENTITY;
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
SET @i = 0;
END CATCH
END CATCH
RAISERROR ('#0040 Finished', 0, 1) WITH NOWAIT;
SET @CurrentStep = '0041';
SET @TempString = 'SELECT @IntermediateResults = CAST(CAST(ROUND(cntr_value/1024.,3) AS DECIMAL(11,3)) AS VARCHAR) FROM sys.dm_os_performance_counters
WHERE counter_name = ''Log File(s) Used Size (KB)'' AND instance_name = @DBName;'
BEGIN TRY
/* If user do not have permissions to read Log File size there will be an error resulting "N/A" for Log file size */
EXEC sp_executesql @TempString,
N'@DBName VARCHAR(128), @IntermediateResults VARCHAR(30) OUTPUT',
@DBName = @DBName,
@IntermediateResults = @IntermediateResults OUTPUT;
END TRY
BEGIN CATCH
SET @IntermediateResults = 'N/A';
END CATCH
SET @TempString =
'SELECT ''<TR><TD ALIGN="CENTER">'' + CAST(f.file_id as VARCHAR) + ''</TD><TD> </TD><TD>'' + f.name + ''</TD><TD>'' + f.physical_name + ''</TD><TD align="RIGHT">'' +
CASE WHEN max_size < 0 THEN ''Unlimited'' ELSE CAST(CAST(ROUND(max_size/ (1024. * 128.),3) AS DECIMAL(11,3)) AS VARCHAR) END
+ ''</TD><TD align="RIGHT">'' + CASE is_percent_growth WHEN 0 THEN CASE
WHEN growth < 128 THEN CAST(growth * 8 AS VARCHAR) + ''KB''
WHEN growth < 131072 THEN CAST(CAST(ROUND(growth /128.,3) AS DECIMAL(12,3)) AS VARCHAR) + ''MB''
ELSE CAST(CAST(ROUND(growth /131072.,3) AS DECIMAL(12,3)) AS VARCHAR) + ''GB'' END
ELSE CAST(growth AS VARCHAR) + ''%'' END + ''</TD><TD align="RIGHT">'' +
CAST(CAST(ROUND(f.size/128.,3) AS DECIMAL(11,3)) AS VARCHAR) + ''</TD><TD align="RIGHT">'' + ''' +
@IntermediateResults + ''' + ''</TD><TD ALIGN="CENTER">'' +
CASE WHEN ' + CAST(@i as VARCHAR) + ' = 0 THEN ''Error'' ELSE ''# of VLFs: ' + CAST(@i as VARCHAR) + ''' END + ''</TD></TR></TABLE>''
FROM ' + @DBName + '.sys.database_files f WHERE TYPE = 1; ';
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @Results(ResultRecord) EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
RAISERROR ('#0041 Finished', 0, 1) WITH NOWAIT;
/*0050 Collect list of all Objects */
SET @CurrentStep = '0050';
SET @TempString = '
SELECT sname, schema_id, oname, object_id, parent_object_id, create_date, modify_date, Type, type_desc, EPValue
FROM (
SELECT s.name as sname, o.schema_id, o.name as oname, o.object_id, o.parent_object_id, o.create_date, o.modify_date, o.Type, o.type_desc, IsNull(e.value,'' '') as EPValue,
CASE Type WHEN ''U'' THEN 0 WHEN ''V'' THEN 15 WHEN ''P'' THEN 10 WHEN ''FN'' THEN 20 WHEN ''TF'' THEN 30 WHEN ''TR'' THEN 40 WHEN ''SN'' THEN 45
WHEN ''D'' THEN 50 WHEN ''C'' THEN 60 WHEN ''UQ'' THEN 70 WHEN ''PK'' THEN 80 WHEN ''F'' THEN 90 ELSE 200 END as SortOrder
FROM ' + @DBName + N'.sys.objects as o
INNER JOIN ' + @DBName + N'.sys.schemas as s ON o.schema_id = s.schema_id
LEFT JOIN ##Temp_extended_Properties_' + @SessionId + ' as e ON o.object_id = e.major_id and e.minor_id = 0
UNION
SELECT ''N/A'', 0, t.name, t.object_id, Null, t.create_date, t.modify_date, t.Type, t.type_desc, IsNull(e.value,'' ''),
CASE Type WHEN ''U'' THEN 0 WHEN ''V'' THEN 15 WHEN ''P'' THEN 10 WHEN ''FN'' THEN 20 WHEN ''TF'' THEN 30 WHEN ''TR'' THEN 40 WHEN ''SN'' THEN 45
WHEN ''D'' THEN 50 WHEN ''C'' THEN 60 WHEN ''UQ'' THEN 70 WHEN ''PK'' THEN 80 WHEN ''F'' THEN 90 ELSE 200 END as SortOrder
FROM ' + @DBName + N'.sys.triggers as t
LEFT JOIN ##Temp_extended_Properties_' + @SessionId + ' as e ON t.object_id = e.major_id and e.minor_id = 0 and e.class = 1
WHERE t.parent_class = 0
) a ORDER BY SortOrder, oname, sname;';
-- ORDER BY CASE ObjectType WHEN 'P' THEN 1 WHEN 'FN' THEN 2 WHEN 'TF' THEN 3 WHEN 'TR' THEN 4 END
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @Objects(SchemaName, SchemaID, ObjectName, ObjectID, ParentObjectID, Created_Dt, Modified_Dt, ObjectType, ObjectType_Desc, Ext_Property)
EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
RAISERROR ('#0050 Finished', 0, 1) WITH NOWAIT;
/*0060 Collect list of User Defined Data Types */
SET @CurrentStep = '0060';
SET @TempString = '
SELECT s.name, u.schema_id, u.name, 0, u.user_type_id, ''UD'', ''USER DEFINED DATA TYPES'', IsNull(CAST(e.value as varchar(256)),'' '')
FROM ' + @DBName + '.sys.types as u
INNER JOIN ' + @DBName + '.sys.types as t ON t.user_type_id = u.system_type_id and u.is_user_defined = 1
INNER JOIN ' + @DBName + '.sys.schemas as s ON u.schema_id = s.schema_id
LEFT JOIN ##Temp_extended_Properties_' + @SessionId + ' as e ON u.user_type_id = e.major_id and e.minor_id = 0 and e.class = 6
ORDER BY u.name;';
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @Objects(SchemaName, SchemaID, ObjectName, ObjectID, ParentObjectID,ObjectType, ObjectType_Desc, Ext_Property) EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
IF @Debug = 1 SELECT * FROM @Objects ORDER BY ObjectType, ObjectName, ObjectID
RAISERROR ('#0060 Finished', 0, 1) WITH NOWAIT;
/*0065 Collect schema names */
SET @CurrentStep = '0065';
SET @TempString =
'SELECT ''SCHEMA'', ''SC'', Count(*) FROM ' + @DBName + '.sys.schemas WHERE schema_id < 16384;';
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @ObjStats(ObjectTypeDesc, ObjectType, ObjCnt) EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
RAISERROR ('#0065 Finished', 0, 1) WITH NOWAIT;
/*0070 Collect Objects' Statistics */
SET @CurrentStep = '0070';
BEGIN TRY
INSERT INTO @ObjStats(ObjectTypeDesc, ObjectType, ObjCnt)
SELECT ObjectType_Desc, ObjectType, COUNT(*)
FROM @Objects
GROUP BY ObjectType, ObjectType_Desc
ORDER BY (
CASE ObjectType
WHEN 'U' THEN 0
WHEN 'V' THEN 15
WHEN 'P' THEN 10
WHEN 'FN' THEN 20
WHEN 'TF' THEN 30
WHEN 'TR' THEN 40
WHEN 'SN' THEN 45
WHEN 'D' THEN 50
WHEN 'C' THEN 60
WHEN 'UQ' THEN 70
WHEN 'PK' THEN 80
WHEN 'F' THEN 90
ELSE 200
END
);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
RAISERROR ('#0070 Finished', 0, 1) WITH NOWAIT;
/*0075 Collect Number of Partition Objects */
SET @CurrentStep = '0075';
SET @TempString = '
SELECT ''PARTITION FUNCTIONS'', CASE NAME WHEN '''' THEN '''' ELSE ''PF'' END, COUNT(*) FROM ' + @DBName + '.sys.partition_functions GROUP BY CASE NAME WHEN '''' THEN '''' ELSE ''PF'' END
UNION ALL
SELECT ''PARTITION SCHEMES'', CASE NAME WHEN '''' THEN '''' ELSE ''PS'' END, COUNT(*) FROM ' + @DBName + '.sys.partition_schemes GROUP BY CASE NAME WHEN '''' THEN '''' ELSE ''PS'' END;' ;
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @ObjStats(ObjectTypeDesc, ObjectType, ObjCnt) EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#0210)<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
RAISERROR ('#0075 Finished', 0, 1) WITH NOWAIT;
/*0080 Collect Indexes if any */
SET @CurrentStep = '0080';
SET @TempString =
'SELECT i.type_desc + '' INDEXES'', ''IX'', Count(*)
FROM ' + @DBName + '.sys.indexes i
INNER JOIN ' + @DBName + '.sys.objects o ON o.object_id = i.object_id
WHERE o.type = ''U'' and i.type_desc IN (''CLUSTERED'', ''NONCLUSTERED'')
GROUP BY i.type_desc;';
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @ObjStats(ObjectTypeDesc, ObjectType, ObjCnt) EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
RAISERROR ('#0080 Finished', 0, 1) WITH NOWAIT;
/*0090 Check if any XML Schema Collection exist */
SET @CurrentStep = '0090';
SET @TempString = '
SELECT ''XML SCHEMA COLLECTIONS'', ''XC'', COUNT(*)
FROM ' + @DBName + '.sys.xml_schema_collections as x
INNER JOIN ' + @DBName + '.sys.schemas as s on s.schema_id = x.schema_id
WHERE x.name != ''sys'' HAVING COUNT(*) > 0;'
IF @Debug = 1 PRINT @TempString;
BEGIN TRY
INSERT INTO @ObjStats(ObjectTypeDesc, ObjectType, ObjCnt) EXECUTE (@TempString);
END TRY
BEGIN CATCH
SET @ErrorMessage = ERROR_MESSAGE();
BEGIN TRY
RAISERROR (@ErrorMessage, 16, 0);
END TRY
BEGIN CATCH
PRINT @TempString; PRINT ERROR_MESSAGE();
SELECT @ErrorList = @ErrorList +
'ErrorLine: ' + CAST(ERROR_LINE ()-8 as VARCHAR) + ' (#' + @CurrentStep + ')<BR>' +
'ErrorMessage: "' + ERROR_MESSAGE() + '"<BR><BR>';
END CATCH
END CATCH
INSERT INTO @Results(ResultRecord)
VALUES ('<H2>Objects'' Statistics:</H2>' +
'<TABLE border=1 cellpadding=5>' +
'<TR><TH>Object Type</TH><TH>Count</TH>' +
'<TH>Object Type</TH><TH>Count</TH>' +
'<TH>Object Type</TH><TH>Count</TH></TR>');
RAISERROR ('#0090 Finished', 0, 1) WITH NOWAIT;
/*0100 Generate content of Object statistic table */
SET @CurrentStep = '0100';
BEGIN TRY
;WITH Devided AS (
SELECT *, (ROW_NUMBER() over(order by StatID)+2) % 3 as ObjOrder
FROM @ObjStats
)
INSERT INTO @Results(ResultRecord)
SELECT
CASE ObjOrder WHEN 0 THEN '<TR>' ELSE '' END + '<TD>' +
CASE WHEN ObjectType IN ('U','P','FN','TF','TR','V','SN','UD','XC','SC','PS','PF')
THEN '<A HREF="#' + CASE
WHEN ObjectType = 'U' THEN 'Table'
WHEN ObjectType = 'P' THEN 'Proc'
WHEN ObjectType = 'V' THEN 'View'
WHEN ObjectType = 'TR' THEN 'Trig'
WHEN ObjectType = 'SN' THEN 'Syn'
WHEN ObjectType = 'UD' THEN 'UDDT'
WHEN ObjectType = 'XC' THEN 'XSC'
WHEN ObjectType = 'SC' THEN 'SCHEMA'
WHEN ObjectType = 'PF' THEN 'PartFunc'
WHEN ObjectType = 'PS' THEN 'PartSchema'
ELSE 'Func'