sqlschool.gr logo

articles

Articles of SQLschool.gr Team

List All Primary Keys and Foreign Keys in your database

Antonios Chatzipavlis
Sunday 15 November 2015

Δεν είναι λίγες οι φορές που θέλεις να μάθεις πράγματα για το database schema σε μια database που είτε είχες φτιάξει στο παρελθόν είτε είναι μια database που στην έχουν φέρει να την διαχειριστείς και από documentation πάσχει.

Για όλους τους παραπάνω λόγους θα πρέπει να ψάξεις, αλλά πρέπει να ψάξεις χωρίς να κουραστείς και το να ψάχνεις με το γραφικό περιβάλλον του SSMS είναι κουραστικό οπότε πρέπει να καταφύγεις σε metadata queries.

Ένα τέτοιο είναι και το παρακάτω το οποίο μπορείτε να καταναλώστε ελεύθερα σε όλες τις εκδόσεις του SQL Server καθώς έχω φροντίσει να χρησιμοποιήσω τα information_schema views και όχι τα system views που στο πέρασμα των εκδόσεων έχουν μικρές ή μεγάλες αλλαγές.

Φυσικά αν κάποιος θέλει περισσότερες πληροφορίες μπορεί να χρησιμοποιήσει απευθείας τα system views αλλά ίσως να αυτό που θα φτιάξει σε μια έκδοση να μην δουλεύει σε επόμενη ή προηγούμενη έκδοση.

Στο συγκεκριμένο metadata query αν υπάρχει composite PK ή FK θα εμφανιστούν περισσότερες γραμμές για το συγκεκριμένο table και constraint και μπορείτε να καταλάβετε την σειρά του με την position_in_key column.

Τέλος εμφανίζονται και τα tables που δεν έχουν PK / FK και αυτές σε όλες τις άλλες columns πλην των βασικών έχουν NULL.
WITH rc AS 
(
    SELECT      kcu.TABLE_SCHEMA AS [schema_name]
    ,           kcu.TABLE_NAME AS [table_name]
    ,           kcu.COLUMN_NAME AS [column_name]
    ,           kcu.ORDINAL_POSITION AS [position_in_key]
    ,           tc.CONSTRAINT_NAME AS [constraint_name]
    ,           tc.CONSTRAINT_TYPE AS [constraint_type]
    ,           cols.DATA_TYPE as [data_type]
    ,           cols.CHARACTER_MAXIMUM_LENGTH as [char_max_len]
    ,           cols.CHARACTER_SET_NAME as [char_set]
    ,           cols.COLLATION_NAME as [collation_name]
    FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS AS tc
    INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE as kcu 
        ON tc.TABLE_SCHEMA=kcu.TABLE_SCHEMA AND tc.TABLE_NAME=kcu.TABLE_NAME AND tc.CONSTRAINT_NAME=kcu.CONSTRAINT_NAME
    INNER JOIN INFORMATION_SCHEMA.COLUMNS AS cols 
        ON cols.TABLE_SCHEMA=kcu.TABLE_SCHEMA AND cols.TABLE_NAME=kcu.TABLE_NAME AND cols.COLUMN_NAME=kcu.COLUMN_NAME
)
SELECT    tbl.TABLE_SCHEMA
,        tbl.TABLE_NAME
,        rc.column_name
,        rc.position_in_key
,        rc.constraint_name
,        rc.constraint_type
,        rc.data_type
,        rc.char_max_len
,        rc.char_set
,        rc.collation_name
FROM RC
RIGHT OUTER JOIN INFORMATION_SCHEMA.TABLES as tbl
    ON tbl.TABLE_NAME = rc.table_name AND tbl.TABLE_SCHEMA = rc.[schema_name]
WHERE tbl.TABLE_TYPE='BASE TABLE'
ORDER BY 1,2,4
results

Antonios Chatzipavlis

Antonios Chatzipavlis

Antonios is a Data Solutions Consultant and Trainer. He has been working in IT since 1988. In his career, he has worked as senior developer, IT Manager, Solutions Architect and IT Consultant. Since 1995 he has been devoted on new technologies and software development tools, mainly by Microsoft, either by training company staff and colleagues or assisting them in design, development and implementation as a consultant or chief developer. He has focused in Databases and Data Science since 1995. He specialized in Microsoft SQL Server since version 6.0 in areas like SQL Server Internals, Database Design and Development, Business Intelligence and in 2010 he has started working with Azure Data Platform, NoSQL databases, Big Data Technologies and Machine Learning. He is an active member of many IT communities in Greece, answering colleagues' questions and writing articles in his web site. He is the owner of SQLschool.gr which is a community portal with a lot of information about Microsoft SQL Server. He has been a Microsoft Certified Trainer (MCT) since 2000. Microsoft honored him as MVP on Data Platform due to his activities in SQL Server since 2010. He holds a large number of Microsoft Certifications and Microsoft SQL Server Certifications since version 6.5.

Episode

First look: SQL Database in Microsoft Fabric

image

More Episodes...

Tip

What's New in SQL Server 2022 - Episodes

More Tips...

Become a member

If you want to receive updates from us become a member to our community.

Connect

Explore

Learn


sqlschool.gr © 2010-2024 All rights reserved

This site uses cookies for operational and analytics purposes only. By continuing to browse this site, you agree to their use.