Technical Article

The Ultimate Table Searcher Mk2

,

*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=
Util_TableSearch Mk2
By Jesse Roberge - YeshuaAgapao@Yahoo.com

Searches for tables who's names contain the search string. Gives Aggregate Size, Rows, Index, and Column information as well.
LIKE wildcards are not automatic, which allows for easy 'begins with', 'ends with', and 'equal to' queries.
Improvements from Mk1: Added PartitionCount, IndexCount, ColumnCount, TotalMaxColumnLength, HasPrimaryKey, and HasClusteredIndex.
Requires the VIEW DATABASE STATE database permission.

Update 2009-01-14:
Fixed Rows Output - Was being erroneously multiplied by (1+#NonClusteredIndexes)
SUM(Rows) Should be SUM(CASE WHEN index_id BETWEEN 0 AND 1 THEN row_count ELSE 0 END)

Update 2009-09-21:
Added HasUniqueIndex, ClusteredIndexIsUnique, PrimaryKeyIsClustered, and NonPKUniqueIndexCount.
Added searching of indexed (materialized; has a clustered index) views
Added searching of system tables

Update 2009-10-01:
Fixed system object searching (Catelog views do not have sys.dm_db_partition_stats entries)
Added optional output of non-materialized virtual table objects
Size and index output columns will be NULL for these.
All system catelog views and DMVs are non-materialized.

Required Input Parameters:
@TableName sysname Filters tables. Can use LIKE wildcards. All tables if blank.

Optional Input Parameters:
@SchemaName sysname='' Filters schemas. Can use LIKE wildcards. All schemas if blank.
@VirtualTables TinyInt=0 Search virutal tables (views, table-valued functions) - Size and Index output will be NULL for these
@UserOjbects TinyInt=1 Search user objects
@SystemObjects TinyInt=0 Search system objects

Usage
EXECUTE Util_TableSearch '%mpi%'
EXECUTE Util_TableSearch @SchemaName='dbo', @TableName='%order%'

Copyright:
Licensed under the L-GPL - a weak copyleft license - you are permitted to use this as a component of a proprietary database and call this from proprietary software.
Copyleft lets you do anything you want except plagarize, conceal the source, proprietarize modifications, or prohibit copying & re-distribution of this script/proc.

This program is free software: you can redistribute it and/or modify
it under the terms of the GNU Lesser General Public License as
published by the Free Software Foundation, either version 3 of the
License, or (at your option) any later version.

This program is distributed in the hope that it will be useful,
but WITHOUT ANY WARRANTY; without even the implied warranty of
MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
GNU Lesser General Public License for more details.

see <http://www.fsf.org/licensing/licenses/lgpl.html> for the license text.

*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=

SET ANSI_NULLS ON
SET QUOTED_IDENTIFIER ON
SET ANSI_PADDING ON
GO

IF OBJECT_ID('Util.Util_TableSearch', 'P') IS NOT NULL DROP PROCEDURE Util.Util_TableSearch
GO

/**
*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=
Util_TableSearch Mk2
By Jesse Roberge - YeshuaAgapao@Yahoo.com

Searches for tables who's names contain the search string.  Gives Aggregate Size, Rows, Index, and Column information as well.
LIKE wildcards are not automatic, which allows for easy 'begins with', 'ends with', and 'equal to' queries.
Improvements from Mk1: Added PartitionCount, IndexCount, ColumnCount, TotalMaxColumnLength, HasPrimaryKey, and HasClusteredIndex.
Requires the VIEW DATABASE STATE database permission.

Update 2009-01-14:
Fixed Rows Output - Was being erroneously multiplied by (1+#NonClusteredIndexes)
SUM(Rows) Should be SUM(CASE WHEN index_id BETWEEN 0 AND 1 THEN row_count ELSE 0 END)

Update 2009-09-21:
Added HasUniqueIndex, ClusteredIndexIsUnique, PrimaryKeyIsClustered, and NonPKUniqueIndexCount.
Added searching of indexed (materialized; has a clustered index) views
Added searching of system tables

Update 2009-10-01:
Fixed system object searching (Catelog views do not have sys.dm_db_partition_stats entries)
Added optional output of non-materialized virtual table objects
Size and index output columns will be NULL for these.
All system catelog views and DMVs are non-materialized.

Required Input Parameters:
@TableName sysnameFilters tables.  Can use LIKE wildcards.  All tables if blank.

Optional Input Parameters:
@SchemaName sysname=''Filters schemas.  Can use LIKE wildcards.  All schemas if blank.
@VirtualTables TinyInt=0Search virutal tables (views, table-valued functions) - Size and Index output will be NULL for these
@UserOjbects TinyInt=1Search user objects
@SystemObjects TinyInt=0Search system objects

Usage
EXECUTE Util_TableSearch '%mpi%'
EXECUTE Util_TableSearch @SchemaName='dbo', @TableName='%order%'

Copyright:
Licensed under the L-GPL - a weak copyleft license - you are permitted to use this as a component of a proprietary database and call this from proprietary software.
Copyleft lets you do anything you want except plagarize, conceal the source, proprietarize modifications, or prohibit copying & re-distribution of this script/proc.

This program is free software: you can redistribute it and/or modify
    it under the terms of the GNU Lesser General Public License as
    published by the Free Software Foundation, either version 3 of the
    License, or (at your option) any later version.

    This program is distributed in the hope that it will be useful,
    but WITHOUT ANY WARRANTY; without even the implied warranty of
    MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
    GNU Lesser General Public License for more details.

    see <http://www.fsf.org/licensing/licenses/lgpl.html> for the license text.

*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=
**/
CREATE PROCEDURE Util.Util_TableSearch
@TableName sysname,
@SchemaName sysname='',
@VirtualTables TinyInt=0,
@UserObjects TinyInt=1,
@SystemObjects TinyInt=0
AS

--Table Search (Name)
SELECT
objects.system_object,
schemas.schema_id, objects.object_id,
schemas.name AS schema_name, objects.name AS object_name,
objects.type, objects.type_desc,
partitions.PartitionCount, partitions.Rows,
partitions.SizeMB, partitions.SizeMBIndexes,
indexes.NonClusteredIndexCount,
columns.ColumnCount, columns.TotalMaxColumnLength,
indexes.HasUniqueIndex, indexes.HasPrimarykey,
indexes.HasClusteredIndex, CASE WHEN indexes.HasClusteredIndex=1 THEN indexes.ClusteredIndexIsUnique END AS ClusteredIndexIsUnique,
CASE WHEN indexes.HasPrimarykey=1 AND indexes.HasClusteredIndex=1 THEN indexes.PrimaryKeyIsClustered END AS PrimaryKeyIsClustered,
indexes.NonPKUniqueIndexCount
FROM
(
SELECT 0 AS system_object, object_id, name, schema_id, type, type_desc, parent_object_id
FROM sys.objects
WHERE
1=@UserObjects
AND (@VirtualTables=1 AND objects.type IN ('IF', 'IT', 'U', 'S', 'TF', 'V') OR objects.type IN ('U', 'S', 'V'))
AND objects.name LIKE @TableName
UNION ALL
SELECT 1 AS system_object, object_id, name, schema_id, type, type_desc, parent_object_id
FROM sys.system_objects AS objects
WHERE
1=@SystemObjects
AND (@VirtualTables=1 AND objects.type IN ('IF', 'IT', 'U', 'S', 'TF', 'V') OR objects.type IN ('U', 'S', 'V'))
AND objects.name LIKE @TableName
) AS objects
JOIN sys.schemas ON objects.schema_id=schemas.schema_id
JOIN (
SELECT
object_id, COUNT(*) AS ColumnCount,
SUM(max_length) AS TotalMaxColumnLength
FROM sys.all_columns
GROUP BY object_id
) AS columns ON objects.object_id=columns.object_id
LEFT OUTER JOIN (
SELECT
object_id, SUM(CASE WHEN index_id BETWEEN 0 AND 1 THEN row_count ELSE 0 END) AS Rows,
CONVERT(numeric(19,3), CONVERT(numeric(19,3), SUM(CASE WHEN index_id BETWEEN 0 AND 1 THEN in_row_reserved_page_count+lob_reserved_page_count+row_overflow_reserved_page_count ELSE 0 END))/CONVERT(numeric(19,3), 128)) AS SizeMB,
CONVERT(numeric(19,3), CONVERT(numeric(19,3), SUM(CASE WHEN index_id>1 THEN in_row_reserved_page_count+lob_reserved_page_count+row_overflow_reserved_page_count ELSE 0 END))/CONVERT(numeric(19,3), 128)) AS SizeMBIndexes,
SUM(CASE WHEN index_id BETWEEN 0 AND 1 THEN 1 ELSE 0 END) AS PartitionCount
FROM sys.dm_db_partition_stats
GROUP BY object_id
) AS partitions ON objects.object_id=partitions.object_id
LEFT OUTER JOIN (
SELECT
object_id,
MAX(CONVERT(tinyint, is_primary_key)) AS HasPrimarykey,
MAX(CONVERT(tinyint, is_unique)) AS HasUniqueIndex,
SUM(CASE WHEN is_primary_key=1 THEN 0 ELSE CONVERT(tinyint, is_unique) END) AS NonPKUniqueIndexCount,
SUM(CASE WHEN index_id=1 THEN 1 ELSE 0 END) AS HasClusteredIndex,
SUM(CASE WHEN index_id=1 AND is_unique=1 THEN 1 ELSE 0 END) AS ClusteredIndexIsUnique,
SUM(CASE WHEN index_id>1 THEN 1 ELSE 0 END) AS NonClusteredIndexCount,
SUM(CASE WHEN index_id=1 AND is_primary_key=1 THEN 1 ELSE 0 END) AS PrimaryKeyIsClustered
FROM sys.indexes
GROUP BY object_id
) AS indexes ON objects.object_id=indexes.object_id
WHERE
(@VirtualTables=1 OR partitions.object_id IS NOT NULL AND indexes.object_id IS NOT NULL)
AND schemas.name LIKE CASE WHEN @SchemaName='' THEN schemas.name ELSE @SchemaName END
ORDER BY schemas.name, objects.type, objects.name
GO

--*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating