Setting the system time for a session
Setting the system time with the CURRENT TEMPORAL SYSTEM_TIME special register can reduce or eliminate the changes required when running an application against different points in time.
About this task
Setting the CURRENT TEMPORAL SYSTEM_TIME special register does not affect regular tables. Only queries on temporal tables with versioning enabled (system-period temporal tables and bitemporal tables) use the time set in the special register. There is also no affect on DDL statements. The special register does not apply to any scans run for referential integrity processing. .
The BIND command contains the SYSTIMESENSITIVE option and is set to YES by default. The SYSTIMESENSITIVE option indicates whether references to system-period temporal tables in static and dynamic SQL statements are affected by the value of the CURRENT TEMPORAL SYSTEM_TIME special register. For more information about the type of objects that CURRENT TEMPORAL SYSTEM_TIME also affects, see CURRENT TEMPORAL SYSTEM_TIME special register. If queries in the application are meant to access only the current version of data, set SYSTIMESENSITIVE to NO to optimize the static queries. For SQL procedures, use the SET_ROUTINE_OPTS procedure to set the bind-like options, called query compiler variables.
Procedure
When this special register is set to a non-null value, applications that issue a query will return data as of that date or timestamp. The following examples request information from the result tables in the Deleting data from a system-period temporal table topic.
Results
policy_info
table and its associated
history table are as follows:
policy_id | coverage | sys_start | sys_end | ts_id |
---|---|---|---|---|
A123 | 12000 | 2010-01-31-22.31.33.495925000000 | 9999-12-30-00.00.00.000000000000 | 2010-01-31-22.31.33.495925000000 |
C567 | 25000 | 2011-02-28-09.10.12.649592000000 | 9999-12-30-00.00.00.000000000000 | 2011-02-28-09.10.12.649592000000 |
policy_id | coverage | sys_start | sys_end | ts_id |
---|---|---|---|---|
C567 | 20000 | 2010-01-31-22.31.33.495925000000 | 2011-02-28-09.10.12.649592000000 | 2010-01-31-22.31.33.495925000000 |
B345 | 18000 | 2010-01-31-22.31.33.495925000000 | 2011-09-01-12.18.22.959254000000 | 2010-01-31-22.31.33.495925000000 |
- The request for data from one year ago queries the
policy_info
table as of 2010-05-17-14.45.31.434235000000. The query is implicitly rewritten to:
The SELECT queries both theSELECT policy_id, coverage FROM policy_info FOR SYSTEM_TIME AS OF TIMESTAMP '2010-05-17-14.45.31.434235000000';
policy_info
and thehist_policy_info
tables and returns:A123, 12000 C567, 20000 B345, 18000
- The query on
view1
is implicitly rewritten to:
The query is then rewritten to:SELECT * FROM view1 FOR SYSTEM_TIME AS OF CURRENT TEMPORAL SYSTEM_TIME;
The SELECT queries both theSELECT policy_id, coverage FROM policy_info FOR SYSTEM_TIME AS OF TIMESTAMP '2011-02-28-09.10.12.649592000000';
policy_info
and thehist_policy_info
tables and returns:
The query onA123, 12000 C567, 25000 B345, 18000
view2
involves a view on a regular table that references a system-period temporal table, causing an implicit relationship between a regular table and the special register. The query is implicitly rewritten to:
The query is then rewritten to:SELECT * FROM view2 FOR SYSTEM_TIME AS OF CURRENT TEMPORAL SYSTEM_TIME;
The SELECT returns rows whereSELECT * FROM regular_table WHERE col1 in (SELECT coverage FROM policy_info FOR SYSTEM_TIME AS OF TIMESTAMP '2011-02-28-09.10.12.649592000000');
col1
values match values incoverage
. - An error is returned because there are multiple time period specifications. The special register was set to a non-null value and the query also specified a time.