Home > Articles > Data > SQL Server

SQL Server Reference Guide

Hosted by

Toggle Open Guide Table of ContentsGuide Contents

Close Table of ContentsGuide Contents

Close Table of Contents

SQL Server Meta-Data, Part Two

Last updated Mar 28, 2003.

It is vital to understand your system, and in part one of this tutorial I explained how you can find the “Meta-data” or “data about data” — on your system, including the server settings and data structures. In the previous tutorial, I explained the “proper” way to query your system, using the “sp_help” stored procedures, the graphical tools, and several system functions. In this tutorial, I will spend a little more time “under the covers”, and explore the ways you can query system tables to see the state of your server.

I do not recommend that you use the system tables unless you have to. The whole point of those views, stored procedures and functions on the server is so that the data is “abstracted” away for you. That way the system tables can change, but your data will always be available. However, sometimes, especially in the earlier versions of SQL Server, the system tables provided the richest view of all of the system objects. In addition, most of the time those tables have remained stable. So knowing the system objects provides a “lingua franca” of sorts between the versions.

To begin, you need to understand a little about the system databases. You get four databases automatically when you install SQL Server:

  • master
  • model
  • msdb
  • tempdb

The “master” database is where we will spend the most time in this tutorial. It holds much of the data that SQL Server uses to run itself. I will show you some of the most interesting tables you have there, but there are many others that we will not cover.

The “model” database is used whenever you create a new database. Anything you put in the model database is placed in any other database you create after that. It does not affect restored or attached databases, but serves as a template when you type CREATE DATABASE or use the graphical tools to create a database. Other than the system tables for a database (which I will explain shortly), there are not any system objects we are interested in here.

The “msdb” database is used by the SQL Server Agent system. I will not cover those tables in this tutorial, but I will cover it later. There is a tremendous amount of information you can get from this database regarding maintenance plans, backups, replication, Agent Jobs and more.

The “tempdb” database is created each time the system starts up, and is destroyed each time the system shuts down. I won’t cover anything in this database in this tutorial.

So let’s get started with the tables that show system information, and then move on to the database and security information. Once again, I’ll use SQL Server 2000 for this tutorial, since it is the earliest version I talk about on this site. With only a few exceptions (such as putting sys. in front of the table name) you can still use these queries for SQL Server 2005 and higher. In the next few tutorials I’ll show you

System Information

The primary database you can use for system information is master. Within this database are several tables you can use to get meta-data about the system. The first is sysservers. There are a few settings here that can be useful, but to get a quick list of the SQL Server Instances your system “knows” about, and whether they are local or a linked server, run this query:

SELECT srvname 
, 'ServerType' = CASE isremote 
	WHEN 0 THEN 'LocalServer'
	WHEN 1 THEN 'LinkedServer'
END
FROM sysservers;
GO 

Database Information

The master database also stores information about the databases each instance owns. To get a list of databases, you can use the sysdatabases table:

SELECT name AS 'DatabaseName'
, dbid AS 'DatabaseID'
, crdate AS 'CreateDate'
, filename AS 'PrimaryFile'
FROM
sysdatabases
ORDER BY name;
GO

The important field here is dbid, which is the unique key for each database. We will use that to create other interesting information shortly.

For the rest of the database information, you set the context, using the USE databasename; GO query. Each database has a set of system tables used to track information for that database.

The previous query only shows the primary file. Databases have multiple files, for both the data and the logs. Each file has a “logical” name, used by SQL Server, and a “physical” filename that is used by the operating system. To show all of the files for a database, you can query the sysfiles table like this:

SELECT fileid AS 'FileID'
, name AS 'LogicalName'
, 'FileType' = CASE status
	WHEN 1048576 THEN 'DataFile'
	WHEN 1048642 THEN 'LogFile'
END
, filename AS 'FilenName'
, ((size*8192)/1024) AS 'SizeMB' 
FROM sysfiles
ORDER BY LogicalName;
GO

Drilling down to the next level, you can find the database objects using one of the largest tables, called sysobjects. This table will take a few passes, so let’s take a look at a simple query that gets the various objects in a database by type:

SELECT name AS 'ObjectName'
, 'ObjectType' = CASE xtype 
WHEN 'C' THEN 'CHECK'
WHEN 'D' THEN 'DEFAULT'
WHEN 'F' THEN 'FOREIGNKEY'
WHEN 'L' THEN 'Log'
WHEN 'FN' THEN 'ScalarFunction'
WHEN 'IF' THEN 'InlineTableFunction'
WHEN 'P' THEN 'StoredProcedure'
WHEN 'PK' THEN 'PRIMARYKEY'
WHEN 'RF' THEN 'ReplicationFilterStoredProcedure' 
WHEN 'S' THEN 'SystemTable'
WHEN 'TF' THEN 'TableFunction'
WHEN 'TR' THEN 'Trigger'
WHEN 'U' THEN 'UserTable'
WHEN 'UQ' THEN 'UNIQUEConstraint'
WHEN 'V' THEN 'View'
WHEN 'X' THEN 'ExtendedStoredProcedure'
END
FROM sysobjects
ORDER BY xtype, name;
GO

This query is actually kind of cumbersome — it shows all objects in the database. Usually you want a specific object, or a set of objects. For instance, to find all of the stored procedures in a database, you can use this query. Just replace “master” with the name of the database you want to search:

USE master;
GO
SELECT name 
FROM sysobjects
WHERE xtype = 'P'
ORDER BY name;
GO

You’ll notice that when you query the tables (xtype=’U’) you don’t see any columns. Those are actually stored in another table, called syscolumns. Joining the sysobjects table to the syscolumns table, you can find the column names (this makes more sense in a database like pubs):

USE pubs;
GO
SELECT b.name AS 'Table'
, a.name AS 'Column'
FROM syscolumns a
INNER JOIN sysobjects b
ON a.id = b.id
ORDER BY b.name, a.name;
GO

Although you can find the foreign keys and other relationships using system tables, I will cover that in another article.

Security Information

Now we will go after the logins on the server, once again using the master database, this time using the syslogins table. Remember that SQL Server has two principals associated with any particular database object — a server login, and a database user. This query shows the logins for the server:

USE master;
GO

SELECT SID AS 'SecurityID'
, name AS 'UserName' 
, loginname AS 'LoginName'
, 'LoginType' = CASE isntuser
	WHEN 0 THEN 'SQLOrOtherLogin'
	WHEN 1 THEN 'WindowsUserAccount'
END
FROM syslogins
ORDER BY name, loginname;
GO

Just as we moved into the database for specific database information, you will need to change the “context” of the database you are working in by using the pull-down graphical tool in your query tool. Personally, I always use the USE statement, because that works for both the graphical tools and any scripting I do.

Because there are actually two principals involved (the server login and the database user), I like to make sure I know how the two are linked. Normally you’ll create the same name for both accounts, but because we are DBAs, we are naturally untrusting! I always include the name of the server login along with my database users. Here is a query on the sysusers (database) table that shows that information:

USE pubs;
GO

SELECT a.name AS 'DatabaseUser'
, b.loginname AS 'ServerLogin'
FROM sysusers a
INNER JOIN master.dbo.syslogins b
ON a.sid = b.sid 
ORDER BY a.name;
GO

There are other methods that you can use to get meta-data about your systems. In the next tutorial, I will show you the Dynamic Management Views you have for SQL Server 2005 and higher. And in the references section, I will show you how to use the Database Management Objects (DMO) and PowerShell in a programming route to find meta-data. You have many options.

InformIT Articles and Sample Chapters

There is a lot more information on the system tables in the article SQL Building Blocks and Server Settings

Books and eBooks

My good friend Richard Waymire has a rundown on this same kind of information, all the way back in SQL Server version 7, in Sams Teach Yourself Microsoft SQL Server 7 in 21 Days, available in the (free) InformIT Reference Library.

Online Resources

Once you learn these tables, you can read the next tutorial that shows you how to use the newer functions and views for the same info. But Microsoft also has a complete article describing the relationships between the old system tables that I’ve shown here and the newer functions: http://msdn.microsoft.com/en-us/library/ms187997(SQL.90).aspx

And if you want a full download of an Entity Relationship Diagram (ERD) of the system tables in SQL Server 2000, you can get that here for free: http://microsoft.apress.com/asptodayarchive/72995/using-sql-server-system-tables-metadata