- SQL Server Reference Guide
- Introduction
- SQL Server Reference Guide Overview
- Table of Contents
- Microsoft SQL Server Defined
- SQL Server Editions
- SQL Server Access
- Informit Articles and Sample Chapters
- Online Resources
- Microsoft SQL Server Features
- SQL Server Books Online
- Clustering Services
- Data Transformation Services (DTS) Overview
- Replication Services
- Database Mirroring
- Natural Language Processing (NLP)
- Analysis Services
- Microsot SQL Server Reporting Services
- XML Overview
- Notification Services for the DBA
- Full-Text Search
- SQL Server 2005 - Service Broker
- Using SQL Server as a Web Service
- SQL Server Encryption Options Overview
- SQL Server 2008 Overview
- SQL Server 2008 R2 Overview
- SQL Azure
- The Utility Control Point and Data Application Component, Part 1
- The Utility Control Point and Data Application Component, Part 2
- Microsoft SQL Server Administration
- The DBA Survival Guide: The 10 Minute SQL Server Overview
- Preparing (or Tuning) a Windows System for SQL Server, Part 1
- Preparing (or Tuning) a Windows System for SQL Server, Part 2
- Installing SQL Server
- Upgrading SQL Server
- SQL Server 2000 Management Tools
- SQL Server 2005 Management Tools
- SQL Server 2008 Management Tools
- SQL Azure Tools
- Automating Tasks with SQL Server Agent
- Run Operating System Commands in SQL Agent using PowerShell
- Automating Tasks Without SQL Server Agent
- Storage – SQL Server I/O
- Service Packs, Hotfixes and Cumulative Upgrades
- Tracking SQL Server Information with Error and Event Logs
- Change Management
- SQL Server Metadata, Part One
- SQL Server Meta-Data, Part Two
- Monitoring - SQL Server 2005 Dynamic Views and Functions
- Monitoring - Performance Monitor
- Unattended Performance Monitoring for SQL Server
- Monitoring - User-Defined Performance Counters
- Monitoring: SQL Server Activity Monitor
- SQL Server Instances
- DBCC Commands
- SQL Server and Mail
- Database Maintenance Checklist
- The Maintenance Wizard: SQL Server 2000 and Earlier
- The Maintenance Wizard: SQL Server 2005 (SP2) and Later
- The Web Assistant Wizard
- Creating Web Pages from SQL Server
- SQL Server Security
- Securing the SQL Server Platform, Part 1
- Securing the SQL Server Platform, Part 2
- SQL Server Security: Users and other Principals
- SQL Server Security – Roles
- SQL Server Security: Objects (Securables)
- Security: Using the Command Line
- SQL Server Security - Encrypting Connections
- SQL Server Security: Encrypting Data
- SQL Server Security Audit
- High Availability - SQL Server Clustering
- SQL Server Configuration, Part 1
- SQL Server Configuration, Part 2
- Database Configuration Options
- 32- vs 64-bit Computing for SQL Server
- SQL Server and Memory
- Performance Tuning: Introduction to Indexes
- Statistical Indexes
- Backup and Recovery
- Backup and Recovery Examples, Part One
- Backup and Recovery Examples, Part Two: Transferring Databases to Another System (Even Without Backups)
- SQL Profiler - Reverse Engineering An Application
- SQL Trace
- SQL Server Alerts
- Files and Filegroups
- Partitioning
- Full-Text Indexes
- Read-Only Data
- SQL Server Locks
- Monitoring Locking and Deadlocking
- Controlling Locks in SQL Server
- SQL Server Policy-Based Management, Part One
- SQL Server Policy-Based Management, Part Two
- SQL Server Policy-Based Management, Part Three
- Microsoft SQL Server Programming
- An Outline for Development
- Database
- Database Services
- Database Objects: Databases
- Database Objects: Tables
- Database Objects: Table Relationships
- Database Objects: Keys
- Database Objects: Constraints
- Database Objects: Data Types
- Database Objects: Views
- Database Objects: Stored Procedures
- Database Objects: Indexes
- Database Objects: User Defined Functions
- Database Objects: Triggers
- Database Design: Requirements, Entities, and Attributes
- Business Process Model Notation (BPMN) and the Data Professional
- Business Questions for Database Design, Part One
- Business Questions for Database Design, Part Two
- Database Design: Finalizing Requirements and Defining Relationships
- Database Design: Creating an Entity Relationship Diagram
- Database Design: The Logical ERD
- Database Design: Adjusting The Model
- Database Design: Normalizing the Model
- Creating The Physical Model
- Database Design: Changing Attributes to Columns
- Database Design: Creating The Physical Database
- Database Design Example: Curriculum Vitae
- NULLs
- The SQL Server Sample Databases
- The SQL Server Sample Databases: pubs
- The SQL Server Sample Databases: NorthWind
- The SQL Server Sample Databases: AdventureWorks
- The SQL Server Sample Databases: Adventureworks Derivatives
- UniversalDB: The Demo and Testing Database, Part 1
- UniversalDB: The Demo and Testing Database, Part 2
- UniversalDB: The Demo and Testing Database, Part 3
- UniversalDB: The Demo and Testing Database, Part 4
- Getting Started with Transact-SQL
- Transact-SQL: Data Definition Language (DDL) Basics
- Transact-SQL: Limiting Results
- Transact-SQL: More Operators
- Transact-SQL: Ordering and Aggregating Data
- Transact-SQL: Subqueries
- Transact-SQL: Joins
- Transact-SQL: Complex Joins - Building a View with Multiple JOINs
- Transact-SQL: Inserts, Updates, and Deletes
- An Introduction to the CLR in SQL Server 2005
- Design Elements Part 1: Programming Flow Overview, Code Format and Commenting your Code
- Design Elements Part 2: Controlling SQL's Scope
- Design Elements Part 3: Error Handling
- Design Elements Part 4: Variables
- Design Elements Part 5: Where Does The Code Live?
- Design Elements Part 6: Math Operators and Functions
- Design Elements Part 7: Statistical Functions
- Design Elements Part 8: Summarization Statistical Algorithms
- Design Elements Part 9:Representing Data with Statistical Algorithms
- Design Elements Part 10: Interpreting the Data—Regression
- Design Elements Part 11: String Manipulation
- Design Elements Part 12: Loops
- Design Elements Part 13: Recursion
- Design Elements Part 14: Arrays
- Design Elements Part 15: Event-Driven Programming Vs. Scheduled Processes
- Design Elements Part 16: Event-Driven Programming
- Design Elements Part 17: Program Flow
- Forming Queries Part 1: Design
- Forming Queries Part 2: Query Basics
- Forming Queries Part 3: Query Optimization
- Forming Queries Part 4: SET Options
- Forming Queries Part 5: Table Optimization Hints
- Using SQL Server Templates
- Transact-SQL Unit Testing
- Index Tuning Wizard
- Unicode and SQL Server
- SQL Server Development Tools
- The SQL Server Transact-SQL Debugger
- The Transact-SQL Debugger, Part 2
- Basic Troubleshooting for Transact-SQL Code
- An Introduction to Spatial Data in SQL Server 2008
- Performance Tuning
- Performance Tuning SQL Server: Tools and Processes
- Performance Tuning SQL Server: Tools Overview
- Creating a Performance Tuning Audit - Defining Components
- Creating a Performance Tuning Audit - Evaluation Part One
- Creating a Performance Tuning Audit - Evaluation Part Two
- Creating a Performance Tuning Audit - Interpretation
- Creating a Performance Tuning Audit - Developing an Action Plan
- Understanding SQL Server Query Plans
- Performance Tuning: Implementing Indexes
- Performance Monitoring Tools: Windows 2008 (and Higher) Server Utilities, Part 1
- Performance Monitoring Tools: Windows 2008 (and Higher) Server Utilities, Part 2
- Performance Monitoring Tools: Windows System Monitor
- Performance Monitoring Tools: Logging with System Monitor
- Performance Monitoring Tools: User Defined Counters
- General Transact-SQL (T-SQL) Performance Tuning, Part 1
- General Transact-SQL (T-SQL) Performance Tuning, Part 2
- General Transact-SQL (T-SQL) Performance Tuning, Part 3
- Performance Monitoring Tools: An Introduction to SQL Profiler
- Performance Tuning: Introduction to Indexes
- Performance Monitoring Tools: SQL Server 2000 Index Tuning Wizard
- Performance Monitoring Tools: SQL Server 2005 Database Tuning Advisor
- Performance Monitoring Tools: SQL Server Management Studio Reports
- Performance Monitoring Tools: SQL Server 2008 Activity Monitor
- The SQL Server 2008 Management Data Warehouse and Data Collector
- Performance Monitoring Tools: Evaluating Wait States with PowerShell and Excel
- Practical Applications
- Choosing the Back End
- The DBA's Toolbox, Part 1
- The DBA's Toolbox, Part 2
- Scripting Solutions for SQL Server
- Building a SQL Server Lab
- Using Graphics Files with SQL Server
- Enterprise Resource Planning
- Customer Relationship Management (CRM)
- Building a Reporting Data Server
- Building a Database Documenter, Part 1
- Building a Database Documenter, Part 2
- Data Management Objects
- Data Management Objects: The Server Object
- Data Management Objects: Server Object Methods
- Data Management Objects: Collections and the Database Object
- Data Management Objects: Database Information
- Data Management Objects: Database Control
- Data Management Objects: Database Maintenance
- Data Management Objects: Logging the Process
- Data Management Objects: Running SQL Statements
- Data Management Objects: Multiple Row Returns
- Data Management Objects: Other Database Objects
- Data Management Objects: Security
- Data Management Objects: Scripting
- Powershell and SQL Server - Overview
- PowerShell and SQL Server - Objects and Providers
- Powershell and SQL Server - A Script Framework
- Powershell and SQL Server - Logging the Process
- Powershell and SQL Server - Reading a Control File
- Powershell and SQL Server - SQL Server Access
- Powershell and SQL Server - Web Pages from a SQL Query
- Powershell and SQL Server - Scrubbing the Event Logs
- SQL Server 2008 PowerShell Provider
- SQL Server I/O: Importing and Exporting Data
- SQL Server I/O: XML in Database Terms
- SQL Server I/O: Creating XML Output
- SQL Server I/O: Reading XML Documents
- SQL Server I/O: Using XML Control Mechanisms
- SQL Server I/O: Creating Hierarchies
- SQL Server I/O: Using HTTP with SQL Server XML
- SQL Server I/O: Using HTTP with SQL Server XML Templates
- SQL Server I/O: Remote Queries
- SQL Server I/O: Working with Text Files
- Using Microsoft SQL Server on Handheld Devices
- Front-Ends 101: Microsoft Access
- Comparing Two SQL Server Databases
- English Query - Part 1
- English Query - Part 2
- English Query - Part 3
- English Query - Part 4
- English Query - Part 5
- RSS Feeds from SQL Server
- Using SQL Server Agent to Monitor Backups
- Reporting Services - Creating a Maintenance Report
- SQL Server Chargeback Strategies, Part 1
- SQL Server Chargeback Strategies, Part 2
- SQL Server Replication Example
- Creating a Master Agent and Alert Server
- The SQL Server Central Management System: Definition
- The SQL Server Central Management System: Base Tables
- The SQL Server Central Management System: Execution of Server Information (Part 1)
- The SQL Server Central Management System: Execution of Server Information (Part 2)
- The SQL Server Central Management System: Collecting Performance Metrics
- The SQL Server Central Management System: Centralizing Agent Jobs, Events and Scripts
- The SQL Server Central Management System: Reporting the Data and Project Summary
- Time Tracking for SQL Server Operations
- Migrating Departmental Data Stores to SQL Server
- Migrating Departmental Data Stores to SQL Server: Model the System
- Migrating Departmental Data Stores to SQL Server: Model the System, Continued
- Migrating Departmental Data Stores to SQL Server: Decide on the Destination
- Migrating Departmental Data Stores to SQL Server: Design the ETL
- Migrating Departmental Data Stores to SQL Server: Design the ETL, Continued
- Migrating Departmental Data Stores to SQL Server: Attach the Front End, Test, and Monitor
- Tracking SQL Server Timed Events, Part 1
- Tracking SQL Server Timed Events, Part 2
- Patterns and Practices for the Data Professional
- Managing Vendor Databases
- Consolidation Options
- Connecting to a SQL Azure Database from Microsoft Access
- SharePoint 2007 and SQL Server, Part One
- SharePoint 2007 and SQL Server, Part Two
- SharePoint 2007 and SQL Server, Part Three
- Querying Multiple Data Sources from a Single Location (Distributed Queries)
- Importing and Exporting Data for SQL Azure
- Working on Distributed Teams
- Professional Development
- Becoming a DBA
- Certification
- DBA Levels
- Becoming a Data Professional
- SQL Server Professional Development Plan, Part 1
- SQL Server Professional Development Plan, Part 2
- SQL Server Professional Development Plan, Part 3
- Evaluating Technical Options
- System Sizing
- Creating a Disaster Recovery Plan
- Anatomy of a Disaster (Response Plan)
- Database Troubleshooting
- Conducting an Effective Code Review
- Developing an Exit Strategy
- Data Retention Strategy
- Keeping Your DBA/Developer Job in Troubled Times
- The SQL Server Runbook
- Creating and Maintaining a SQL Server Configuration History, Part 1
- Creating and Maintaining a SQL Server Configuration History, Part 2
- Creating an Application Profile, Part 1
- Creating an Application Profile, Part 2
- How to Attend a Technical Conference
- Tips for Maximizing Your IT Budget This Year
- The Importance of Blue-Sky Planning
- Application Architecture Assessments
- Transact-SQL Code Reviews, Part One
- Transact-SQL Code Reviews, Part Two
- Cloud Computing (Distributed Computing) Paradigms
- NoSQL for the SQL Server Professional, Part One
- NoSQL for the SQL Server Professional, Part Two
- Object-Role Modeling (ORM) for the Database Professional
- Business Intelligence
- BI Explained
- Developing a Data Dictionary
- BI Security
- Gathering BI Requirements
- Source System Extracts and Transforms
- ETL Mechanisms
- Business Intelligence Landscapes
- Business Intelligence Layouts and the Build or Buy Decision
- A Single Version of the Truth
- The Operational Data Store (ODS)
- Data Marts – Combining and Transforming Data
- Designing Data Elements
- The Enterprise Data Warehouse — Aggregations and the Star Schema
- On-Line Analytical Processing (OLAP)
- Data Mining
- Key Performance Indicators
- BI Presentation - Client Tools
- BI Presentation - Portals
- Implementing ETL - Introduction to SQL Server 2005 Integration Services
- Building a Business Intelligence Solution, Part 1
- Building a Business Intelligence Solution, Part 2
- Building a Business Intelligence Solution, Part 3
- Tips and Troubleshooting
- SQL Server and Microsoft Excel Integration
- Tips for the SQL Server Tools: SQL Server 2000
- Tips for the SQL Server Tools – SQL Server 2005
- Transaction Log Troubles
- SQL Server Connection Problems
- Orphaned Database Users
- Additional Resources
- Tools and Downloads
- Utilities (Free)
- Tool Review (Free): DBDesignerFork
- Aqua Data Studio
- Microsoft SQL Server Best Practices Analyzer
- Utilities (Cost)
- Quest Software's TOAD for SQL Server
- Quest Software's Spotlight on SQL Server
- SQL Server on Microsoft's Virtual PC
- Red Gate SQL Bundle
- Microsoft's Visio for Database Folks
- Quest Capacity Manager
- SQL Server Help
- Visual Studio Team Edition for Database Professionals
- Microsoft Assessment and Planning Solution Accelerator
- Aggregating Server Data from the MAPS Tool
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