In SQL Server the sp_server_info
system stored procedure returns a list of attribute names and matching values for SQL Server, the database gateway, or the underlying data source. It returns a subset of the information provided by SQLGetInfo in ODBC.
Basically, it allows you to see information about SQL Server.
Syntax
The syntax goes like this:
sp_server_info [[@attribute_id = ] 'attribute_id']
The (optional) @attribute_id
argument enables you to narrow the results to just one specific attribute.
Example 1 – Return All Attributes
In this example, I execute the stored procedure without passing any arguments.
EXEC sp_server_info;
It can also be run like this:
sp_server_info;
Here’s the result on my SQL Server 2019 instance:
+----------------+------------------------+---------------------------------------------------------------------+ | attribute_id | attribute_name | attribute_value | |----------------+------------------------+---------------------------------------------------------------------| | 1 | DBMS_NAME | Microsoft SQL Server | | 2 | DBMS_VER | Microsoft SQL Server 2019 - 15.0.1800.32 | | 10 | OWNER_TERM | owner | | 11 | TABLE_TERM | table | | 12 | MAX_OWNER_NAME_LENGTH | 128 | | 13 | TABLE_LENGTH | 128 | | 14 | MAX_QUAL_LENGTH | 128 | | 15 | COLUMN_LENGTH | 128 | | 16 | IDENTIFIER_CASE | MIXED | | 17 | TX_ISOLATION | 2 | | 18 | COLLATION_SEQ | charset=iso_1 sort_order=nocase_iso charset_num=1 sort_order_num=52 | | 19 | SAVEPOINT_SUPPORT | Y | | 20 | MULTI_RESULT_SETS | Y | | 22 | ACCESSIBLE_TABLES | Y | | 100 | USERID_LENGTH | 128 | | 101 | QUALIFIER_TERM | database | | 102 | NAMED_TRANSACTIONS | Y | | 103 | SPROC_AS_LANGUAGE | Y | | 104 | ACCESSIBLE_SPROC | Y | | 105 | MAX_INDEX_COLS | 16 | | 106 | RENAME_TABLE | Y | | 107 | RENAME_COLUMN | Y | | 108 | DROP_COLUMN | Y | | 109 | INCREASE_COLUMN_LENGTH | Y | | 110 | DDL_IN_TRANSACTION | Y | | 111 | DESCENDING_INDEXES | Y | | 112 | SP_RENAME | Y | | 113 | REMOTE_SPROC | Y | | 500 | SYS_SPROC_VERSION | 15.00.1800 | +----------------+------------------------+---------------------------------------------------------------------+
Example 2 – Specify an Attribute
If you’re only interested in one attribute, you can pass that attribute’s ID. Doing this results in just the row of that attribute being returned.
EXEC sp_server_info 500;
It can also be done like this:
sp_server_info 500; sp_server_info @attribute_id = 500; EXEC sp_server_info @attribute_id = 500;
Result:
+----------------+-------------------+-------------------+ | attribute_id | attribute_name | attribute_value | |----------------+-------------------+-------------------| | 500 | SYS_SPROC_VERSION | 15.00.1800 | +----------------+-------------------+-------------------+
In this example, I return attribute number 500, which specifies the version of the catalog stored procedures currently implemented.
Example 3 – Run sp_server_info on a Linked Server
In this example, I execute sp_server_info
via a pass-through query on a linked server called Homer.
SELECT * FROM OPENQUERY( Homer, 'EXEC sp_server_info 500' );
Result:
+----------------+-------------------+-------------------+ | attribute_id | attribute_name | attribute_value | |----------------+-------------------+-------------------| | 500 | SYS_SPROC_VERSION | 14.00.3048 | +----------------+-------------------+-------------------+
Example 4 – Specify Which Columns are Displayed
One side-benefit of OPENQUERY()
is that you can reduce the columns returned by the stored procedure.
Example:
SELECT attribute_name, attribute_value FROM OPENQUERY( Homer, 'EXEC sp_server_info 500' );
Result:
+-------------------+-------------------+ | attribute_name | attribute_value | |-------------------+-------------------| | SYS_SPROC_VERSION | 14.00.3048 | +-------------------+-------------------+