Names in the Catalog: In general, all names stored in columns of a catalog table are undelimited and case sensitive. For example, assume the following table was created:
CREATE TABLE "colname"/"long_table_name" ("long_column_name" CHAR(10), INTCOL INTEGER)
If the following select statement is used to return information about the mapping between SQL names and system names, the following select statement could be used:
SELECT TABLE_NAME, SYSTEM_TABLE_NAME, COLUMN_NAME, SYSTEM_COLUMN_NAME FROM QSYS2/SYSCOLUMNS WHERE TABLE_NAME = 'long_table_name' AND TABLE_SCHEMA = 'colname'
The following rows would be returned:
TABLE_NAME | SYSTEM_TABLE_NAME | COLUMN_NAME | SYSTEM_COLUMN_NAME |
---|---|---|---|
long_table_name | "long0001" | long_column_name | LONG_00001 |
long_table_name | "long0001" | INTCOL | INTCOL |
System Names in the Catalog: In general, the longer SQL column names should be used rather than the short system column names. The short system column names for iSeries™ catalog tables and views are explicitly maintained for compatibility with prior releases and other DB2® UDB products. The short system column names for the ODBC and JDBC catalog views and the ANS and ISO catalog views are not explicitly maintained and may change between releases.
Null Values in the Catalog: If the information in a column is not applicable, the null value is returned. Using the table created above, the following select statement, which queries the NUMERIC_SCALE and the CHARACTER_MAXIMUM_LENGTH, would return the null value when the data was not applicable to the data type of the column.
SELECT COLUMN_NAME, NUMERIC_SCALE, CHARACTER_MAXIMUM_LENGTH FROM QSYS2/SYSCOLUMNS WHERE TABLE_NAME = 'long_table_name' AND TABLE_SCHEMA = 'colname'
The following rows would be returned:
COLUMN_NAME | NUMERIC_SCALE | CHARACTER_MAXIMUM_LENGTH |
---|---|---|
long_column_name | ? | 10 |
INTCOL | 0 | ? |
Because numeric scale is not valid for a character column, the null value is returned for NUMERIC_SCALE for the "long_column_name" column. Because character length is not valid for a numeric column, the null value is returned for CHARACTER_MAXIMUM_LENGTH for the INTCOL column.
Install and Backup Considerations: Certain catalog tables and any views created over the catalog tables and views should be regularly saved:
Granting Privileges to Catalog Views: Tables and views in the catalog are like any other database tables and views. If you have authorization, you can use SQL statements to look at data in the catalog views in the same way that you retrieve data from any other table. The tables and views in the catalogs are shipped with the SELECT privilege to PUBLIC. This privilege may be revoked and the SELECT privilege granted to individual users.
QSYS Catalog Tables: Most of the catalog views are based on the following tables in the QSYS library (sometimes called the database cross reference files). These tables are not shipped with the SELECT privilege to PUBLIC and should not be used directly:
QADBCCST | QADBKFLD | QADBXSFLD |
QADBFDEP | QADBPKG | QADBXTRIGB |
QADBFCST | QADBXRDBD | QADBXTRIGC |
QADBIFLD | QADBXREF | QADBXTRIGD |
Use of SELECT *: New columns are likely to be added to tables and views in the catalog as new functionality is implemented and as the ISO/ANSI standards evolve. For this reason, it is recommended that SELECT * not be used when accessing catalog tables and views unless your application is prepared to tolerate these new columns.