8i | 9i | 10g | 11g | 12c | 13c | 18c | 19c | 21c | 23c | Misc | PL/SQL | SQL | RAC | WebLogic | Linux
Upgrade the Database Time Zone File Using the DBMS_DST Package
The DBMS_DST
package was introduced to simplify the process of upgrading the database time zone file, as well as the time zone data based on new time zone file.
- The Problem
- Check Current Time Zone Version
- Prepare for the Upgrade
- Upgrade the Time Zone File (non-CDB)
- Upgrade the Time Zone File (Multitenant)
- Getting the Latest Time Zone File
The Problem
Countries occasionally change their time zones, or alter the way they handle daylight saving time (DST). From Oracle 11gR2 onward, new time zone files are shipped with upgrades and patches, but they are not automatically applied to the database.
Applying a change to the database time zone file not only affects the way new data is handled, but potentially alters data stored in TIMESTAMP WITH TIME ZONE
columns, so you need to consider the impact of this before upgrading the time zone file.
Remember, if you only deal with dates in your country, and your country has not altered its time zone or daylight saving time policy, this upgrade may not be necessary.
Check Current Time Zone Version
The V$TIMEZONE_FILE
view displays the zone file version being used by the database.
SELECT * FROM v$timezone_file; FILENAME VERSION CON_ID -------------------- ---------- ---------- timezlrg_26.dat 26 0 SQL>
This can also be queried from the REGISTRY$DATABASE
table.
SELECT tz_version FROM registry$database; TZ_VERSION ---------- 26 SQL>
It can also be queried from the DATABASE_PROPERTIES
view.
COLUMN property_name FORMAT A30 COLUMN property_value FORMAT A20 SELECT property_name, property_value FROM database_properties WHERE property_name LIKE 'DST_%' ORDER BY property_name; PROPERTY_NAME PROPERTY_VALUE ------------------------------ -------------------- DST_PRIMARY_TT_VERSION 26 DST_SECONDARY_TT_VERSION 0 DST_UPGRADE_STATE NONE SQL>
The latest available version of the timezone file is displayed using the GET_LATEST_TIMEZONE_VERSION
function in the DBMS_DST
package.
SELECT DBMS_DST.get_latest_timezone_version FROM dual; GET_LATEST_TIMEZONE_VERSION --------------------------- 31 SQL>
We can see there is a difference between the current and latest version of the time zone file, so we should consider performing an upgrade.
Prepare for the Upgrade
The prepare phase is where you check the impact of a time zone file upgrade, including the tables that will be affected by the upgrade. This phase is optional, but it makes sense to at least check what is going to happen.
Use the BEGIN_PREPARE
procedure, passing in the file version you want to upgrade to. In this case we are selecting the latest version.
DECLARE l_tz_version PLS_INTEGER; BEGIN l_tz_version := DBMS_DST.get_latest_timezone_version; DBMS_OUTPUT.put_line('l_tz_version=' || l_tz_version); DBMS_DST.begin_prepare(l_tz_version); END; /
We can now check the upgrade we are going to attempt. Notice the DST_SECONDARY_TT_VERSION
column is now populated.
COLUMN property_name FORMAT A30 COLUMN property_value FORMAT A20 SELECT property_name, property_value FROM database_properties WHERE property_name LIKE 'DST_%' ORDER BY property_name; PROPERTY_NAME PROPERTY_VALUE ------------------------------ -------------------- DST_PRIMARY_TT_VERSION 26 DST_SECONDARY_TT_VERSION 31 DST_UPGRADE_STATE PREPARE SQL>
Empty the default tables that hold the affected tables list and errors. If you are using custom tables, created with the CREATE_AFFECTED_TABLE
, CREATE_ERROR_TABLE
, CREATE_TRIGGER_TABLE
procedures, then empty those instead.
TRUNCATE TABLE sys.dst$affected_tables; TRUNCATE TABLE sys.dst$error_table;
Find tables affected by the upgrade. Depending on your use of TIMESTAMP WITH TIME ZONE
columns, you might not have any.
EXEC DBMS_DST.find_affected_tables;
Check the results of the call.
SELECT * FROM sys.dst$affected_tables; SELECT * FROM sys.dst$error_table;
When you've identified the affected tables and determined you are happy to continue, you can end the prepare phase.
EXEC DBMS_DST.end_prepare;
Upgrade the Time Zone File (non-CDB)
Individual tables or schemas can be upgraded, but in this example we use UPGRADE_DATABASE
procedure to upgrade all affected tables in the database.
Put the database into upgrade mode.
SHUTDOWN IMMEDIATE; STARTUP UPGRADE;
Begin the upgrade to the latest version.
SET SERVEROUTPUT ON DECLARE l_tz_version PLS_INTEGER; BEGIN SELECT DBMS_DST.get_latest_timezone_version INTO l_tz_version FROM dual; DBMS_OUTPUT.put_line('l_tz_version=' || l_tz_version); DBMS_DST.begin_upgrade(l_tz_version); END; /
Restart the database.
SHUTDOWN IMMEDIATE; STARTUP;
Do the upgrade of the database file zone file.
SET SERVEROUTPUT ON DECLARE l_failures PLS_INTEGER; BEGIN DBMS_DST.upgrade_database(l_failures); DBMS_OUTPUT.put_line('DBMS_DST.upgrade_database : l_failures=' || l_failures); DBMS_DST.end_upgrade(l_failures); DBMS_OUTPUT.put_line('DBMS_DST.end_upgrade : l_failures=' || l_failures); END; /
The {CDB|DBA|ALL|USER}_TSTZ_TABLES
views display the tables that are processed by the time zone file upgrade, and their current upgrade status. The following examples show how they could be used for a CDB an non-CDB database.
-- CDB COLUMN owner FORMAT A30 COLUMN table_name FORMAT A30 SELECT con_id, owner, table_name, upgrade_in_progress FROM cdb_tstz_tables ORDER BY 1,2,3; -- Non-CDB COLUMN owner FORMAT A30 COLUMN table_name FORMAT A30 SELECT owner, table_name, upgrade_in_progress FROM dba_tstz_tables ORDER BY 1,2;
Once the upgrade is complete, check the time zone file version being used.
SELECT * FROM v$timezone_file; FILENAME VERSION CON_ID -------------------- ---------- ---------- timezlrg_31.dat 31 0 SQL> COLUMN property_name FORMAT A30 COLUMN property_value FORMAT A20 SELECT property_name, property_value FROM database_properties WHERE property_name LIKE 'DST_%' ORDER BY property_name; PROPERTY_NAME PROPERTY_VALUE ------------------------------ -------------------- DST_PRIMARY_TT_VERSION 31 DST_SECONDARY_TT_VERSION 0 DST_UPGRADE_STATE NONE SQL>
Upgrade the Time Zone File (Multitenant)
In a multitenant environment, the time zone file upgrade must be performed in all containers. If you follow the example of the non-CDB instance, it will only be upgraded in the root container. What's more, any new PDBs created from the seed will also use the old time zone file. To solve this we run the upgrade in the root container and all PDBs using the "catcon.pl" Perl script.
This example performs all the steps in all containers, without doing any investigation, and assumes everything will work with no additional intervention. You may not want to make this assumption on a database you care about. You can perform the manual steps described above, including the investigation during the prepare phase and dealing with upgrade failures, for each container individually.
Create a script called "/tmp/upgrade_tzf.sql" with the following contents.
SHUTDOWN IMMEDIATE; STARTUP UPGRADE; SET SERVEROUTPUT ON DECLARE l_tz_version PLS_INTEGER; BEGIN SELECT DBMS_DST.get_latest_timezone_version INTO l_tz_version FROM dual; DBMS_OUTPUT.put_line('l_tz_version=' || l_tz_version); DBMS_DST.begin_upgrade(l_tz_version); END; / SHUTDOWN IMMEDIATE; STARTUP; SET SERVEROUTPUT ON DECLARE l_failures PLS_INTEGER; BEGIN DBMS_DST.upgrade_database(l_failures); DBMS_OUTPUT.put_line('DBMS_DST.upgrade_database : l_failures=' || l_failures); DBMS_DST.end_upgrade(l_failures); DBMS_OUTPUT.put_line('DBMS_DST.end_upgrade : l_failures=' || l_failures); END; /
Now we run the script in all containers using the "catcon.pl" Perl script. The "-n 1" flag is important. The script does a shutdown and startup. If the script is run in parallel, some of the PDBs will be processed at the same time as the root container, so their upgrade will be interrupted by the root container shutdown/startup. Running with a single worker keeps things sequential.
$ORACLE_HOME/perl/bin/perl \ -I$ORACLE_HOME/perl/lib \ -I$ORACLE_HOME/rdbms/admin \ $ORACLE_HOME/rdbms/admin/catcon.pl \ -n 1 \ -l /tmp/ \ -b upgrade_tzf \ /tmp/upgrade_tzf.sql
An alternative is to do the root container on its own, then do all the other PDBs in parallel by excluding the root container.
# Root only. $ORACLE_HOME/perl/bin/perl \ -I$ORACLE_HOME/perl/lib \ -I$ORACLE_HOME/rdbms/admin \ $ORACLE_HOME/rdbms/admin/catcon.pl \ -l /tmp/ \ -b upgrade_tzf \ -c 'CDB$ROOT' \ /tmp/upgrade_tzf.sql # Root excluded. $ORACLE_HOME/perl/bin/perl \ -I$ORACLE_HOME/perl/lib \ -I$ORACLE_HOME/rdbms/admin \ $ORACLE_HOME/rdbms/admin/catcon.pl \ -l /tmp/ \ -b upgrade_tzf \ -C 'CDB$ROOT' \ /tmp/upgrade_tzf.sql
Check the "upgrade_tzf*.log" files for the result of the upgrade in each container.
Getting the Latest Time Zone File
You can find latest time zone file for your database in this MOS note.
The note is quite long and confusing, but the patches are listed in the section "C.1.d) DST patches list". Each link takes you to a further note describing the patch and providing the relevant download links. The patches are applied using OPatch in the normal way, but this only makes the new time zone file available. Once the patch has been applied you can go through the process described above to apply it to a database.
For more information see:
Hope this helps. Regards Tim...