INFORMATION_SCHEMA.101

  • Comments posted to this topic are about the item INFORMATION_SCHEMA.101

    [font="Comic Sans MS"]Tom Powell
    http://philergia.wordpress.com/[/font]

  • I have recently put together the following script for listing table structures which people may find useful

    DECLARE @Table_Name nvarchar(128)

    --SELECT * FROM INFORMATION_SCHEMA.TABLES

    DECLARE myCursor CURSOR

    FOR SELECT [TABLE_NAME] FROM INFORMATION_SCHEMA.TABLES

    WHERE [TABLE_NAME]<>'sysdiagrams'

    ORDER BY [TABLE_NAME]

    ----

    OPEN myCursor

    FETCH NEXT FROM myCursor

    INTO @Table_Name

    WHILE (@@FETCH_STATUS=0)

    BEGIN

    SELECT "table_name"='['+[TABLE_NAME]+']',"ordinal_position"=-1 FROM INFORMATION_SCHEMA.TABLES

    WHERE [TABLE_NAME]=@Table_Name

    Union

    Select

    column_name+' ('+

    data_type + CASE WHEN left(data_type,2)='bi'

    THEN ''

    WHEN data_type='datetime'

    THEN ''

    WHEN data_type='int'

    THEN ''

    WHEN character_maximum_length<0

    THEN '(nomax)'

    WHEN numeric_precision_radix>numeric_precision

    THEN '('+convert(varchar(4),numeric_precision)+','+convert(varchar(4),numeric_scale)+')'

    WHEN numeric_precision_radix<numeric_precision

    THEN '('+convert(varchar(4),numeric_precision)+','+convert(varchar(4),numeric_scale)+')'

    ELSE '('+convert(varchar(4),character_maximum_length)+')'

    END

    + CASE WHEN is_nullable='NO'

    THEN ', not null'

    ELSE ', default='+ CASE WHEN column_default is null

    THEN 'NULL'

    ELSE column_default

    END

    END

    +')'

    ,ordinal_position

    FromINFORMATION_SCHEMA.COLUMNS c

    Where [TABLE_NAME]=@Table_Name

    Order by ordinal_position,table_name

    FETCH NEXT FROM myCursor

    INTO @Table_Name

    END

    ----

    CLOSE myCursor

    DEALLOCATE myCursor

  • Thanks, Tom.

  • When writing DDL deployment scripts, I try to leverage information schema views rather than system views.

    -- If a named constraint exists, then drop it:

    if exists (select * from information_schema.table_constraints

    where table_schema = 'schema_name'

    and table_name = 'table_name'

    and constraint_name = 'cc_constraint_name')

    begin

    alter table someschemaname.sometablename

    drop constraint cc_someconstraintname;

    end;

    -- If a column does not exist, then add it:

    if not exists (select 1 from information_schema.columns

    where table_schema = 'schema_name'

    and table_name = 'table_name'

    and column_name = 'column_name')

    begin

    alter table schema_name.table_name

    add column_name int null;

    end;

    However, indexes are one example of a common database object that (as far as I know) arn't covered, so I have to fall back to using sys.sysindexes.

    -- If an index does not exist, then create it:

    if not exists (select * from sys.sysindexes where name = 'ix_index_name')

    begin

    create nonclustered index ix_index_name ...

    end;

    "Do not seek to follow in the footsteps of the wise. Instead, seek what they sought." - Matsuo Basho

  • Thanks Tom, this article is very timely as I am embarking on migrating my databases over to SQLSvr2008 (from 2000) and I'm also looking for opportunities to consolidate and prune certain databases. This will help a lot, thanks again.

    Anthony

  • A good overview of the INFORMATION_SCHEMA views, Tom, and I, like Eric, also use them where possible. For the situation you mentioned with the routine definition spanning two rows, you can use the sys.sql_modules view, since the whole definition fits on one row.

    John

  • Great article. I love your final quip about being a Calvinist.

    🙂

    FWIW, I've developed a set of views that allow you to query for any table or view to see what other tables or views reference them. True you can get similar results using "Show Dependencies", but I've not found that that's very reliable, especially when it comes to UNIONs and Subselects. Note, however it uses substring matches, so there may be some false positives.

  • I'm glad my article is scaring out all these scripts. There's no point in reinventing the wheel.

    [font="Comic Sans MS"]Tom Powell
    http://philergia.wordpress.com/[/font]

  • Thanks for the article. The discussion has also been nice.

    ---------------------------------------------------------------------
    Use Full Links:
    KB Article from Microsoft on how to ask a question on a Forum

  • Thanks Tom - I have noted that the ROUTINE_DEFINITION that SQL Server seems to be constrained only to the FIRST 4000 characters, rather than 4000 character "chunks". This makes this much less useful, as comments tend to lead off my stored procs and functions, and this gets counted in the 4000 "searchable" limit.

    I go with the more robust sql_modules

    SELECT OBJECT_NAME(T1.object_id)

    FROM sys.sql_modules AS T1

    WHERE T1.definition LIKE '%MySearchString%'

    This handles the both multiple "chunks", as well as the Calvinist issue 🙂

  • I don't think:

    '%[Bob].%'

    does what you intended. The square brackets indicate a list of characters, so it would be 'B' 'o' or 'b', rather than '[Bob]'. I think you meant something like:

    '%\[Bob\].%' ESCAPE '\'

  • Thanks for this article. Our group is inheriting a few DBs so this is timely.

    The searching on INFORMATION_ROUTINES might be a little confusing when searching for possible linked server calls considering we often use a [servername\instance] syntax when creating them.

    Ken

  • Really nice article tom. i come to know so many uses of information_schema. good one thanks.

  • Thanks Tom, tend to get caught up in using the sys.* catalog views and forget there are other ways to skin that cat 🙂

  • How about using the "undocumented" sp_MSforeachdb.

    -- Finding Tables

    EXEC sp_MSforeachdb 'USE [?]

    Select TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, TABLE_TYPE

    From INFORMATION_SCHEMA.TABLES

    Where TABLE_NAME like ''%Address%''

    AND TABLE_CATALOG NOT IN (''Master'', ''model'', ''msdb'', ''tempdb'', ''ReportServer'', ''ReportServerTempDB'')

    ORDER BY TABLE_NAME'

Viewing 15 posts - 1 through 14 (of 14 total)

You must be logged in to reply to this topic. Login to reply