Permalink
Browse files

Add GatherDatabaseMetadata updated GatherTableStats and GatherTableMe…

…tadata to use fewer temp tables.
  • Loading branch information...
TexasAssetProtection committed Jun 30, 2011
1 parent df52d6c commit 2df24e50720d06156ee0d73da6b9f6123e7a32bd
Showing with 180 additions and 42 deletions.
  1. +164 −0 GatherDatabaseMetadata.sql
  2. +7 −17 Management.GatherTableMetadata.sql
  3. +9 −25 Management.GatherTableStatistics.sql
View
@@ -0,0 +1,164 @@
+/************************************************************************************************
+Metadata
+By Wesley D. Brown
+Date 06/27/2011
+
+**Description**
+This uses sys.extended_properties to pull back comments attached to columns and tables.
+It requires that MS_Description be the name of the property.
+It also pulls back all column definitions stored in the systables for for that database.
+Functions:
+**End Discription**
+**Change Log**
+Bug Fix:
+**End Change Log**
+************************************************************************************************/
+/************************************************************************************************
+* Create these tables first if they don't exist in your system.
+CREATE TABLE [dbo].[DatabaseMetadata] (
+ [ServerName] [varchar] (256),
+ [DBName] [varchar] (256),
+ [TableName] [varchar] (128),
+ [Schema] [varchar] (128),
+ [TableDescription] [varchar] (2000),
+ [RecordedDateTime] [datetime]
+)
+
+CREATE TABLE [dbo].[DatabaseMetadataHistory] (
+ [ServerName] [varchar] (256),
+ [DBName] [varchar] (256),
+ [TableName] [varchar] (128),
+ [Schema] [varchar] (128),
+ [TableDescription] [varchar] (2000),
+ [RecordedDateTime] [datetime]
+)
+************************************************************************************************/
+IF EXISTS (
+ SELECT 1
+ FROM INFORMATION_SCHEMA.ROUTINES
+ WHERE SPECIFIC_NAME = N'GatherDatabaseMetadata'
+)
+DROP PROCEDURE GatherDatabaseMetadata
+GO
+
+CREATE PROCEDURE GatherDatabaseMetadata
+ @DatabaseList VARCHAR(MAX),
+ @ExcludeSystemDatabases tinyint = 1
+AS
+ SET NOCOUNT ON
+/*****************************************
+* Truncate holding tables
+*****************************************/
+ IF EXISTS (SELECT 1
+ FROM dbo.DatabaseMetadata)
+ BEGIN
+ INSERT INTO dbo.DatabaseMetadataHistory
+ SELECT *
+ FROM DatabaseMetadata;
+
+ TRUNCATE TABLE dbo.DatabaseMetadata;
+ END
+
+ DECLARE @cmd VARCHAR(8000),
+ @table_name VARCHAR(128),
+ @servername VARCHAR(256),
+ @dbname VARCHAR(256),
+ @schemaname NVARCHAR(128),
+ @tablename NVARCHAR(128),
+ @recordeddatetime datetime
+
+ CREATE TABLE #dbnames
+ (
+ name NVARCHAR(128)
+ )
+
+ SET @recordeddatetime = GETDATE()
+ SET @servername = CAST(Serverproperty('servername') AS VARCHAR(256))
+
+ IF Upper(@DatabaseList) = 'ALL'
+ BEGIN
+ IF @ExcludeSystemDatabases = 1
+ BEGIN
+ SET @DatabaseList = '';
+
+ SELECT @DatabaseList = @DatabaseList + '''' + name + ''','
+ FROM MASTER.dbo.sysdatabases
+ WHERE name NOT IN ( 'master', 'msdb', 'model', 'pubs',
+ 'northwind', 'tempdb' );
+ END
+ ELSE
+ BEGIN
+ SELECT @DatabaseList = @DatabaseList + '''' + name + ''','
+ FROM MASTER.dbo.sysdatabases;
+ END
+
+ SET @DatabaseList = LEFT(@DatabaseList, Len(@DatabaseList) - 2) + ''''
+
+ INSERT INTO #dbnames
+ EXEC('select name from master.dbo.sysdatabases where name in ('+@DatabaseList+')')
+
+ END
+ --found at http://mangalpardeshi.blogspot.com/2009/03/how-to-split-comma-delimited-string.html
+ ;WITH Cte AS
+ (
+ select CAST('<M>' + REPLACE( @DatabaseList, ',' , '</M><M>') + '</M>' AS XML) AS DatabaseNames
+ )
+
+ insert into #dbnames
+ SELECT
+ Split.a.value('.', 'VARCHAR(100)') AS DatabaseNames
+ FROM Cte
+ CROSS APPLY DatabaseNames.nodes('/M') Split(a)
+
+ IF not exists(select 1 from #dbnames)
+ BEGIN
+ insert into #dbnames select @DatabaseList
+ END
+
+ DECLARE db CURSOR FAST_FORWARD FOR
+ SELECT name
+ FROM #dbnames
+
+ OPEN db
+
+ FETCH NEXT FROM db INTO @dbname
+
+ WHILE ( @@FETCH_STATUS <> -1 )
+ BEGIN
+ IF ( @@FETCH_STATUS <> -2 )
+ BEGIN
+ IF (SELECT CONVERT(SYSNAME, Databasepropertyex(@dbname, 'status'))
+ )
+ =
+ 'ONLINE'
+ BEGIN
+ set @cmd ='
+ insert into dbo.DatabaseMetadata
+ SELECT
+ '''+@servername+''' AS ''ServerName'',
+ '''+@dbname+''' AS ''DBName'',
+ o.name AS ''TableName'',
+ Object_schema_name(o.object_id,DB_ID('''+@dbname+''')) AS ''SchemaName'',
+ Replace(Replace(Cast(e.value AS VARCHAR(2000)), Char(13), ''''), Char(11), '''') AS ''TableDescription'',
+ '''+convert(varchar,@recordeddatetime, 121)+'''
+ FROM
+ ['+@dbname+'].sys.objects o
+ LEFT JOIN ['+@dbname+'].sys.extended_properties e
+ ON o.object_id = e.major_id
+ AND e.minor_id = 0
+ WHERE
+ o.type = ''U''
+ ORDER BY
+ Object_schema_name(o.object_id,DB_ID('''+@dbname+''')),
+ o.object_id'
+ EXEC(@cmd)
+ END
+ END
+ FETCH NEXT FROM db INTO @dbname
+ END
+
+ CLOSE db
+ DEALLOCATE db
+
+ DROP TABLE #dbnames
+ SET nocount OFF
@@ -25,7 +25,7 @@ CREATE TABLE [dbo].[TableMetadata] (
[ColumnType] [varchar] (128),
[ColumnLength] [int] ,
[ColumnDescription] [varchar] (2000),
- RecordedDateTime datetime
+ [RecordedDateTime] [datetime]
)
CREATE TABLE [dbo].[TableMetadataHistory] (
@@ -38,7 +38,7 @@ CREATE TABLE [dbo].[TableMetadataHistory] (
[ColumnType] [varchar] (128),
[ColumnLength] [int] ,
[ColumnDescription] [varchar] (2000),
- RecordedDateTime datetime
+ [RecordedDateTime] [datetime]
)
************************************************************************************************/
IF EXISTS (
@@ -49,8 +49,6 @@ IF EXISTS (
DROP PROCEDURE GatherTableMetadata
GO
-
--- exec GatherTableMetadata 'ALL',1
CREATE PROCEDURE GatherTableMetadata
@DatabaseList VARCHAR(MAX),
@ExcludeSystemDatabases tinyint = 1
@@ -77,13 +75,6 @@ AS
@tablename NVARCHAR(128),
@recordeddatetime datetime
- CREATE TABLE #tblholding
- (
- tblname VARCHAR(500),
- schemaname NVARCHAR(128),
- tablename NVARCHAR(128)
- )
-
CREATE TABLE #dbnames
(
name NVARCHAR(128)
@@ -154,8 +145,8 @@ AS
SELECT
'''+@servername+''' AS ''ServerName'',
'''+@dbname+''' AS ''DBName'',
- Object_name(o.object_id) AS ''TableName'',
- Object_schema_name(o.object_id) AS ''SchemaName'',
+ o.name AS ''TableName'',
+ Object_schema_name(o.object_id,DB_ID('''+@dbname+''')) AS ''SchemaName'',
c.column_id AS ''ColumnOrder'',
c.name AS ''ColumnName'',
s.name AS ''ColumnType'',
@@ -171,14 +162,15 @@ AS
LEFT JOIN ['+@dbname+'].sys.extended_properties e
ON c.object_id = e.major_id
AND c.column_id = e.minor_id
+ and
+ e.class = 1
WHERE
o.type = ''U''
ORDER BY
- Object_schema_name(o.object_id),
+ Object_schema_name(o.object_id,DB_ID('''+@dbname+''')),
o.object_id,
c.column_id'
EXEC(@cmd)
- print (@cmd)
END
END
FETCH NEXT FROM db INTO @dbname
@@ -188,6 +180,4 @@ AS
DEALLOCATE db
DROP TABLE #dbnames
- DROP TABLE #tblholding
-
SET nocount OFF
@@ -85,19 +85,6 @@ AS
@servername VARCHAR(256),
@dbname VARCHAR(256)
- CREATE TABLE #stats
- (
- ServerName varchar(255)
- ,DBName varchar(255)
- ,SchemaName nvarchar(128)
- ,TableName nvarchar(128)
- ,RowCounts numeric(38,0)
- ,ReservedKB numeric(38,0)
- ,DataKB numeric(38,0)
- ,IndexSizeKB numeric(38,0)
- ,UnusedKB numeric(38,0)
- ,RecordedDateTime datetime
- )
CREATE TABLE #dbnames
(
@@ -175,18 +162,18 @@ AS
CONVERT(SYSNAME, Databasepropertyex(@dbname, 'status'))) = 'ONLINE'
BEGIN
exec('
- USE ['+@dbname+']
- insert into #stats
+
+ insert into dbo.TableStats
SELECT
- '''+@servername+''' AS ServerName,
- '''+@dbname+''' AS DBName,
- Object_schema_name(object_id) AS SchemaName,
- Object_name(object_id) AS TableName,
+ '''+@servername+''' AS ServerName,
+ '''+@dbname+''' AS DBName,
+ Object_schema_name(object_id,DB_ID('''+@dbname+''')) AS SchemaName,
+ Object_name(object_id,DB_ID('''+@dbname+''')) AS TableName,
Sum(CASE
WHEN index_id < 2 THEN row_count
ELSE 0
- END) AS RowCounts,
- Sum(reserved_page_count) * 8 AS ReservedKB,
+ END) AS RowCounts,
+ Sum(reserved_page_count) * 8 AS ReservedKB,
Sum(CASE
WHEN index_id < 2 THEN in_row_data_page_count + lob_used_page_count + row_overflow_used_page_count
ELSE lob_used_page_count + row_overflow_used_page_count
@@ -202,9 +189,6 @@ AS
WHERE
Objectproperty(object_id, ''IsUserTable'') = 1
GROUP BY object_id')
- insert into dbo.TableStats
- select * from #stats
- truncate table #stats
END
END
@@ -215,6 +199,6 @@ AS
DEALLOCATE db
- DROP TABLE #stats
+ DROP TABLE #dbnames
SET nocount OFF

0 comments on commit 2df24e5

Please sign in to comment.