Problem solve Get help with specific problems with your technologies, process and projects.

Uncovering database file information with T-SQL metadata functions

Admins can use metadata functions to reveal detailed information about SQL Server files and filegroups, including file names, IDs and file properties.

Part 1 | Part 2 | Part 3

Part one of this series looked at how to use basic metadata functions to view object names and IDs, while part two examined additional metadata function uses, such as how to view property settings for various objects. Here, you’ll learn how to use metadata functions to view detailed database file and filegroup information.

Viewing file information

In addition to retrieving object and property information, you can use metadata functions to view details about the database files and their filegroups. For instance, in the following example I use the FILE_IDEX, FILE_NAME, FILEGROUP_ID, and FILEGROUP_NAME to retrieve data about the files and filegroups that support the AdventureWorks2008 database:

SELECT
   FILE_IDEX('AdventureWorks2008_Data') AS FileId,
   FILE_NAME(1) AS FileName,
   FILEGROUP_ID('primary') AS FileGroupId,
   FILEGROUP_NAME(1) AS FileGroupName;

The FILE_IDEX function returns the ID associated with a database file. As you can see, you must pass in the name of the file as an argument when you call the function. The FILE_NAME function returns the name of a file based on the ID you enter as an argument. The FILEGROUP_ID function returns the ID associated with a filegroup. Again, you must supply the name of that filegroup. Lastly, the FILEGROUP_NAME function returns the name of the filegroup based on the supplied ID. The SELECT statement returns the following results:

FileId FileName FileGroupId FileGroupName
1 AdventureWorks2008_Data 1 PRIMARY

As the results confirm, the ID for the AdventureWorks2008_Data file is 1 and the ID for the PRIMARY filegroup is 1.

SQL Server also supports metadata functions that let you view the properties for files and filegroups. For example, you can use the FILEPROPERTY function to retrieve the property settings for a specific file. To use the function you must specify the name of the file and then the name of the property, as shown in the following SELECT statement:

SELECT
   FILEPROPERTY('AdventureWorks2008_Data',
    'IsReadOnly') AS ReadOnly,
   FILEPROPERTY('AdventureWorks2008_Data',
    'IsPrimaryFile') AS PrimaryFile,
   FILEPROPERTY('AdventureWorks2008_Data',
    'SpaceUsed') AS SpaceUsed;

As you can see, the FILEPROPERTY function is similar to the property functions you saw earlier. First, I specified the name of the file (AdventureWorks2008_Data) and then the property. The IsReadOnly property indicates whether the file is read-only, the IsPrimaryFile property shows whether this is the primary database file and the SpaceUsed property shows how many pages have been allocated to the file. As the following results indicate, the file is not read-only, but it is the primary file and it has had 23,240 pages allocated to it:

ReadOnly PrimaryFile SpaceUsed
0 1 23240


SQL Server also supports a FILEGROUPPROPERTY function, which lets you view details about a filegroup. Again, you must specify two arguments -- the name of the filegroup and the name of the property. In the following SELECT statement, I retrieve information about the PRIMARY filegroup:

SELECT
   FILEGROUPPROPERTY('primary', 'IsReadOnly')
    AS ReadOnly,
   FILEGROUPPROPERTY('primary', 'IsUserDefinedFg')
    AS UserDefined,
   FILEGROUPPROPERTY('primary', 'IsDefault')
    AS DefaultFg;

As you would expect, the IsReadOnly property indicates whether the filegroup is read-only, the IsUserDefinedFg property indicates whether this is a user-defined filegroup and the IsDefault property shows whether this is the default filegroup. The following results show that the filegroup is neither read-only nor user-defined, but it is the default:

ReadOnly UserDefined DefaultFg
0 0 1

So there you have it. In this short series I’ve introduced you to a variety of metadata functions, but in the interest of brevity I did not go into the specifics of each function beyond how you can use them in your T-SQL statements. That is, I did not go into a lot of detail about the restrictions or limitations of the functions, but you can find more details by referring to the topic for that function in SQL Server Books Online. In the meantime, you should now be familiar enough with these functions to access much of the metadata available to each database.

Back to part one: Exploring metadata functions in SQL Server 2008

ABOUT THE AUTHOR
Robert Sheldon is a technical consultant and the author of numerous books, articles, and training material related to Microsoft Windows, various relational database management systems, and business intelligence design and implementation. You can find more information at www.rhsheldon.com.

This was last published in September 2010

Dig Deeper on SQL-Transact SQL (T-SQL)

Start the conversation

Send me notifications when other members comment.

By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy

Please create a username to comment.

-ADS BY GOOGLE

SearchBusinessAnalytics

SearchDataCenter

SearchDataManagement

SearchAWS

SearchOracle

SearchContentManagement

SearchWindowsServer

Close