The Archaeology of Rules

  • So I have this old SQL 2000 database that has been upgraded to SQL 2005 and will soon be upgraded to SQL 2008. In it, are these archaic RULEs:

    I would like to extract the fossil footprint of these RULEs as circled in red with a query.

    For CHECK CONSTRAINTs (which seem to be the replacement for RULEs), I know I can get what I want as follows (last column):

    -- Display CHECK CONSTRAINT clauses

    select a.TABLE_CATALOG, a.TABLE_SCHEMA, a.TABLE_NAME, a.COLUMN_NAME, CHECK_CLAUSE

    from information_schema.columns a

    inner join information_schema.constraint_column_usage b

    on a.column_name = b.column_name and a.table_name = b.table_name

    inner join information_schema.check_constraints c

    on b.constraint_name = c.constraint_name

    where a.column_default is not null

    I can identify the RULEs by looking in sys.objects, so from that I can use the object_id if I need it:

    -- Display RULEs (clauses not in this table)

    SELECT name, object_id

    FROM sys.all_objects

    WHERE type = 'R'

    I can even find the RULEs referenced in the information_schema VIEWs like this:

    -- No columns in information_schema.table_constraints show the rule clause

    SELECT a.TABLE_CATALOG, a.TABLE_SCHEMA, a.TABLE_NAME, a.COLUMN_NAME, a.CONSTRAINT_NAME

    ,b.CONSTRAINT_TYPE

    FROM information_schema.constraint_column_usage a

    LEFT OUTER JOIN information_schema.table_constraints b

    ON a.CONSTRAINT_CATALOG = b.CONSTRAINT_CATALOG AND

    a.CONSTRAINT_SCHEMA = b.CONSTRAINT_SCHEMA AND

    a.TABLE_CATALOG = b.TABLE_CATALOG AND

    a.TABLE_SCHEMA = b.TABLE_SCHEMA AND

    a.CONSTRAINT_NAME = b.CONSTRAINT_NAME

    WHERE b.CONSTRAINT_TYPE IS NULL

    However finding the clause for the rule remains elusive.

    Can anybody help?

    Also, does anybody know if this feature is scheduled for deprecation any time soon?


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • My archaeological dig uncovered the following:

    SELECT a.name

    ,LTRIM(RIGHT(defn, LEN(defn) - (3 + CHARINDEX(' as ', defn))))

    FROM sys.all_objects a

    INNER JOIN sys.sql_modules b

    ON a.object_id = b.object_id

    CROSS APPLY (SELECT RTRIM(REPLACE(REPLACE(b.definition, CHAR(10), ' '), CHAR(13), ' '))) c (defn)

    WHERE a.type = 'R'

    Not the prettiest fossil but it seems to work.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 2 posts - 1 through 1 (of 1 total)

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