Quelques requêtes pour gérer les clefs primaires manquantes

Voici quelques requêtes SQL Server pour rendre compte des clefs primaires manquantes et les ajouter dans le cas ou elles manques…

1 – Liste des tables n’ayant pas de clef primaire

SELECT TABLE_SCHEMA, TABLE_NAME
FROM   INFORMATION_SCHEMA.TABLES
WHERE  TABLE_TYPE = 'BASE TABLE'
EXCEPT
SELECT TABLE_SCHEMA, TABLE_NAME
FROM   INFORMATION_SCHEMA.TABLE_CONSTRAINTS
WHERE  CONSTRAINT_TYPE = 'PRIMARY KEY';

2 – Liste des tables ayant une colonne IDENTITY

SELECT s.name AS TABLE_SCHEMA, o.name AS TABLE_NAME, c.*
FROM   sys.objects AS o
       INNER JOIN sys.schemas AS s
             ON o.schema_id = s.schema_id
       INNER JOIN sys.COLUMNS AS c
             ON o.object_id = c.object_id
WHERE  o."type" = 'U'
  AND  is_identity = 1;

3 – Liste des tables n’ayant pas de clef primaire et pas de colonne identity

SELECT TABLE_SCHEMA, TABLE_NAME
FROM   INFORMATION_SCHEMA.TABLES
WHERE  TABLE_TYPE = 'BASE TABLE'
EXCEPT
SELECT TABLE_SCHEMA, TABLE_NAME
FROM   INFORMATION_SCHEMA.TABLE_CONSTRAINTS
WHERE  CONSTRAINT_TYPE = 'PRIMARY KEY'
EXCEPT
SELECT s.name AS TABLE_SCHEMA, o.name AS TABLE_NAME
FROM   sys.objects AS o
       INNER JOIN sys.schemas AS s
             ON o.schema_id = s.schema_id
       INNER JOIN sys.COLUMNS AS c
             ON o.object_id = c.object_id
WHERE  o."type" = 'U'
  AND  is_identity = 1;

4 – Liste des tables avec nom de la colonne IDENTITY, n’ayant pas de clef primaire, mais une colonne IDENTITY

WITH T AS
(
(
SELECT TABLE_SCHEMA, TABLE_NAME
FROM   INFORMATION_SCHEMA.TABLES
WHERE  TABLE_TYPE = 'BASE TABLE'
EXCEPT
SELECT TABLE_SCHEMA, TABLE_NAME
FROM   INFORMATION_SCHEMA.TABLE_CONSTRAINTS
WHERE  CONSTRAINT_TYPE = 'PRIMARY KEY'
)
INTERSECT
SELECT s.name AS TABLE_SCHEMA, o.name AS TABLE_NAME
FROM   sys.objects AS o
       INNER JOIN sys.schemas AS s
             ON o.schema_id = s.schema_id
       INNER JOIN sys.COLUMNS AS c
             ON o.object_id = c.object_id
WHERE  o."type" = 'U'
  AND  is_identity = 1
)
SELECT T.*, c.name AS COLUMN_NAME
FROM   T  
       JOIN sys.COLUMNS AS c
             ON OBJECT_ID(T.TABLE_SCHEMA + '.' + T.TABLE_NAME) = c.object_id
WHERE  is_identity = 1;

5 РCr̩ation des clefs primaires manquantes

WITH T0 AS
(
-- table n'ayant pas de clef primaire mais une colonne IDENTITY
(
SELECT TABLE_SCHEMA, TABLE_NAME
FROM   INFORMATION_SCHEMA.TABLES
WHERE  TABLE_TYPE = 'BASE TABLE'
EXCEPT
SELECT TABLE_SCHEMA, TABLE_NAME
FROM   INFORMATION_SCHEMA.TABLE_CONSTRAINTS
WHERE  CONSTRAINT_TYPE = 'PRIMARY KEY'
)
INTERSECT
SELECT s.name AS TABLE_SCHEMA, o.name AS TABLE_NAME
FROM   sys.objects AS o
       INNER JOIN sys.schemas AS s
             ON o.schema_id = s.schema_id
       INNER JOIN sys.COLUMNS AS c
             ON o.object_id = c.object_id
WHERE  o."type" = 'U'
  AND  is_identity = 1
),
T1 AS
(
-- table n'ayant pas de clef primaire et pas de colonne identity
SELECT TABLE_SCHEMA, TABLE_NAME
FROM   INFORMATION_SCHEMA.TABLES
WHERE  TABLE_TYPE = 'BASE TABLE'
EXCEPT
SELECT TABLE_SCHEMA, TABLE_NAME
FROM   INFORMATION_SCHEMA.TABLE_CONSTRAINTS
WHERE  CONSTRAINT_TYPE = 'PRIMARY KEY'
EXCEPT
SELECT s.name AS TABLE_SCHEMA, o.name AS TABLE_NAME
FROM   sys.objects AS o
       INNER JOIN sys.schemas AS s
             ON o.schema_id = s.schema_id
       INNER JOIN sys.COLUMNS AS c
             ON o.object_id = c.object_id
WHERE  o."type" = 'U'
  AND  is_identity = 1
)
SELECT CASE WHEN c.is_nullable = 1
               THEN N'ALTER TABLE [' + TABLE_SCHEMA + N'].[' + TABLE_NAME + '] ALTER COLUMN [' + c.name + '] ' + t.name + ' NOT NULL;'
               ELSE N''
       END
       + N'ALTER TABLE [' + TABLE_SCHEMA + N'].[' + TABLE_NAME + N'] ADD CONSTRAINT [PK_'+ TABLE_NAME + N'] PRIMARY KEY ([' + c.name + N'])'
       + CASE WHEN EXISTS(SELECT * FROM sys.indexes WHERE object_id = OBJECT_ID(TABLE_SCHEMA + N'.' + TABLE_NAME) AND index_id = 1)
                 THEN ' NONCLUSTERED;'
                 ELSE ';'
        END
FROM   T0
       INNER JOIN sys.COLUMNS AS c
             ON OBJECT_ID(T0.TABLE_SCHEMA + '.' + T0.TABLE_NAME) = c.object_id
       INNER JOIN sys.types AS t
             ON c.system_type_id = t.system_type_id
WHERE  is_identity = 1
UNION ALL
SELECT N'ALTER TABLE [' + TABLE_SCHEMA + N'].[' + TABLE_NAME + N'] ADD _ID INT NOT NULL IDENTITY PRIMARY KEY'
       + CASE WHEN EXISTS(SELECT * FROM sys.indexes WHERE object_id = OBJECT_ID(TABLE_SCHEMA + N'.' + TABLE_NAME) AND index_id = 1)
                 THEN ' NONCLUSTERED;'
                 ELSE ';'
        END
FROM   T1;
Frédéric Brouard, alias SQLpro, ARCHITECTE DE DONNÉES
Expert  S.G.B.D  relationnelles   et   langage  S.Q.L
Moste  Valuable  Professionnal  Microsoft  SQL Server
Société SQLspot  :  modélisation, conseil, formation,
optimisation,  audit,  tuning,  administration  SGBDR
Enseignant: CNAM PACA, ISEN Toulon, CESI Aix en Prov.

L’entreprise SQL Spot
Le site web sur le SQL et les SGBDR

MVP Microsoft SQL
Server

Laisser un commentaire