Views created per table

  • Comments posted to this topic are about the item Views created per table

    ============================================================
    SELECT YOUR PROBLEM FROM SSC.com WHERE PROBLEM DESCRIPTION =
    http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]

  • Hello,

    Thanks for the script.

    An interesting experiment, but unless there were hundreds of Views in a DB, I think I would prefer using a straight select e.g. Select * From INFORMATION_SCHEMA.VIEW_TABLE_USAGE Order By TABLE_NAME, VIEW_NAME

    Regards,

    John Marsh

    www.sql.lu
    SQL Server Luxembourg User Group

  • Hi,

    At first I thought the query was really good - it would need a tweak to make it a bit better where you have nested views - so something like this:

    with Table_analysis (View_Name , level )

    as (

    select view_name, 0 as level

    from information_schema.view_table_usage

    where table_name = @Table_Name

    union all

    select vtu.view_name, level + 1 as level

    from information_schema.view_table_usage vtu

    inner join Table_analysis ta

    on ta.View_Name = vtu.table_name

    )

    select * from Table_analysis

    order by view_name

    go

    unfortunately the results of this don't match up with the Red Gate Dependency checker which found an additional 10 or so views for one of our tables within the same database. After manually checking the differences I found that the nested views should have been included in both lists but sadly the view_table_usage didn't contain all the information it should.

    A bit disappointing really - this could have been a really good technique to get view information - instead we have to use Red Gate dependency checker to work out what views access a certain table when we are making DDL changes to tables

    Sorry for sounding like a salesman of Red Gate - but using this view_table_usage data doesn't work for us.

    Tony

  • Most of the time, we need to know not only the views that depend on a table, but any other object, as well. For that matter, we often want to know what depends on other types of objects, such as UDFs, stored procedures, and views. For this I have a handy script I'll share with you. We use various schemas in out databases, so this script enables you to use the qualified name of the object.

    /*

    Find all dependencies on objects

    1. Set @SEARCH_TABLE_NAME = NULL to see all dependencies

    2. Set @SEARCH_TABLE_NAME to name of object for which you need to know what other objects

    depend on it.

    3. Result is list of objects that depend on the object dependencies

    */

    DECLARE @SEARCH_TABLE_NAME VARCHAR(200) = NULL

    DECLARE @TABLE_NAME SYSNAME = PARSENAME(@SEARCH_TABLE_NAME,1)

    DECLARE @TABLE_SCHEMA_NAME SYSNAME = PARSENAME(@SEARCH_TABLE_NAME,2)

    IF @SEARCH_TABLE_NAME IS NOT NULL -- only display dependent object information

    SELECT DISTINCT o.type_desc AS [DependentObjectType], os.name+'.'+OBJECT_NAME(d.object_id) [DependentObjectName]

    FROM sys.sql_dependencies d

    INNER JOIN sys.objects o

    ON d.object_id = o.object_id

    INNER JOIN sys.schemas os

    ON o.schema_id = os.schema_id

    INNER JOIN sys.objects do

    ON d.referenced_major_id = do.object_id

    INNER JOIN sys.schemas dos

    ON do.schema_id = dos.schema_id

    WHERE d.object_id != do.object_id

    AND OBJECT_NAME(referenced_major_id) = @TABLE_NAME

    AND (@TABLE_SCHEMA_NAME IS NULL OR dos.name = @TABLE_SCHEMA_NAME)

    ORDER BY 2

    ELSE -- Display both dependent object and referenced object information

    SELECT DISTINCT o.type_desc AS [DependentObjectType], os.name+'.'+OBJECT_NAME(d.object_id) [DependentObjectName],

    do.type_desc AS [ReferencedObjectType],dos.name+'.'+OBJECT_NAME(referenced_major_id) [ReferencedObjectName]

    FROM sys.sql_dependencies d

    INNER JOIN sys.objects o

    ON d.object_id = o.object_id

    INNER JOIN sys.schemas os

    ON o.schema_id = os.schema_id

    INNER JOIN sys.objects do

    ON d.referenced_major_id = do.object_id

    INNER JOIN sys.schemas dos

    ON do.schema_id = dos.schema_id

    WHERE d.object_id != do.object_id

    AND (@TABLE_NAME IS NULL OR OBJECT_NAME(referenced_major_id) = @TABLE_NAME)

    AND (@TABLE_SCHEMA_NAME IS NULL OR dos.name = @TABLE_SCHEMA_NAME)

    ORDER BY 2,3

Viewing 4 posts - 1 through 3 (of 3 total)

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