This document contains information on undocumented stored procedures in Microsoft SQL Server.
Name | Function | |
---|---|---|
sp_cursor | Update a cursor | |
sp_cursorclose | close a cursor | |
sp_cursorexecute | Open a prepared cursor | |
sp_cursorfetch | Fetch rows | |
sp_cursoropen | Open a cursor | |
sp_cursoroption | Set cursor options | |
sp_cursorprepare | Prepare a cursor statement | |
sp_cursorprepexec | Prepare a cursor statement and open | |
sp_cursorunprepare | Free a prepared cursor statement | |
sp_execute | Execute a prepared statement | |
sp_prepare | Prepare an SQL statement | |
sp_prepexec | Prepare and execute an SQL statement | |
sp_unprepare | Free a prepared statement |
Defines the attributes of an API server cursor, such as its scrolling behavior and the statement used to build the result set on which the cursor operates, then populates the cursor. The statement can contain embedded parameters.
sp_cursoropen [@cursor =] cursor_handle OUTPUT,
[@stmt =] 'stmt'
[, [@scrollopt =] scroll_options OUTPUT]
[, [@ccopt =] concurrency_options OUTPUT]
[, [@rowcount =] rowcount OUTPUT]
[
{, [@paramdef =] N'parameter_name data_type
[,...n]' }
{, [@param1 =] value1 [,...n]
}
]
Is a string containing a single SELECT statement or a single stored procedure call. The size of the string is limited only by available database server memory. stmt can contain parameters having the same form as a variable name, for example:
'SELECT * FROM Employees WHERE EmployeeID = @IDParameter'
Each parameter included in stmt must have a corresponding entry in both the @paramdef parameter definition list and the parameter values list.
Value | Description |
---|---|
0x0001 | Keyset-driven cursor. |
0x0002 | Dynamic cursor. |
0x0004 | Forward-only cursor. |
0x0008 | Static cursor. |
0x0010 | Fast forward-only cursor. |
0x1000 | Parameterized query. |
0x2000 | Auto fetch. |
0x4000 | Auto close. |
0x8000 | Check acceptable types. |
0x10000 | Keyset-driven acceptable. |
0x20000 | Dynamic acceptable. |
0x40000 | Forward-only acceptable. |
0x80000 | Static acceptable. |
0x100000 | Fast forward-only acceptable. |
Value | Description |
---|---|
0x0001 | Read-only. |
0x0002 | Scroll locks. |
0x0004 | Optimistic. Checks timestamps and, when not available, values. |
0x0008 | Optimistic. Checks values (non-text, non-image). |
0x2000 | Open on any SQL. |
0x4000 | Update keyset in place. |
0x10000 | Read-only acceptable. |
0x20000 | Locks acceptable. |
0x40000 | Optimistic acceptable. |
0 (success) or 1 (failure).
Returns the result set generated by stmt, but containing no rows.
sp_cursoropen is a more powerful (and programmatic) way of creating server-side cursors on SQL Server.
Execute permissions default to the public role.
This simple example creates a dynamic read-only cursor for a SELECT statement with no parameters.
USE pubs
-- Create a dynamc read-only cursor
DECLARE @cursor INT
EXEC sp_cursoropen @cursor OUTPUT, N'SELECT * FROM myTable',
2, 8193
-- Close the cursor
EXEC sp_cursorclose @cursor
This example creates a dynamic read-only cursor for a SELECT statement with 2 parameters.
USE pubs
-- Create a dynamc read-only cursor
DECLARE @cursor INT
EXEC sp_cursoropen @cursor OUTPUT, N'SELECT * FROM myTable
WHERE col1=@P1 AND col2 LIKE @P2', 2, 8193, N'@P1 INT, @P2 VARCHAR(255)', 10,
'%x%'
-- Close the cursor
EXEC sp_cursorclose @cursor
This example creates a dynamic read-only cursor for a stored procedure with 2 parameters (the procedure must return only one result set or the cursor creation will fail). Note that output parameters can also be used and return values retrieved via output parameters.
USE pubs
-- Create a dynamc read-only cursor
DECLARE @cursor INT
DECLARE @retval INT
EXEC sp_cursoropen @cursor OUTPUT, 'EXEC @P1=myProc @P2',
2, 8193, N'@P1 INT OUTPUT, @P2 INT', @retval, 1
-- Close the cursor
EXEC sp_cursorclose @cursor
Fetches a row or block of rows from an API server cursor.
sp_cursorfetch [@cursor =] cursor_handle
[, [@fetchtype =] fetchtype]
[, [@rownum =] rownum OUTPUT]
[, [@nrows =] nrows OUTPUT]
Value | Description |
---|---|
0x0001 | First row. |
0x0002 | Next row. |
0x0004 | Previous row. |
0x0008 | Last row. |
0x0010 | Absolute row index. |
0x0020 | Relative row index. |
0x0040 | By value (???). |
0x0080 | Refresh. |
0x0100 | Result set info. |
0x0200 | Previous noadjust (?). |
0x0400 | Skip update concurrency (???). |
0 (success) or 1 (failure).
Returns the requested row or group of rows from the cursor.
In addition to fetching rows, the 'result set info' fetch type can be used to retrieve information about the cursor (current row in @rownum and total number of rows in @nrows).
Execute permissions default to the public role.
USE pubs
-- Create a dynamc read-only cursor
DECLARE @cursor INT
EXEC sp_cursoropen @cursor OUTPUT, 'SELECT * FROM myTable',
2, 8193
-- Fetch the next 3 lines
EXEC sp_cursorfetch @cursor, 2, 0, 3
-- Close the cursor
EXEC sp_cursorclose @cursor
Closes ande deallocates an API server cursor.
sp_cursorclose [@cursor =] cursor_handle
0 (success) or 1 (failure).
None.
Execute permissions default to the public role.
USE pubs
-- Create a dynamic read-only cursor
DECLARE @cursor INT
EXEC sp_cursoropen @cursor OUTPUT, 'SELECT * FROM myTable',
2, 8193
-- Close the cursor
EXEC sp_cursorclose @cursor
Sets various options for API server cursors.
sp_cursoroption [@cursor =] cursor_handle,
[@code =] code,
{ [@value =] value
| [@cursorname =] cursorname }
Value | Description |
---|---|
1 | Only return the TEXTPTR of the LOB column specified by value |
2 | Set cursor name. |
0 (success) or 1 (failure).
None.
Execute permissions default to the public role.
USE pubs
-- Create a dynamc cursor
DECLARE @cursor INT
EXEC sp_cursoropen @cursor OUTPUT, 'SELECT * FROM myTable',
2, 8193
-- Name the cursor
EXEC sp_cursoroption @cursor, 2, 'myCursor'
-- Use a cursor variable to access the cursor
DECLARE @x CURSOR
EXEC sp_describe_cursor @x out, N'global', 'myCursor'
FETCH NEXT FROM @x
-- Use the cursor directly by name
FETCH NEXT FROM myCursor
-- Close the cursor
EXEC sp_cursorclose @cursor
Can be used to request inserts and positioned updates or deletes on API server cursors.
sp_cursor [@cursor =] cursor_handle,
[@optype =] optype,
[@rownum =] rownum,
[@table =] 'table'
{, [@param1 =] value1 [,...n]
}
Value | Description |
---|---|
1 | Update row (?). |
4 | Insert row. |
33 | Update row. |
34 | Delete row. |
0 (success) or 1 (failure).
None.
Execute permissions default to the public role.
USE pubs
-- Create a dynamc cursor
DECLARE @cursor INT
EXEC sp_cursoropen @cursor OUTPUT, 'SELECT * FROM myTable',
2, 8193
-- Fetch the next 2 lines; this puts lines 1 and 2 in the
fetch buffer
EXEC sp_cursorfetch @cursor, 2, 0, 2
-- Update the second line in the fetch buffer
EXEC sp_cursor @cursor, 33, 2, '', @intCol=5, @charCol='x'
-- Close the cursor
EXEC sp_cursorclose @cursor
Used to prepare a parameterized cursor statement.
sp_cursorprepare [@cursor =] statement_handle OUTPUT,
[@paramdef =] N'parameter_name data_type
[,...n]',
[@stmt =] N'stmt',
[@options =] options,
[, [@scrollopt =] scroll_options OUTPUT]
[, [@ccopt =] concurrency_options OUTPUT]
Is a string containing a single SELECT statement or a single stored procedure call. The size of the string is limited only by available database server memory. stmt can contain parameters having the same form as a variable name, for example:
'SELECT * FROM Employees WHERE EmployeeID = @IDParameter'
Each parameter included in stmt must have a corresponding entry in both the @paramdef parameter definition list.
0 (success) or 1 (failure).
None.
Execute permissions default to the public role.
Used to prepare and open a parameterized cursor statement. This command combines the functions of the sp_cursorprepare and sp_cursorexecute procedures and is available from SQL2000 onwards.
sp_cursorprepexec [@handle =] statement_handle OUTPUT,
[@cursor =] cursor_handle OUTPUT,
[@paramdef =] N'parameter_name data_type,
[,...n]'
[@stmt =] N'stmt',
[, [@scrollopt =] scroll_options OUTPUT]
[, [@ccopt =] concurrency_options OUTPUT]
[, [@rowcount =] rowcount OUTPUT]
Is a string containing a single SELECT statement or a single stored procedure call. The size of the string is limited only by available database server memory. stmt can contain parameters having the same form as a variable name, for example:
'SELECT * FROM Employees WHERE EmployeeID = @IDParameter'
Each parameter included in stmt must have a corresponding entry in both the @paramdef parameter definition list.
0 (success) or 1 (failure).
Returns the result set generated by stmt, but containing no rows.
Execute permissions default to the public role.
Used to execute (open) a prepared cursor statement.
sp_cursorexecute [@handle =] statement_handle,
[@cursor =] cursor_handle OUTPUT,
[, [@scrollopt =] scroll_options OUTPUT]
[, [@ccopt =] concurrency_options OUTPUT]
[, [@rowcount =] rowcount OUTPUT]
{, [@param1 =] value1 [,...n]
}
0 (success) or 1 (failure).
Returns the result set generated by the prepared statement handle, but containing no rows.
Execute permissions default to the public role.
Used to free a prepared cursor statement.
sp_cursorunprepare [@handle =] statement_handle
0 (success) or 1 (failure).
None.
Execute permissions default to the public role.
Used to prepare a parameterized SQL statement.
sp_prepare [@handle =] statement_handle OUTPUT,
[@paramdef =] N'parameter_name data_type
[,...n]',
[@stmt =] N'stmt',
[@flag =] flag,
Is a string containing a single SELECT statement or a single stored procedure call. The size of the string is limited only by available database server memory. stmt can contain parameters having the same form as a variable name, for example:
'SELECT * FROM Employees WHERE EmployeeID = @IDParameter'
Each parameter included in stmt must have a corresponding entry in both the @paramdef parameter definition list.
0 (success) or 1 (failure).
None.
Execute permissions default to the public role.
Used to execute a prepared SQL statement.
sp_execute [@handle =] statement_handle
{, [@param1 =] value1 [,...n]
}
0 (success) or 1 (failure).
Returns a result set if specified by the prepared statement.
Execute permissions default to the public role.
Used to free a prepared SQL statement.
sp_unprepare [@handle =] statement_handle
0 (success) or 1 (failure).
None.
Execute permissions default to the public role.
Used to prepare and execute a parameterized SQL statement. This command combines the functions of the sp_prepare and sp_execute procedures and is available from SQL2000 onwards.
sp_prepexec [@handle =] statement_handle OUTPUT,
[@paramdef =] N'parameter_name data_type,
[,...n]'
[@stmt =] N'stmt',
{, [@param1 =] value1 [,...n]
}
Is a string containing a valid SQL statement. The size of the string is limited only by available database server memory. stmt can contain parameters having the same form as a variable name, for example:
'SELECT * FROM Employees WHERE EmployeeID = @IDParameter'
Each parameter included in stmt must have a corresponding entry in both the @paramdef parameter definition list.
0 (success) or 1 (failure).
Returns a result set if specified by the prepared statement.
Execute permissions default to the public role.