Technical Article

The Ultimate Column Searcher

,

*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=
Util_ColumnSearch
By Jesse Roberge - YeshuaAgapao@Yahoo.com
Update - Fixed existance check for drop

Searches for columns with names containing @Colname that belong to tables with names containing @TableName (optional) or schemas with names containing @SchemaName (optional). Gives size and rowcount for tables.
LIKE wildcards are not automatic, which allows for easy 'begins with', 'ends with', and 'equal to' queries.
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:
Fixed column_id sorting, now sorts correctly as an int rather than a (converted) string
Added searching of system tables

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

Required Input Parameters
@ColumnName sysname Filters columns. Can use LIKE wildcards.

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

Usage
EXECUTE Util_ColumnSearch '%price%'
EXECUTE Util_ColumnSearch @SchemaName='dbo', @Tablename='cart%', @Columnname='%price%'

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_ColumnSearch', 'P') IS NOT NULL DROP PROCEDURE Util.Util_ColumnSearch
GO

/**
*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=*=
Util_ColumnSearch
By Jesse Roberge - YeshuaAgapao@Yahoo.com
Update - Fixed existance check for drop

Searches for columns with names containing @Colname that belong to tables with names containing @TableName (optional) or schemas with names containing @SchemaName (optional). Gives size and rowcount for tables.
LIKE wildcards are not automatic, which allows for easy 'begins with', 'ends with', and 'equal to' queries.
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:
Fixed column_id sorting, now sorts correctly as an int rather than a (converted) string
Added searching of system tables

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

Required Input Parameters
@ColumnName sysnameFilters columns.  Can use LIKE wildcards.

Optional Input Parameters
@SchemaName sysname=''Filters schemas.  Can use LIKE wildcards.  All schemas if blank.
@TableName sysname=''Filters tables.  Can use LIKE wildcards.  All tables if blank.
@VirtualTables TinyInt=0Search virutal tables (views, table-valued functions) - Size output will be NULL for these
@UserOjbects TinyInt=1Search user objects
@SystemObjects TinyInt=0Search system objects
@Sort TinyInt=11=sort by SchemaName, TableName, ColumnID; 2=sort by SchemaName, TableName, ColumnName

Usage
EXECUTE Util_ColumnSearch '%price%'
EXECUTE Util_ColumnSearch @SchemaName='dbo', @Tablename='cart%', @Columnname='%price%'

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_ColumnSearch
@ColumnName sysname,
@SchemaName sysname='',
@TableName sysname='',
@VirtualTables TinyInt=0,
@UserObjects TinyInt=1,
@SystemObjects TinyInt=0,
@Sort tinyint=1
AS

SELECT
objects.system_object,
schemas.schema_id, objects.object_id,
schemas.name AS schema_name, objects.name AS object_name,
partitions.Rows, partitions.SizeMB,
objects.column_id, objects.column_name AS column_name,
objects.user_type_id, types.name AS user_type_name,
objects.system_type_id, systemtypes.name AS system_type_name,
objects.max_length, objects.precision, objects.scale,
objects.is_nullable, objects.is_identity, objects.is_computed
FROM
(
SELECT
0 AS system_object, objects.object_id, objects.name, objects.schema_id,
objects.type, objects.type_desc, objects.parent_object_id,
columns.column_id, columns.name AS column_name,
columns.user_type_id, columns.system_type_id,
columns.max_length, columns.precision, columns.scale,
columns.is_nullable, columns.is_identity, columns.is_computed
FROM
sys.objects
JOIN sys.columns ON objects.object_id=columns.object_id
WHERE
1=@UserObjects
AND (@VirtualTables=1 AND objects.type IN ('IF', 'IT', 'U', 'S', 'TF', 'V') OR objects.type IN ('U', 'S', 'V'))
AND columns.name LIKE @ColumnName
AND objects.name LIKE CASE WHEN @TableName='' THEN objects.name ELSE @TableName END
UNION ALL
SELECT
1 AS system_object, objects.object_id, objects.name, objects.schema_id,
objects.type, objects.type_desc, objects.parent_object_id,
columns.column_id, columns.name AS column_name,
columns.user_type_id, columns.system_type_id,
columns.max_length, columns.precision, columns.scale,
columns.is_nullable, columns.is_identity, columns.is_computed
FROM
sys.system_objects AS objects
JOIN sys.system_columns AS columns ON objects.object_id=columns.object_id
WHERE
1=@SystemObjects
AND (@VirtualTables=1 AND objects.type IN ('IF', 'IT', 'U', 'S', 'TF', 'V') OR objects.type IN ('U', 'S', 'V'))
AND columns.name LIKE @ColumnName
AND objects.name LIKE CASE WHEN @TableName='' THEN objects.name ELSE @TableName END
) AS objects
JOIN sys.schemas ON objects.schema_id=schemas.schema_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(in_row_reserved_page_count+lob_reserved_page_count+row_overflow_reserved_page_count))/CONVERT(numeric(19,3), 128)) AS SizeMB
FROM sys.dm_db_partition_stats
WHERE dm_db_partition_stats.index_id BETWEEN 0 AND 1 --0=Heap; 1=Clustered; only 1 per table
GROUP BY object_id
) AS partitions ON objects.object_id=partitions.object_id
JOIN sys.types ON objects.user_type_id=types.user_type_id
JOIN sys.types AS systemtypes ON
types.system_type_id=systemtypes.system_type_id
AND systemtypes.system_type_id=systemtypes.user_type_id
WHERE
@VirtualTables=1 OR partitions.object_id IS NOT NULL
AND schemas.name LIKE CASE WHEN @SchemaName='' THEN schemas.name ELSE @SchemaName END
ORDER BY
schemas.name, objects.name,
CASE WHEN @Sort=1 THEN objects.column_id ELSE NULL END,
CASE WHEN @Sort<>1 THEN objects.column_name ELSE NULL END
GO

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

Rate

1 (1)

You rated this post out of 5. Change rating

Share

Share

Rate

1 (1)

You rated this post out of 5. Change rating