Towards the Self-Documenting SQL Server Database

William Brewer investigates an unsung hero in SQL Server, extended properties, and shows how to use them to create self-documenting SQL Server databases.

Last updated on 7th October 2016

Extended Properties in SQL Server

With SQL Server, it is strange how some of the most radical improvements that have been introduced over the years have been slipped in almost unnoticed. Conversely, the features that were plastered all over the marketing brochures are sometimes the ones that turn out to be dead ends.

A feature that fits into the former category is the extended properties of databases. Introduced quietly with SQL Server 2000, one could have easily missed them but they have proved, after all, to be of great value to the developer. Extended properties are the route to creating self-documenting databases. I use the term ‘self-documenting’ in the sense that one can attach the documentation directly to the database itself and its objects, rather than create a separate document. Basically, you use the extended properties of data objects to apply your own properties to the metadata.

Using extended properties

The classic example is to use extended properties of an object to append a description of that object, be it a trigger, stored procedure, function, table, view, parameter, index, constraint or column. One can also use extended properties to document details such as the date of revision, author, input mask, caption, history, rendering-style, and so on.

One of the classic general tricks that programmers have used in the past to add documentation to source code is to structure the comments of source code by inserting predefined markers to indicate the category of information (revision date, for example) to any application that generates the documentation (such as Javadocs). This can’t be done in SQL Server as source is only maintained in the database for certain objects such as procedures and functions. Since the introduction of extended properties, such tricks would be unnecessary anyway.

The advantage of using the extended properties is that the documentation, notes, and so on stay with the databases and can be used as a “live documentation” mechanism. They are backed up with the database, and scripted out with the build scripts.

Despite their obvious utility, Microsoft has treated the feature with a curious lack of enthusiasm. There is the smell of ‘wet paint’ about the design. Extended properties allow you to document your database objects but it has been left to third-party utilities such as SQL Doc and DBDesc to exploit the use of these properties for generating the full documentation of the database from the database itself.

A consequence of Microsoft’s indifference to extended properties is that they forgot to include them in the replication synchronisation process. You have to do it manually (a tool such as SQL Compare will synchronise them properly). Also, they neglected to provide an Information_Schema view of the extended properties, which would have made to make it easier to access them from SQL.

Another difficulty is that some third-party software vendors have used the extended properties for other purposes, such as storing parameters for entity-relationship diagrams. This makes it difficult for utilities that extract the documentation as there is no standard property name other than MS_Description.

Creating extended properties via code

Microsoft provides one extended property, MS_Description, which can be used from both Enterprise Manager and SSMS to provide a description of the object to which it is bound. Further, the Diagram Designer provides a description field, accessible via the custom view, which provides an easy way of viewing and editing the documentation of the columns.

However, extended properties are just about providing basic descriptions of objects. They are a lot more versatile that that. The designers of extended properties sensibly placed no restrictions on the properties that one could attribute to database objects. It is perfectly OK, for example, to provide extra metadata to assist the application layer in rendering or querying the data.

When writing the documentation for objects, it is generally quickest to use the facilities within Microsoft’s own tools to add basic descriptions, but beyond that there eventually comes a time that one has to use stored procedures to add documentation.

At the basic level, in SQL Server 2000, all extended properties are stored in sysproperties, but are accessed by a number of stored procedures.

sp_addextendedproperty

Adds a new extended property to a database object

sp_dropextendedproperty

Removes an extended property from a database object

sp_updateextendedproperty

Updates the value of an existing extended property

fn_listextendedproperty

Retrieves the value of an extended property or the list of all extended properties from a database object

These stored procedures are clumsy to use and hardly encourage the programmer into using extended properties. However, a few examples might make their use a bit clearer:

A database-documenting stored procedure

I find the stored procedures described in the previous section unintuitive and don’t exactly tempt the programmer into adding documentation. For a start, if you try to add an extended property that already exists, you get an error. If you update an extended property that doesn’t exist, you get an error. If you put an extended property on an object that doesn’t exist, you get no error or return code to tell you.  From SQL Server 2005 onwards, a system view was added to make it easier to read extended properties but this doesn’t help with adding, deleting or updating them. I’d prefer something that described the object and its hierarchy in a more conventional way. For example if one wanted to alter the description of a surname column in a Customer table then it should be ‘dbo.Customer.Surname.MS_Description‘ using the ‘schema.table.column‘ hierarchy.

In order to make things easier, I created a simple ‘helper’ stored procedure which simplifies the access to Microsoft’s system stored procedures, but doesn’t try to replace them. If you provide the description of the object and the hierarchy, then it displays what is there. If you provide a value, it either assigns it or, if you want, appends it to the end of the current value.

The stored procedure autosenses which version of SQL Server it is on, and loads with the valid object hierarchies for the operating system. It checks the hierarchy you give it to see if it is valid. This list is rather handy, so the stored procedure also includes a feature that provides the hierarchy as a table.

The full source code for this sp_DBDoc stored procedure is provided in the source code for this article. It is designed to reside in the MASTER database so it can be used as a utility in any database on the server, but you must be db_owner in any database you want to use it for.

Create the stored procedure and let’s try it out. First, let’s see what hierarchies can have extended properties:

or, alternatively:

You will see that there are rather a lot – and that the possible objects that can have attributes attached to them were greatly expanded in SQL 2005, and just four were added since (those picked out in bold are available in both 2000 and 2005, but ‘user’ became ‘schema’ from 2005 onwards):

assembly

Schema.Service

user.function.Constraint

contract

Schema.Synonym

user.function.Parameter

Event Notification

Schema.Table

user.Procedure

fileGroup.Logical file Name

Schema.Table.Column

user.Procedure.Parameter

Message type

Schema.Table.Constraint

user.Queue

partition Function

Schema.Table.Index

user.Queue.Event Notification

partition Scheme

Schema.Table.Trigger

User.Rule

Remote Service Binding

Schema.Type

user.Service

route

Schema.View

user.Synonym

Schema

Schema.View.Trigger

User.Table

schema.aggregate

Schema.View.column

User.Table.Column

schema.Default

Schema.View.index

User.Table.Constraint

schema.function

Schema.XML Schema Collection

User.Table.Index

schema.function.column

Service

User.Table.Trigger

schema.function.Constraint

trigger

user.Type

schema.function.Parameter

type

User.View

schema.Procedure

user

User.View.column

schema.Procedure.Parameter

user.aggregate

User.View.index

schema.Queue

user.Default

User.View.Trigger

schema.Queue.Event Notification

user.function

User.XML Schema Collection

schema.Rule

user.function.column

Asymmetric Key

Certificate

Plan guide

Synonym

Let’s start very simply. Let’s just create a description for the entire database:

Nothing exciting here so let’s add a ‘revision date’ property:

Now we want to add the new version, rather than replace the existing value:

We can list all extended properties and values for columns of a given table, for example the customer table:

Assigning a standard MS_Documentation property and value is easy:

Or you can add your own property. By way of example, we assign a suggested convert style for a date field:

In the following code you’ll find several more examples for this procedure included as comments.

Of course, ultimately, extended properties are just one of the various means of ensuring that your databases are well-documented and easily understood, such as using long descriptive object names.