DBC.COLUMNS view is a table containing information about table and view columns, stored procedures, or macro parameters. The view includes the following column names: DatabaseName, TableName, ColumnName, ColumnFormat, ColumnTitle, ColumnType, and DefaultValue. In GaussDB(DWS), this table is equivalent to the information_schema.columns table.
This feature requires one time execution of the custom script file DSC/scripts/teradata/db_scripts/mig_fn_get_datatype_short_name.sql.
For more information about the steps to execute the file, refer to Operating Environment and Prerequisites respectively.
The DSC migrates the following dbc.columns to their corresponding information_schema columns.
dbc.columns |
information_schema.columns |
---|---|
ColumnName |
Column_Name |
ColumnType |
mig_fn_get_datatype_short_name (data_Type) |
ColumnLength |
character_maximum_length |
DecimalTotalDigits |
numeric_precision |
DecimalFractionalDigits |
numeric_scale |
databasename |
table_schema |
tablename |
table_name |
ColumnId |
ordinal_position |
The following assumptions are made when migrating dbc.columns:
Migration of dbc.columns is not supported for the following cases:
Example:
1 2 3 4 5 6 | SEL columnid ,DecimalFractionalDigits FROM dbc.columns ; |
Output:
1 2 3 4 5 6 | SELECT ordinal_position columnid ,numeric_scale DecimalFractionalDigits FROM information_schema.columns ; |
1 2 3 4 5 6 | SELECT TableName FROM dbc . columns WHERE dbc.columns.databasename = '"Test"'; |
Input: dbc.columns table with all supported columns
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 | SELECT '$AUTO_DB_IP' ,objectdatabasename ,objecttablename ,'$TX_DATE_10' ,'' ,'0' ,FirstStepTime ,FirstRespTime ,RowCount ,cast(RowCount*sum(case when T2.ColumnType ='CV' then T2.ColumnLength/3 else T2.ColumnLength end) as decimal(38,0)) ,'3' ,'' ,'BAK_CLR_DATA' ,'2' ,'' FROM TMP_clr_information T1 inner join dbc.columns T2 on T1.objectdatabasename =T2.DatabaseName and T1.objecttablename =T2.TableName where T2.DatabaseName not in ( sel child from dbc.children where parent='$FCRM_DB' ) group by 1,2,3,4,5,6,7,8,9,11,12,13,14,15; |
Output
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 | SELECT '$AUTO_DB_IP' ,objectdatabasename ,objecttablename ,'$TX_DATE_10' ,'' ,'0' ,FirstStepTime ,FirstRespTime ,RowCount ,CAST( RowCount * SUM ( CASE WHEN mig_fn_get_datatype_short_name ( T2.data_Type ) = 'CV' THEN T2.character_maximum_length / 3 ELSE T2.character_maximum_length END ) AS DECIMAL( 38 ,0 ) ) ,'3' ,'' ,'BAK_CLR_DATA' ,'2' ,'' FROM TMP_clr_information T1 INNER JOIN information_schema.columns T2 ON T1.objectdatabasename = T2.table_schema AND T1.objecttablename = T2.table_name WHERE NOT EXISTS ( SELECT child FROM dbc.children WHERE child = T2.table_schema AND( parent = '$FCRM_DB' ) ) GROUP BY 1 ,2 ,3 ,4 ,5 ,6 ,7 ,8 ,9 ,11 ,12 ,13 ,14 ,15 ; |
Input: dbc.columns table with TABLE NAME
1 2 3 4 5 6 7 8 9 10 | SELECT TRIM( ColumnName ) ,UPPER( dbc.columns.ColumnType ) FROM dbc . columns WHERE dbc.columns.databasename = '"Test"' ORDER BY dbc.columns.ColumnId ; |
Output
1 2 3 4 5 6 7 8 9 10 11 12 13 14 | SELECT TRIM( Column_Name ) ,UPPER( mig_fn_get_datatype_short_name ( information_schema.columns.data_Type ) ) FROM information_schema.columns WHERE information_schema.columns.table_schema = CASE WHEN TRIM( '"Test"' ) LIKE '"%' THEN REPLACE( SUBSTR( '"Test"' ,2 ,LENGTH( '"Test"' ) - 2 ) ,'""' ,'"' ) ELSE LOWER( '"Test"' ) END ORDER BY information_schema.columns.ordinal_position ; |