Dropping a system-period temporal table
Dropping a system-period temporal table also drops its associated history table and any indexes defined on the history table.
Before you begin
About this task
A history table is implicitly dropped when its associated system-period temporal table is dropped. A history table cannot be explicitly dropped by using the DROP statement.
To avoid losing historical data when a system-period temporal table is dropped, you can either create the history table with the RESTRICT ON DROP attribute or alter the history table by adding the RESTRICT ON DROP attribute. If you try to drop a system-period temporal table and its history table has the RESTRICT ON DROP attribute, the drop of the system-period temporal table fails (SQLSTATE 42893). In such cases, you must break the link between the system-period temporal table and the history table by removing the VERSIONING attribute and then rerun the DROP statement.
When a table is altered to drop VERSIONING, all packages with the versioning dependency on the table are invalidated. Other dependent objects, for example, views or triggers are marked invalid 'N' in the system catalog. Auto-revalidation is done. Any objects failing revalidation are left as invalid in the catalog. Some objects can become valid after only explicit user action.
Procedure
To drop a system-period temporal table and its associated history table:
Results
policy_info
and hist_policy_info
tables
as follows:- The DROP statement explicitly drops the system-period temporal
table and implicitly drops the associated history table. The
policy_info
andhist_policy_info
tables are deleted. Any objects that are directly or indirectly dependent on those tables are either deleted or made inoperative. - After the RESTRICT ON DROP attribute is associated with the history
table, any attempt to drop the
policy_info
table would fail (SQLSTATE 42893). A system-period temporal table can also be created or altered to use the RESTRICT ON DROP attribute. - After the link between the system-period temporal table and its
history table is broken, the
policy_info
table can be dropped and thehist_policy_info
history table would remain.
Dropping table spaces
policy_space
and hist_space
table
spaces, the following statement is blocked:DROP TABLESPACE hist_space;
If
table space that contains a history table and the table space containing
the associated system-period temporal table are included together,
then the statement is allowed. For example, the following statement
would succeed:DROP TABLESPACE policy_space hist_space;
A
history table is implicitly dropped when the table space for its associated
system-period temporal table is dropped. For example, the following
statement would drop the hist_policy_info
history
table:DROP TABLESPACE policy_space;