15.00 - Converting Transaction-Time Tables to ANSI System-Versioned System-Time Tables - Teradata Database

Teradata Database Temporal Table Support

prodname
Teradata Database
vrm_release
15.00
category
Programming Reference
featnum
B035-1182-015K

Converting Transaction-Time Tables to ANSI System-Versioned System-Time Tables

Teradata “valid-time” tables qualify as ANSI “application-time” temporal tables, if they are defined using a valid-time derived period column and have no temporal constraints. These tables are ANSI compliant without modifications.

Teradata “transaction-time” tables are analogous to ANSI “system-versioned system-time” temporal tables, but must be converted to system-versioned system-time tables in order to be used with ANSI-compliant temporal SQL. For sites that have implemented transaction-time tables, this appendix provides three methods to convert transaction-time tables to system-time tables. Teradata recommends contacting your Teradata representative for help with this process.

Although Teradata’s original temporal SQL that is used to qualify temporal queries and modifications does operate on Teradata’s ANSI temporal tables, it is not ANSI-compliant SQL.

Note: In order to use ANSI temporal tables on systems that used temporal tables prior to Teradata Database 15.0, the session temporal qualifier must be set to ANSIQUALIFIER. This is normally set appropriately by Teradata personnel. ANSIQUALIFIER changes the SQL behavior with respect to default temporal qualifiers such that unqualified queries and modifications of valid-time tables act as nonsequenced.

You can check the session temporal qualifier setting by looking at the Temporal Qualifier field of the output of the HELP SESSION statement. For more information on HELP SESSION, see SQL Data Definition Language.

For more information on session temporal qualifiers, see “SET SESSION (Session Temporal Qualifiers)” on page 103.

Method 1: Alter Existing Transaction-Time Table

This method:

  • requires that the executor have the NONTEMPORAL privilege in the database, and that the database be enabled to recognize that privilege. For more information on the NONTEMPORAL privilege, see Temporal Table Support.
  • cannot be used if the transaction-time table is row partitioned on the beginning or ending bound of the transaction-time.
  • is not recommended for large, column-partitioned tables because for these tables the update operation in Step 4 can be very resource intensive and time consuming.
  • 1 Note all the constraints on the transaction-time table.

    2 Drop all the constraints from the transaction-time table.

    3 Use NONTEMPORAL ALTER TABLE to add two new columns of type TIMESTAMP(6) WITH TIME ZONE. For the purposes of this procedure, assume the columns are named sys_start and sys_end. These will hold the beginning and ending bound values of the new SYSTEM_TIME derived period column.

    4 Use NONTEMPORAL UPDATE to populate the new columns with the start and end values of the existing transaction-time columns or derived period column.

    5 Use NONTEMPORAL ALTER TABLE to drop the existing transaction-time column. Use the WITHOUT DELETE option to preserve the historical closed rows, which would otherwise be deleted automatically when you drop the transaction-time column:

    ALTER TABLE transaction_time_table_name 
      DROP transaction_time_column WITHOUT DELETE

    6 Use ALTER TABLE to create the SYSTEM_TIME derived period column and to add attributes to the set the sys_start and sys_end columns in the same ALTER TABLE statement:

    ALTER TABLE transaction_time_table_name
     ADD PERIOD FOR SYSTEM_TIME(sys_start,sys_end)
     ADD sys_start TIMESTAMP(6) WITH TIME ZONE NOT NULL
       GENERATED ALWAYS AS ROW START
     add sys_end TIMESTAMP(6) WITH TIME ZONE NOT NULL
       GENERATED ALWAYS AS ROW END;

    7 Add system versioning to make the new table an ANSI system-time temporal table:

    ALTER TABLE transaction_time_table_name 
     ADD SYSTEM VERSIONING;

    8 Recreate all the constraints that were dropped in step 2. Note that ANSI constraints behave as NONSEQUENCED constraints.

    Method 2: INSERT ... SELECT to New Table When Transaction-Time Column is a Derived Period

    This method:

  • requires that the executor have the NONTEMPORAL privilege in the database, and that the database be enabled to recognize that privilege. For more information on the NONTEMPORAL privilege, see Temporal Table Support.
  • cannot be used if the transaction-time table is row partitioned on the beginning or ending bound of the transaction-time.
  • 1 Note all the constraints on the transaction-time table.

    2 Drop all the constraints from the transaction-time table.

    3 Use NONTEMPORAL ALTER TABLE to drop the existing transaction-time column. Use the WITHOUT DELETE option to preserve the historical closed rows, which would otherwise be deleted automatically when you drop the transaction-time column:

    ALTER TABLE transaction_time_table_name 
      DROP transaction_time_column WITHOUT DELETE

    4 Use ALTER TABLE to create the SYSTEM_TIME derived period column and to add attributes to the set the sys_start and sys_end columns in the same ALTER TABLE statement:

    ALTER TABLE new_table_name
     ADD PERIOD FOR SYSTEM_TIME(sys_start,sys_end)
     ADD sys_start TIMESTAMP(6) WITH TIME ZONE NOT NULL
       GENERATED ALWAYS AS ROW START
     add sys_end TIMESTAMP(6) WITH TIME ZONE NOT NULL
       GENERATED ALWAYS AS ROW END;

    5 Add system versioning to make the new table an ANSI system-time temporal table:

    ALTER TABLE new_table_name 
     ADD SYSTEM VERSIONING;

    6 Recreate all the constraints that were dropped in step 2. Note that ANSI constraints behave as NONSEQUENCED constraints.

    Method 3: INSERT ... SELECT to New Table When Transaction-Time Column is a Period Data Type

    This method:

  • does not require the NONTEMPORAL privilege.
  • can be used on transaction-time tables that are row-partitioned on the beginning or ending bound of the transaction-time period.
  • 1 Create a new table with columns that match the non-transaction-time columns of the existing table. Add two new TIMESTAMP(6) WITH TIME ZONE columns that will hold the beginning and ending bound values for the ANSI system-time derived period column. For the purposes of this procedure, assume the columns are named sys_start and sys_end.

    2 Use a NONSEQUENCED INSERT ... SELECT to copy the rows of the transaction-time table into the new table.

    3 Use ALTER TABLE to create the SYSTEM_TIME derived period column and to add attributes to the set the sys_start and sys_end columns in the same ALTER TABLE statement:

    ALTER TABLE new_table_name
     ADD PERIOD FOR SYSTEM_TIME(sys_start,sys_end)
     ADD sys_start TIMESTAMP(6) WITH TIME ZONE NOT NULL
       GENERATED ALWAYS AS ROW START
     add sys_end TIMESTAMP(6) WITH TIME ZONE NOT NULL
       GENERATED ALWAYS AS ROW END;

    4 Note the constraints on the transaction-time table.

    5 Drop the transaction-time table.

    6 Rename the new table as the old table.

    7 Add system versioning to make the new table an ANSI system-time temporal table:

    ALTER TABLE new_table_name 
     ADD SYSTEM VERSIONING;

    8 Recreate all the constraints that were dropped in step 2. Note that ANSI constraints behave as NONSEQUENCED constraints.