SQLColumns
Version Introduced: ODBC 1.0
Summary
SQLColumns returns the list of column names in specified tables. The driver returns this
information as a result set on the specified StatementHandle.
Syntax
SQLRETURN SQLColumns(
Arguments
StatementHandle [Input]
CatalogName[Input]
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]
SchemaName [Input]
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 a pattern value argument; it is treated literally, and its case is
significant.
NameLength2 [Input]
TableName [Input]
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 a pattern value argument; it is treated literally, and its case is
significant.
NameLength3 [Input]
ColumnName [Input]
If the SQL_ATTR_METADATA_ID statement attribute is set to SQL_TRUE, ColumnName is treated as an identifier, and its case is not significant. If it is
SQL_FALSE, ColumnName is a pattern value argument; it is treated literally, and its case is
significant.
NameLength4 [Input]
Returns
SQL_SUCCESS, SQL_SUCCESS_WITH_INFO, SQL_STILL_EXECUTING, SQL_ERROR, or
SQL_INVALID_HANDLE.
Diagnostics
When SQLColumns 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 SQLColumns 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.
Standards Compliance: X/Open
SQLHSTMT StatementHandle,
SQLCHAR * CatalogName,
SQLSMALLINT NameLength1,
SQLCHAR * SchemaName,
SQLSMALLINT NameLength2,
SQLCHAR * TableName,
SQLSMALLINT NameLength3,
SQLCHAR * ColumnName,
SQLSMALLINT NameLength4);
Statement handle.
Catalog name. 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.
Length of *CatalogName.
String search pattern for schema names. 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.
Length of *SchemaName.
String search pattern for table names.
Length of *TableName.
String search pattern for column names.
Length of *ColumnName.
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
| (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, TableName, or ColumnName 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 name length arguments was less than 0, but not
equal to SQL_NTS.
|
|
| The value of one of the name length arguments exceeded the maximum length
value for the corresponding catalog or name. The maximum length of each catalog or
name may be obtained by calling SQLGetInfo with the InfoType values (see “Comments”).
|
HYC00
| Optional feature not implemented
| A catalog name was specified and the driver or data source does not support
catalogs.
A schema name was specified and the driver or data source does not support schemas. |
|
| A string search pattern was specified for the schema name, table name, or
column name and the data source does not support search patterns for one or more of
those arguments.
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 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.
|
This function is typically used before statement execution to retrieve information about columns for a table or tables from the data source’s catalog. SQLColumns can be used to retrieve data for all types of items returned by SQLTables. In addition to base tables, this may include (but is not limited to) views, synonyms, system tables, and so on. Note by contrast, that the functions SQLColAttribute and SQLDescribeCol describe the columns in a result set and that the function SQLNumResultCols returns the number of columns in a result set. 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.”
SQLColumns returns the results as a standard result set, ordered by TABLE_CAT, TABLE_SCHEM, TABLE_NAME, and ORDINAL_POSITION.
Note When an application works with an ODBC 2.x driver, no ORDINAL_POSITION column is returned in the result set. As a result, when working with ODBC 2.x drivers, the order of the columns in the column list returned by SQLColumns is not necessarily the same as the order of the columns returned when the application performs a SELECT statement on all columns in that table.
Note SQLColumns might not return all columns. For example, a driver might not return information about pseudo-columns, such as Oracle ROWID. Applications can use any valid column, regardless of whether it is returned by SQLColumns.
Some columns that can be returned by SQLStatistics are not returned by SQLColumns. For example, SQLColumns does not return the columns in an index created over an expression or filter, such as SALARY + BENEFITS or DEPT = 0012.
The lengths of VARCHAR columns are not shown in the table; the actual lengths depend on the data source. To determine the actual lengths of the TABLE_CAT, TABLE_SCHEM, TABLE_NAME, and COLUMN_NAME columns, an application can call SQLGetInfo with the SQL_MAX_CATALOG_NAME_LEN, SQL_MAX_SCHEMA_NAME_LEN, SQL_MAX_TABLE_NAME_LEN, and SQL_MAX_COLUMN_NAME_LEN options.
The following columns have been renamed for ODBC 3.0. The column name changes do not affect backward compatibility because applications bind by column number.
ODBC 2.0 column
| ODBC 3.0 column
|
TABLE_QUALIFIER | TABLE_CAT
|
TABLE_OWNER
| TABLE_SCHEM
|
PRECISION
| COLUMN_SIZE
|
LENGTH
| BUFFER_LENGTH
|
SCALE
| DECIMAL_DIGITS
|
RADIX
| NUM_PREC_RADIX
|
CHAR_OCTET_LENGTH
| ORDINAL_POSITION
|
COLUMN_DEF
| SQL_DATA_TYPE
|
IS_NULLABLE
| SQL_DATETIME_SUB
|
Column name
| Column number
| Data type
| Comments
|
TABLE_CAT (ODBC 1.0) | 1
| Varchar
| Catalog name; NULL if not applicable to the data source. If a driver supports
catalogs for some tables but not for others, such as when the driver retrieves
data from different DBMSs, it returns an empty string ("") for those tables
that do not have catalogs.
|
TABLE_SCHEM
(ODBC 1.0) | 2
| Varchar
| Schema name; NULL if not applicable to the data source. If a driver supports
schemas for some tables but not for others, such as when the driver retrieves
data from different DBMSs, it returns an empty string ("") for those tables that
do not have schemas.
|
TABLE_NAME
(ODBC 1.0) | 3
| Varchar not NULL
| Table name.
|
COLUMN_NAME
(ODBC 1.0) | 4
| 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) | 5
| Smallint not NULL
| SQL data type. This can be an ODBC SQL data type or a driver-specific SQL data
type. For datetime and interval data types, this column returns the concise
data type (such as SQL_TYPE_DATE or SQL_INTERVAL_YEAR_TO_MONTH, rather than the
non-concise data type such as SQL_DATETIME or SQL_INTERVAL). 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.
The data types returned for ODBC 3.0 and ODBC 2.x applications may be different. For more information, see “Backward Compatibility and Standards Compliance” in Chapter 17, “Programming Considerations.” |
TYPE_NAME
(ODBC 1.0) | 6
| Varchar not NULL
| Data source–dependent data type name; for example, “CHAR”, “VARCHAR”, “MONEY”,
“LONG VARBINAR”, or “CHAR ( ) FOR BIT DATA”.
|
COLUMN_SIZE
(ODBC 1.0) | 7
| Integer
| If DATA_TYPE is SQL_CHAR or SQL_VARCHAR, then this column contains the maximum
length in characters of the column. For datetime data types, this is the total
number of characters required to display the value when converted to
characters. For numeric data types, this is either the total number of digits or the
total number of bits allowed in the column, according to the NUM_PREC_RADIX
column. For interval data types, this is the number of characters in the character
representation of the interval literal (as defined by the interval leading
precision, see “Interval Data Type Length” in Appendix D, “Data Types”). For more information, see “ Column Size, Decimal Digits, Transfer Octet Length, and Display Size” in Appendix D, “Data Types.”
|
BUFFER_LENGTH
(ODBC 1.0) | 8
| Integer
| The length in bytes of data transferred on an SQLGetData, SQLFetch, or SQLFetchScroll 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 about length, see “Column Size, Decimal Digits, Transfer Octet Length, and Display Size” in Appendix D, “Data Types.”
|
DECIMAL_DIGITS
(ODBC 1.0) | 9
| Smallint
| The total number of significant digits to the right of the decimal point. For
SQL_TYPE_TIME and SQL_TYPE_TIMESTAMP, this column contains the number of digits
in the fractional seconds component. For the other data types this is the
decimal digitsof the column on the data source. For interval data types that
contain a time component, this column contains the number of digits to the right of
the decimal point (fractional seconds). For interval data types that do not
contain a time component, this column is 0. For more information on decimal digits,
see “Column Size, Decimal Digits, Transfer Octet Length, and Display Size” in Appendix D, “Data Types.” NULL is returned for data types where decimal
digits is not applicable.
|
NUM_PREC_RADIX
(ODBC 1.0) | 10
| Smallint
| For numeric data types, either 10 or 2. If it is 10, the values in COLUMN_SIZE
and DECIMAL_DIGITS give the number of decimal digits allowed for the column.
For example, a DECIMAL(12,5) column would return a NUM_PREC_RADIX of 10, a
COLUMN_SIZE of 12, and a DECIMAL_DIGITS of 5; A FLOAT column could return a
NUM_PREC_RADIX of 10, a COLUMN_SIZE of 15 and a DECIMAL_DIGITS of NULL.
If it is 2, the values in COLUMN_SIZE and DECIMAL_DIGITS give the number of bits allowed in the column. For example, a FLOAT column could return a RADIX of 2, a COLUMN_SIZE of 53, and a DECIMAL_DIGITS of NULL. NULL is returned for data types where NUM_PREC_RADIX is not applicable. |
NULLABLE
(ODBC 1.0) | 11
| Smallint not NULL
| SQL_NO_NULLS if the column could not include NULL values.
SQL_NULLABLE if the column accepts NULL values. SQL_NULLABLE_UNKNOWN if it is not known whether the column accepts NULL values. The value returned for this column is different than the value returned for the IS_NULLABLE column. The NULLABLE column indicates with certainty that a column can accept NULLs, but cannot indicate with certainty that a column does not accept NULLs. The IS_NULLABLE column indicates with certainty that a column cannot accept NULLs, but cannot indicate with certainty that a column accepts NULLs. |
REMARKS
(ODBC 1.0) | 12
| Varchar
| A description of the column.
|
COLUMN_DEF
(ODBC 3.0) | 13
| Varchar
| The default value of the column. The value in this column should be
interpreted as a string if it is enclosed in quotation marks.
If NULL was specified as the default value, then this column is the word NULL, not enclosed in quotation marks. If the default value cannot be represented without truncation, then this column contains TRUNCATED, with no enclosing single quotation marks. If no default value was specified, then this column is NULL. The value of COLUMN_DEF can be used in generating a new column definition, except when it contains the value TRUNCATED. |
SQL_DATA_TYPE
(ODBC 3.0) | 14
| Smallint not NULL
| SQL data type, as it appears in the SQL_DESC_TYPE record field in the IRD.
This can be an ODBC SQL data type or a driver-specific SQL data type. This column
is the same as the DATA_TYPE column, with the exception of datetime and
interval data types. This column returns the non-concise data type (such as
SQL_DATETIME or SQL_INTERVAL), rather than the concise data type (such as SQL_TYPE_DATE
or SQL_INTERVAL_YEAR_TO_
MONTH) for datetime and interval data types. If this column returns SQL_DATETIME or SQL_INTERVAL, the specific data type can be determined from the SQL_DATETIME_SUB column. 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. The data types returned for ODBC 3.0 and ODBC 2.x applications may be different. For more information, see “Backward Compatibility and Standards Compliance” in Chapter 17, “Programming Considerations.” |
SQL_DATETIME_
SUB (ODBC 3.0) | 15
| Smallint
| The subtype code for datetime and interval data types. For other data types,
this column returns a NULL. For more information about datetime and interval
subcodes, see “SQL_DESC_DATETIME_
INTERVAL_CODE” in SQLSetDescField. |
CHAR_OCTET_
LENGTH (ODBC 3.0) | 16
| Integer
| The maximum length in bytes of a character or binary data type column. For all
other data types, this column returns a NULL.
|
ORDINAL_
POSITION (ODBC 3.0) | 17
| Integer not NULL
| The ordinal position of the column in the table. The first column in the table
is number 1.
|
IS_NULLABLE
(ODBC 3.0) | 18
| Varchar
| “NO” if the column does not include NULLs.
“YES” if the column could include NULLs. This column returns a zero-length string if nullability is unknown. ISO rules are followed to determine nullability. An ISO SQL-compliant DBMS cannot return an empty string. The value returned for this column is different than the value returned for the NULLABLE column. (See the description of the NULLABLE column.) |
In the following example, an application declares buffers for the result set returned by SQLColumns. It calls SQLColumns to return a result set that describes each column in the EMPLOYEE table. It then calls SQLBindCol to bind the columns in the result set to the buffers. Finally, the application fetches each row of data with SQLFetch and processes it.
#define STR_LEN 128+1
#define REM_LEN 254+1
/* Declare buffers for result set data */
SQLCHAR szCatalog[STR_LEN], szSchema[STR_LEN];
SQLCHAR szTableName[STR_LEN], szColumnName[STR_LEN];
SQLCHAR szTypeName[STR_LEN], szRemarks[REM_LEN];
SQLCHAR szColumnDefault[STR_LEN], szIsNullable[STR_LEN];
SQLINTEGER ColumnSize, BufferLength, CharOctetLength, OrdinalPosition;
SQLSMALLINT DataType, DecimalDigits, NumPrecRadix, Nullable;
SQLSMALLINT SQLDataType, DatetimeSubtypeCode;
SQLRETURN retcode;
SQLHSTMT hstmt;
/* Declare buffers for bytes available to return */
SQLINTEGER cbCatalog, cbSchema, cbTableName, cbColumnName;
SQLINTEGER cbDataType, cbTypeName, cbColumnSize, cbBufferLength;
SQLINTEGER cbDecimalDigits, cbNumPrecRadix, cbNullable, cbRemarks;
SQLINTEGER cbColumnDefault, cbSQLDataType, cbDatetimeSubtypeCode, cbCharOctetLength;
SQLINTEGER cbOrdinalPosition, cbIsNullable;
retcode = SQLColumns(hstmt,
NULL, 0, /* All catalogs */
NULL, 0, /* All schemas */
"CUSTOMERS", SQL_NTS, /* CUSTOMERS table */
NULL, 0); /* All columns */
if (retcode == SQL_SUCCESS || retcode == SQL_SUCCESS_WITH_INFO) {
/* Bind columns in result set to buffers */
SQLBindCol(hstmt, 1, SQL_C_CHAR, szCatalog, STR_LEN,&cbCatalog);
SQLBindCol(hstmt, 2, SQL_C_CHAR, szSchema, STR_LEN, &cbSchema);
SQLBindCol(hstmt, 3, SQL_C_CHAR, szTableName, STR_LEN,&cbTableName);
SQLBindCol(hstmt, 4, SQL_C_CHAR, szColumnName, STR_LEN, &cbColumnName);
SQLBindCol(hstmt, 5, SQL_C_SSHORT, &DataType, 0, &cbDataType);
SQLBindCol(hstmt, 6, SQL_C_CHAR, szTypeName, STR_LEN, &cbTypeName);
SQLBindCol(hstmt, 7, SQL_C_SLONG, &ColumnSize, 0, &cbColumnSize);
SQLBindCol(hstmt, 8, SQL_C_SLONG, &BufferLength, 0, &cbBufferLength);
SQLBindCol(hstmt, 9, SQL_C_SSHORT, &DecimalDigits, 0, &cbDecimalDigits);
SQLBindCol(hstmt, 10, SQL_C_SSHORT, &NumPrecRadix, 0, &cbNumPrecRadix);
SQLBindCol(hstmt, 11, SQL_C_SSHORT, &Nullable, 0, &cbNullable);
SQLBindCol(hstmt, 12, SQL_C_CHAR, szRemarks, REM_LEN, &cbRemarks);
SQLBindCol(hstmt, 13, SQL_C_CHAR, szColumnDefault, STR_LEN, &cbColumnDefault);
SQLBindCol(hstmt, 14, SQL_C_SSHORT, &SQLDataType, 0, &cbSQLDataType);
SQLBindCol(hstmt, 15, SQL_C_SSHORT, &DatetimeSubtypeCode, 0,
&cbDatetimeSubtypeCode);
SQLBindCol(hstmt, 16, SQL_C_SLONG, &CharOctetLength, 0, &cbCharOctetLength);
SQLBindCol(hstmt, 17, SQL_C_SLONG, &OrdinalPosition, 0, &cbOrdinalPosition);
SQLBindCol(hstmt, 18, SQL_C_CHAR, szIsNullable, STR_LEN, &cbIsNullable);
while(TRUE) {
retcode = SQLFetch(hstmt);
if (retcode == SQL_ERROR || retcode == SQL_SUCCESS_WITH_INFO) {
show_error( );
}
if (retcode == SQL_SUCCESS || retcode == SQL_SUCCESS_WITH_INFO){
...; /* Process fetched data */
} else {
break;
}
}
}
Related Functions
For information about
| See
|
Binding a buffer to a column in a result set | SQLBindCol
|
Canceling statement processing
| SQLCancel
|
Returning privileges for a column or columns
| SQLColumnPrivileges
|
Fetching a block of data or scrolling through a result set
| SQLFetchScroll
|
Fetching multiple rows of data
| SQLFetch
|
Returning columns that uniquely identify a row, or columns automatically
updated by a transaction
| SQLSpecialColumns
|
Returning table statistics and indexes
| SQLStatistics
|
Returning a list of tables in a data source
| SQLTables
|
Returning privileges for a table or tables
| SQLTablePrivileges
|