Introduction
Extended stored procedure is a dynamic link library that run directly
in the address space of SQL Server and is programmed using the
SQL Server Open Data Services API. You can write your own extended
stored procedure in a programming language such as C. You can run
extended stored procedures from the Query Analyzer, for example,
as normal stored procedures. Extended stored procedures are used to
extend the capabilities of SQL Server.
In this article, I want to tell you about some useful undocumented
extended stored procedures. The extended stored procedures, which
were described below, are working with SQL Server 7.0 as well as with
SQL Server 2000.
sp_MSgetversion
This extended stored procedure can be used to get the current version
of Microsoft SQL Server.
To get the current SQL Server version, run
EXEC master..sp_MSgetversion
Note. By the way, more recommended way to get the current SQL Server
version (this way provides more information) is executing the following
select statement:
select @@version
xp_dirtree
This extended stored procedure can be used to get the list of all
subdirectories for the passed directory.
To get all subdirectories for the C:\MSSQL7 directory, run
EXEC master..xp_dirtree 'C:\MSSQL7'
Here is the result set from my machine:
subdirectory depth------------- -----------
Binn 1
Resources 2
1033 3
DevTools 1
Include 2
Lib 2
Data 1
Install 1
HTML 1
Books 1
LOG 1
JOBS 1
BACKUP 1
REPLDATA 1
FTP 2
xp_enum_oledb_providers
This extended stored procedure can be used to get the list of all
OLE DB providers. The xp_enum_oledb_providers returns Provider Name,
Parse Name and Provider Description.
To get the list of all OLE DB providers, run
EXEC master..xp_enum_oledb_providers
xp_enumcodepages
This extended stored procedure can be used to get the list of all
code pages, character sets and their description.
This is the example:
EXEC master..xp_enumcodepages
xp_enumdsn
This extended stored procedure returns the list of all System DSNs
and their description.
To get the list of System DSNs, run:
EXEC master..xp_enumdsn
xp_enumerrorlogs
This extended stored procedure returns the list of all error logs
with the last change date.
To get the list of error logs, run:
EXEC master..xp_enumerrorlogs
Here is the result set from my machine:
Archive # Date----------- ------------------
6 02/27/2001 08:00
5 03/04/2001 22:46
4 03/05/2001 22:28
3 03/08/2001 10:32
2 03/10/2001 00:06
1 03/10/2001 23:29
0 03/11/2001 18:58
xp_enumgroups
This extended stored procedure returns the list of Windows NT groups
and their description.
To get the list of the Windows NT groups, run:
EXEC master..xp_enumgroups
xp_fileexist
You can use this extended stored procedure to determine whether the
particular file exists on the disk or not.
Syntax:
EXECUTE xp_fileexist filename [, file_exists INT OUTPUT]
To check whether the file boot.ini exists on the disk c: or not, run:
EXEC master..xp_fileexist 'c:\boot.ini'
Here is the result set from my machine:
File Exists File is a Directory Parent Directory Exists----------- ------------------- -----------------------
1 0 1
xp_fixeddrives
This very useful extended stored procedure returns the list of all
fixed hard drives and the amount free space in Mb for each hard drive.
This is the example:
EXEC master..xp_fixeddrives
Here is the result set from my machine:
drive MB free----- -----------
C 12082
D 396
E 793
F 46
xp_getnetname
This extended stored procedure returns the WINS name of the SQL Server
that you're connected to.
This is the example:
EXEC master..xp_getnetname
Here is the result set from my machine:
Server Net Name---------------
CHIGRIK
xp_readerrorlog
This extended stored procedure returns the content of the errorlog
file. You can find this errorlog file in the C:\MSSQL7\Log directory,
by default.
To see the text of the errorlog file, run:
EXEC master..xp_readerrorlog
xp_regdeletekey
This extended stored procedure will delete the whole key from the
registry. You should use it very carefully.
Syntax:
EXECUTE xp_regdeletekey [@rootkey=]'rootkey',[@key=]'key'
To delete key 'SOFTWARE\Test' from the 'HKEY_LOCAL_MACHINE', run:
EXEC master..xp_regdeletekey@rootkey='HKEY_LOCAL_MACHINE',
@key='SOFTWARE\Test'
xp_regdeletevalue
This extended stored procedure will delete the particular value for
the key from the registry. You should use it very carefully.
Syntax:
EXECUTE xp_regdeletevalue [@rootkey=]'rootkey',[@key=]'key',
[@value_name=]'value_name'
To delete value 'TestValue' for the key 'SOFTWARE\Test' from the
'HKEY_LOCAL_MACHINE', run:
EXEC master..xp_regdeletevalue@rootkey='HKEY_LOCAL_MACHINE',
@key='SOFTWARE\Test',
@value_name='TestValue'
xp_regread
This extended stored procedure is used to read from the registry.
Syntax:
EXECUTE xp_regread [@rootkey=]'rootkey',[@key=]'key'
[, [@value_name=]'value_name']
[, [@value=]@value OUTPUT]
To read into variable @test from the value 'TestValue' from the key
'SOFTWARE\Test' from the 'HKEY_LOCAL_MACHINE', run:
DECLARE @test varchar(20)EXEC master..xp_regread @rootkey='HKEY_LOCAL_MACHINE',
@key='SOFTWARE\Test',
@value_name='TestValue',
@value=@test OUTPUT
SELECT @test
Here is the result set from my machine:
--------------------Test
xp_regwrite
This extended stored procedure is used to write in the registry.
Syntax:
EXECUTE xp_regwrite [@rootkey=]'rootkey',[@key=]'key',
[@value_name=]'value_name',
[@type=]'type',
[@value=]'value'
To write the variable 'Test' in value 'TestValue', key 'SOFTWARE\Test',
'HKEY_LOCAL_MACHINE', run:
EXEC master..xp_regwrite@rootkey='HKEY_LOCAL_MACHINE',
@key='SOFTWARE\Test',
@value_name='TestValue',
@type='REG_SZ',
@value='Test'
xp_subdirs
This extended stored procedure is used to get the list of subdirectories
for the passed directory. In comparison with xp_dirtree, xp_subdirs
returns only those directories whose depth = 1.
This is the example:
EXEC master..xp_subdirs 'C:\MSSQL7'
Here is the result set from my machine:
subdirectory-----------------------
Binn
DevTools
Data
Install
HTML
Books
LOG
JOBS
BACKUP
REPLDATA