SQLSpecialColumns

Conformance

Version Introduced:ODBC 1.0
Standards Compliance:X/Open

Summary

SQLSpecialColumns retrieves the following information about columns within a specified table:

Syntax

SQLRETURN SQLSpecialColumns(
SQLHSTMTStatementHandle,
SQLSMALLINTIdentifierType,
SQLCHAR *CatalogName,
SQLSMALLINTNameLength1,
SQLCHAR *SchemaName,
SQLSMALLINTNameLength2,
SQLCHAR *TableName,
SQLSMALLINTNameLength3,
SQLSMALLINTScope,
SQLSMALLINTNullable);

Arguments

StatementHandle

[Input]
Statement handle.

IdentifierType

[Input]
Type of column to return. Must be one of the following values:

SQL_BEST_ROWID: Returns the optimal column or set of columns that, by retrieving values from the column or columns, allows any row in the specified table to be uniquely identified. A column can be either a pseudo-column specifically designed for this purpose (as in Oracle ROWID or Ingres TID) or the column or columns of any unique index for the table.

SQL_ROWVER: Returns the column or columns in the specified table, if any, that are automatically updated by the data source when any value in the row is updated by any transaction (as in SQLBase ROWID or Sybase TIMESTAMP).

CatalogName

[Input]
Catalog name for the table. If a driver supports catalogs for some tables but not for others, such as when the driver retrieves data from different DBMSs, an empty string ("") denotes those tables that do not have catalogs. CatalogName cannot contain a string search pattern.

If the SQL_ATTR_METADATA_ID statement attribute is set to SQL_TRUE, CatalogName is treated as an identifier, and its case is not significant. If it is SQL_FALSE, CatalogName is an ordinary argument; it is treated literally, and its case is significant. For more information, see “Arguments in Catalog Functions” in Chapter 7, “Catalog Functions.”

NameLength1

[Input]
Length of *CatalogName.

SchemaName

[Input]
Schema name for the table. If a driver supports schemas for some tables but not for others, such as when the driver retrieves data from different DBMSs, an empty string ("") denotes those tables that do not have schemas. SchemaName cannot contain a string search pattern.

If the SQL_ATTR_METADATA_ID statement attribute is set to SQL_TRUE, SchemaName is treated as an identifier, and its case is not significant. If it is SQL_FALSE, SchemaName is an ordinary argument; it is treated literally, and its case is significant.

NameLength2

[Input]
Length of *SchemaName.

TableName

[Input]
Table name. This argument cannot be a null pointer. TableName cannot contain a string search pattern.

If the SQL_ATTR_METADATA_ID statement attribute is set to SQL_TRUE, TableName is treated as an identifier, and its case is not significant. If it is SQL_FALSE, TableName is an ordinary argument; it is treated literally, and its case is significant.

NameLength3

[Input]
Length of *TableName.

Scope

[Input]
Minimum required scope of the rowid. The returned rowid may be of greater scope. Must be one of the following:

SQL_SCOPE_CURROW: The rowid is guaranteed to be valid only while positioned on that row. A later reselect using rowid may not return a row if the row was updated or deleted by another transaction.

SQL_SCOPE_TRANSACTION: The rowid is guaranteed to be valid for the duration of the current transaction.

SQL_SCOPE_SESSION: The rowid is guaranteed to be valid for the duration of the session (across transaction boundaries).

Nullable

[Input]
Determines whether to return special columns that can have a NULL value. Must be one of the following:

SQL_NO_NULLS: Exclude special columns that can have NULL values.  Note that some drivers cannot support SQL_NO_NULLS, and that these drivers will return an empty result set if SQL_NO_NULLS was specified. Applications should be prepared for this case, and request SQL_NO_NULLS only if it is absolutely required.

SQL_NULLABLE: Return special columns even if they can have NULL values.

Returns

SQL_SUCCESS, SQL_SUCCESS_WITH_INFO, SQL_STILL_EXECUTING, SQL_ERROR, or SQL_INVALID_HANDLE.

Diagnostics

When SQLSpecialColumns returns SQL_ERROR or SQL_SUCCESS_WITH_INFO, an associated SQLSTATE value may be obtained by calling SQLGetDiagRec with a HandleType of SQL_HANDLE_STMT and a Handle of StatementHandle. The following table lists the SQLSTATE values commonly returned by SQLSpecialColumns and explains each one in the context of this function; the notation “(DM)” precedes the descriptions of SQLSTATEs returned by the Driver Manager. The return code associated with each SQLSTATE value is SQL_ERROR, unless noted otherwise.

SQLSTATE Error Description
01000 General warning Driver-specific informational message. (Function returns SQL_SUCCESS_WITH_INFO.)
08S01 Communication link failure The communication link between the driver and the data source to which the driver was connected failed before the function completed processing.
24000 Invalid cursor state A cursor was open on the StatementHandle and SQLFetch or SQLFetchScroll had been called. This error is returned by the Driver Manager if SQLFetch or SQLFetchScroll has not returned SQL_NO_DATA, and is returned by the driver if SQLFetch or SQLFetchScroll has returned SQL_NO_DATA.

A cursor was open on the StatementHandle but SQLFetch or SQLFetchScroll had not been called.

40001 Serialization failure The transaction was rolled back due to a resource deadlock with another transaction.
40003 Statement completion unknown The associated connection failed during the execution of this function and the state of the transaction cannot be determined.
HY000 General error An error occurred for which there was no specific SQLSTATE and for which no implementation-specific SQLSTATE was defined. The error message returned by SQLGetDiagRec in the *MessageText buffer describes the error and its cause.
HY001 Memory allocation
error
The driver was unable to allocate memory required to support execution or completion of the function.
HY008 Operation canceled Asynchronous processing was enabled for the StatementHandle. The function was called and, before it completed execution, SQLCancel was called on the StatementHandle. Then the function was called again on the StatementHandle.

The function was called and, before it completed execution, SQLCancel was called on the StatementHandle from a different thread in a multithread application.

HY009 Invalid use of null pointer The TableName argument was a null pointer.

(DM) The SQL_ATTR_METADATA_ID statement attribute was set to SQL_TRUE, the CatalogName argument was a null pointer, and the SQL_CATALOG_NAME InfoType returns that catalog names are supported.

(DM) The SQL_ATTR_METADATA_ID statement attribute was set to SQL_TRUE, and the SchemaName argument was a null pointer.

HY010 Function sequence error (DM) An asynchronously executing function (not this one) was called for the StatementHandle and was still executing when this function was called.

(DM) SQLExecute, SQLExecDirect, SQLBulkOperations, or SQLSetPos was called for the StatementHandle and returned SQL_NEED_DATA. This function was called before data was sent for all data-at-execution parameters or columns.

HY013 Memory management error The function call could not be processed because the underlying memory objects could not be accessed, possibly because of low memory conditions.
HY090 Invalid string or buffer length (DM) The value of one of the length arguments was less than 0, but not equal to SQL_NTS.
The value of one of the length arguments exceeded the maximum length value for the corresponding name. The maximum length of each name may be obtained by calling SQLGetInfo with the InfoType values: SQL_MAX_CATALOG_NAME_LEN, SQL_MAX_SCHEMA_NAME_LEN, or SQL_MAX_TABLE_NAME_LEN.
HY097 Column type out of range (DM) An invalid IdentifierType value was specified.
HY098 Scope type out of range (DM) An invalid Scope value was specified.
HY099 Nullable type out of range (DM) An invalid Nullable value was specified.
HYC00 Optional feature not implemented A catalog was specified and the driver or data source does not support catalogs.

A schema was specified and the driver or data source does not support schemas.

The combination of the current settings of the SQL_ATTR_CONCURRENCY and SQL_ATTR_CURSOR_TYPE statement attributes was not supported by the driver or data source.

The SQL_ATTR_USE_BOOKMARKS statement attribute was set to SQL_UB_VARIABLE, and the SQL_ATTR_CURSOR_TYPE statement attribute was set to a cursor type for which the driver does not support bookmarks.

HYT00 Timeout expired The query timeout period expired before the data source returned the requested result set. The timeout period is set through SQLSetStmtAttr, SQL_ATTR_QUERY_TIMEOUT.
HYT01 Connection timeout expired The connection timeout period expired before the data source responded to the request. The connection timeout period is set through SQLSetConnectAttr, SQL_ATTR_CONNECTION_TIMEOUT.
IM001 Driver does not support this function (DM) The driver associated with the StatementHandle does not support the function.

Comments

When the IdentifierType argument is SQL_BEST_ROWID, SQLSpecialColumns returns the column or columns that uniquely identify each row in the table. These columns can always be used in a select-list or WHERE clause. SQLColumns, which is used to return a variety of information on the columns of a table, does not necessarily return the columns that uniquely identify each row, or columns that are automatically updated when any value in the row is updated by a transaction. For example, SQLColumns might not return the Oracle pseudo-column ROWID. This is why SQLSpecialColumns is used to return these columns. For more information, see “Uses of Catalog Data” in Chapter 7, “Catalog Functions.”

Note For more information about the general use, arguments, and returned data of ODBC catalog functions, see Chapter 7, “Catalog Functions.”

If there are no columns that uniquely identify each row in the table, SQLSpecialColumns returns a rowset with no rows; a subsequent call to SQLFetch or SQLFetchScroll on the statement returns SQL_NO_DATA.

If the IdentifierType, Scope, or Nullable arguments specify characteristics that are not supported by the data source, SQLSpecialColumns returns an empty result set.

If the SQL_ATTR_METADATA_ID statement attribute is set to SQL_TRUE, the CatalogName, SchemaName, and TableName arguments are treated as identifiers, so cannot be set to a null pointer in certain situations. (For more information, see “Arguments in Catalog Functions” in Chapter 7, “Catalog Functions.”)

SQLSpecialColumns returns the results as a standard result set, ordered by SCOPE.

The following columns have been renamed for ODBC 3.x. The column name changes do not affect backward compatibility because applications bind by column number.

ODBC 2.0 column ODBC 3.x column
PRECISION COLUMN_SIZE
LENGTH BUFFER_LENGTH
SCALE DECIMAL_DIGITS

To determine the actual length of the COLUMN_NAME column, an application can call SQLGetInfo with the SQL_MAX_COLUMN_NAME_LEN option.

The following table lists the columns in the result set. Additional columns beyond column 8 (PSEUDO_COLUMN) can be defined by the driver. An application should gain access to driver-specific columns by counting down from the end of the result set rather than specifying an explicit ordinal position. For more information, see “Data Returned by Catalog Functions” in Chapter 7, "Catalog Functions."


Column name
Column number
Data type

Comments
SCOPE
(ODBC 1.0)
1 Smallint

Actual scope of the rowid. Contains one of the following values:

SQL_SCOPE_CURROW
SQL_SCOPE_TRANSACTION
SQL_SCOPE_SESSION

NULL is returned when IdentifierType is SQL_ROWVER. For a description of each value, see the description of Scope in “Syntax” earlier in this section.

COLUMN_NAME
(ODBC 1.0)
2 Varchar
not NULL
Column name. The driver returns an empty string for a column that does not have a name.
DATA_TYPE
(ODBC 1.0)
3 Smallint
not NULL
SQL data type. This can be an ODBC SQL data type or a driver-specific SQL data type. For a list of valid ODBC SQL data types, see “SQL Data Types” in Appendix D, “Data Types.” For information about driver-specific SQL data types, see the driver’s documentation.
TYPE_NAME
(ODBC 1.0)
4 Varchar
not NULL
Data source – dependent data type name; for example, “CHAR”, “VARCHAR”, “MONEY”, “LONG VARBINARY”, or “CHAR ( ) FOR BIT DATA”.
COLUMN_SIZE
(ODBC 1.0)
5 Integer The size of the column on the data source. For more information concerning column size, see “Column Size, Decimal Digits, Transfer Octet Length, and Display Size,” in Appendix D, “Data Types.”
BUFFER_LENGTH
(ODBC 1.0)
6 Integer The length in bytes of data transferred on an SQLGetData or SQLFetch operation if SQL_C_DEFAULT is specified. For numeric data, this size may be different than the size of the data stored on the data source. This value is the same as the COLUMN_SIZE column for character or binary data. For more information, see “Column Size, Decimal Digits, Transfer Octet Length, and Display Size,” in Appendix D, “Data Types.”
DECIMAL_DIGITS
(ODBC 1.0)
7 Smallint The decimal digits of the column on the data source. NULL is returned for data types where decimal digits are not applicable. For more information concerning decimal digits, see “Column Size, Decimal Digits, Transfer Octet Length, and Display Size,” in Appendix D, “Data Types.”
PSEUDO_COLUMN
(ODBC 2.0)
8 Smallint Indicates whether the column is a pseudo-column, such as Oracle ROWID:

SQL_PC_UNKNOWN
SQL_PC_NOT_PSEUDO
SQL_PC_PSEUDO

Note For maximum interoperability, pseudo-columns should not be quoted with the identifier quote character returned by SQLGetInfo.


After the application retrieves values for SQL_BEST_ROWID, the application can use these values to reselect that row within the defined scope. The SELECT statement is guaranteed to return either no rows or one row.

If an application reselects a row based on the rowid column or columns and the row is not found, then the application can assume that the row was deleted or the rowid columns were modified. The opposite is not true: even if the rowid has not changed, the other columns in the row may have changed.

Columns returned for column type SQL_BEST_ROWID are useful for applications that need to scroll forward and back within a result set to retrieve the most recent data from a set of rows. The column or columns of the rowid are guaranteed not to change while positioned on that row.

The column or columns of the rowid may remain valid even when the cursor is not positioned on the row; the application can determine this by checking the SCOPE column in the result set.

Columns returned for column type SQL_ROWVER are useful for applications that need the ability to check whether any columns in a given row have been updated while the row was reselected using the rowid. For example, after reselecting a row using rowid, the application can compare the previous values in the SQL_ROWVER columns to the ones just fetched. If the value in a SQL_ROWVER column differs from the previous value, the application can alert the user that data on the display has changed.

Code Example

For a code example of a similar function, see SQLColumns.

Related Functions

For information about See
Binding a buffer to a column in a result set SQLBindCol
Canceling statement processing SQLCancel
Returning the columns in a table or tables SQLColumns
Fetching a single row or a block of data in a forward-only direction SQLFetch
Fetching a block of data or scrolling through a result set SQLFetchScroll
Returning the columns of a primary key SQLPrimaryKeys