Finding Composite Primary Key Columns

You never know when the idea for a script will make an appearance.

I had to work with composite primary keys recently while working on a project for a client.  More specifically, I had to create a process that would dynamically (dynamic SQL?! Say it isn’t so?!) handle composite keys in an efficient manner.

Usually, a primary key is just a single column that uniquely identifies a row within a table.  However, a composite primary key consisting of 2 or more columns can be created.  Regardless if the primary key is singular or composite, it provides identical functionality.  In this particular instance, this process would perform data modifications based on the columns that composed the primary key.  Thus I needed to be able to determine what columns are in the key.

There is a limit to the number of columns you can have in a composite key.  In SQL Server 2016 and newer, the limit is 32 columns and prior to that a primary key could have up to 16 columns.   Keep in mind, neither limit is a goal but it’s there if you need it.

The Parts & Pieces

As I started to work on this, my first thought was that it would be helpful to know how many tables had a composite primary key.  This would give me an idea on how many tables I was dealing with.  Thankfully, SQL Server has this information by using system DMVs (dynamic management views) along with the COL_NAME function.

Note
The COL_NAME function will only work with SQL Server 2008 and newer.  

Below is my attempt to get a result of how many columns compose the primary key,

  1. -- how many columns make up the primary key   
  2. SELECT Schema_name(o.schema_id)                    AS 'Schema',   
  3.        Object_name(i.object_id)                    AS 'TableName',   
  4.        Count(Col_name(ic.object_id, ic.column_id)) AS 'Primary_Key_Column_Count'   
  5. FROM   sys.indexes i   
  6.        INNER JOIN sys.index_columns ic   
  7.                ON i.object_id = ic.object_id   
  8.                   AND i.index_id = ic.index_id   
  9.        INNER JOIN sys.objects o   
  10.                ON i.object_id = o.object_id   
  11.        INNER JOIN sys.schemas s   
  12.                ON o.schema_id = s.schema_id   
  13. WHERE  i.is_primary_key = 1   
  14.        AND o.type_desc = 'USER_TABLE'   
  15. GROUP  BY Object_name(i.object_id),   
  16.           o.schema_id   
  17. HAVING Count(1) > 1   
  18. ORDER  BY 1  

In looking at the AdventureWorks2014 database, the above script will give you an output that looks like this,

SQL Server

Cool!  Now I knew which tables had a primary key comprised of multiple columns as well as how many columns were in the key definition.

Taking things a step further, I thought that it would be useful to see what columns the primary key is composed of in that same output.  This part becomes a little more complicated to gather as we need to get the list of columns, which could be 1 – 32 columns (or 1-16 columns depending on the version of SQL Server) into a comma delimited list.

Using the STUFF function along with XML PATH is a quick and efficient way to generate a comma delimited list of string values.

Thus this script was born,

  1. SELECT Schema_name(o.schema_id)            AS 'Schema',   
  2.        Object_name(i2.object_id)           AS 'TableName',   
  3.        Stuff((SELECT ',' + Col_name(ic.object_id, ic.column_id)   
  4.               FROM   sys.indexes i1   
  5.                      INNER JOIN sys.index_columns ic   
  6.                              ON i1.object_id = ic.object_id   
  7.                                 AND i1.index_id = ic.index_id   
  8.               WHERE  i1.is_primary_key = 1   
  9.                      AND i1.object_id = i2.object_id   
  10.                      AND i1.index_id = i2.index_id   
  11.               FOR xml path('')), 1, 1, ''AS PK   
  12. FROM   sys.indexes i2   
  13.        INNER JOIN sys.objects o   
  14.                ON i2.object_id = o.object_id   
  15. WHERE  i2.is_primary_key = 1   
  16.        AND o.type_desc = 'USER_TABLE'   

We can see the output of this query below,

SQL Server

Note that this output has the schema and table name just like the first result set.

Using a CTE, we can tie these two result sets together and get a clean unified look.

  1. -- Let's get the columns of the Primary key into a CTE   
  2. ;WITH mycte   
  3.      AS (SELECT Schema_name(o.schema_id)            AS 'Schema',   
  4.                 Object_name(i2.object_id)           AS 'TableName',   
  5.                 Stuff((SELECT ',' + Col_name(ic.object_id, ic.column_id)   
  6.                        FROM   sys.indexes i1   
  7.                               INNER JOIN sys.index_columns ic   
  8.                                       ON i1.object_id = ic.object_id   
  9.                                          AND i1.index_id = ic.index_id   
  10.                        WHERE  i1.is_primary_key = 1   
  11.                               AND i1.object_id = i2.object_id   
  12.                               AND i1.index_id = i2.index_id   
  13.                        FOR xml path('')), 1, 1, ''AS PK   
  14.          FROM   sys.indexes i2   
  15.                 INNER JOIN sys.objects o   
  16.                         ON i2.object_id = o.object_id   
  17.          WHERE  i2.is_primary_key = 1   
  18.                 AND o.type_desc = 'USER_TABLE')   
  19. -- Use this select to get the count, join to the CTE and get the column list   
  20. SELECT Schema_name(o.schema_id)                    AS 'Schema',   
  21.        Object_name(i.object_id)                    AS 'TableName',   
  22.        Count(Col_name(ic.object_id, ic.column_id)) AS 'Primary_Key_Column_Count'   
  23.        ,   
  24.        mycte.pk                                    AS   
  25.        'Primary_Key_Columns'   
  26. FROM   sys.indexes i   
  27.        INNER JOIN sys.index_columns ic   
  28.                ON i.object_id = ic.object_id   
  29.                   AND i.index_id = ic.index_id   
  30.        INNER JOIN sys.objects o   
  31.                ON i.object_id = o.object_id   
  32.        INNER JOIN mycte   
  33.                ON mycte.tablename = Object_name(i.object_id)   
  34. WHERE  i.is_primary_key = 1   
  35.        AND o.type_desc = 'USER_TABLE'   
  36. GROUP  BY Schema_name(o.schema_id),   
  37.           Object_name(i.object_id),   
  38.           mycte.pk   
  39. HAVING Count('Primay_Key_Column_Count') > 1   
  40. ORDER  BY 'TableName' ASC   

We can see from below that now we have a nice result set that tells use not only how many columns are in the primary key but also what those keys are.

SQL Server

Update

Based on comments, I’ve removed the CTE and replaced it with an in-line query as well as included the schema for each object.  This should be a cleaner look.  The 
GitHub repository has been updated with this change. 

Summary

When working with composite primary keys, it’s a good idea to know how many columns as well as what columns are in the key.  This query helped me in creating the process my client needed. It just might help you to figure out some logic when writing dynamic SQL!

You can download the full script from here.

Enjoy!


Similar Articles
Denny Cherry & Associates Consulting
Expert Consultants From HA to DR to up-time to SQL virtualization to scalability.