Checking Naming Conventions of MSSQL Constraints and Indexes

If you create constraints and indexes in Management Studio, they are automatically named based on their type and the name of the table they belong to. If you create them manually, or overwrite their default names, naming may end up inconsistent.

Here are two simple queries to check for naming conventions.

Check that the constraint names match ‘constraint type’ + ‘table name’:

SELECT p.name, 
    CASE c.type
        WHEN 'F' THEN 'FK'
        WHEN 'D' THEN 'DF'
        WHEN 'UQ' THEN 'UK'
        WHEN 'C' THEN 'CK'
        ELSE c.type 
    END + ' ' + c.name
FROM sys.objects p
INNER JOIN sys.objects c ON p.object_id = c.parent_object_id
WHERE p.type = 'U'
AND c.name NOT LIKE
    CASE c.type
        WHEN 'F' THEN 'FK'
        WHEN 'D' THEN 'DF'
        WHEN 'UQ' THEN 'UK'
        WHEN 'C' THEN 'CK'
        ELSE c.type 
    END + '[_]' + p.name + '%'
ORDER BY 1, 2

Check that the index names match ‘index type’ + ‘table name’:

SELECT p.name, i.name
FROM   sys.objects p
INNER JOIN sys.indexes i ON p.object_id = i.object_id
WHERE p.type = 'U'
AND i.name NOT LIKE
    CASE
        WHEN i.is_primary_key = 1 THEN 'PK'
        WHEN i.is_unique = 1 THEN 'UK'
        ELSE 'IX'
    END + '[_]' + p.name + '%'
ORDER BY p.name, i.name

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s

This site uses Akismet to reduce spam. Learn how your comment data is processed.