This blog posting describes a script to convert Oracle date columns to Timestamps as used from PeopleTools 8.50 but only rebuilding those indexes that reference those columns, rather than drop and recreate every index in the system, thus producing a significant saving of time during the upgrade.
(A longer version of this article is available on my website)
I am working on a PeopleSoft upgrade project. We are going from PeopleTools 8.49 to 8.53. One of the things that happens is that some date columns in the Oracle database become timestamps.
Timestamps were introduced by Oracle in version 10g of the database, and provide the ability to store times accurate to the nanosecond (although the default is microsecond). Dates are accurate to the whole second.
There are 3 types of temporal column in PeopleSoft as defined on PSDBFIELD. Prior to PeopleTools 8.50 they all become Oracle date columns in the database. However, from PeopleTools 8.50; Time and DateTime fields are built as TimeStamp columns.if bit 5 of PSSTATUS.DATABASE_OPTIONS (value 32) is set.
Timestamps must be handled differently to dates in SQL. Some date arithmetic must be done differently, in particular the difference between two timestamps is a timestamp rather than a number of days. Therefore this setting also controls how PeopleCode date macros expand on Oracle.
During the upgrade, PeopleSoft Change Assistant simply alters all the Time and DateTime columns from dates to timestamps. This generally works well. The data value doesn't appear to get longer, so the block doesn't run out of room leading to row migration, and so it isn't necessary to rebuild every table that is affected.
However, there are some limitations. If the column being converted to a timestamp falls into one of the following categories you will get an error.
However, dropping and recreating all these indexes can be very time consuming and increases the duration of the outage required to perform the upgrade. This has been my incentive to find a better way.
Function-Based Indexes
PeopleSoft Application Designer defines some key and search fields as descending. The rows in components and the results of search dialogue are sorted on the key fields in the order specified. Application Designer then indexes these columns in descending order (prior to PeopleTools 8 and since PeopleTools 8.47). If any column in an Oracle index is in descending order the index is created as a function-based index. Consequently, there can be a lot of descending indexes in a PeopleSoft system! HR systems are particularly affected because many tables are effective-dated, and the field EFFDT is usually a descending key field.
It is not possible to alter a column to a timestamp if it appears anywhere in a function-based index. You get the following error:
(A longer version of this article is available on my website)
I am working on a PeopleSoft upgrade project. We are going from PeopleTools 8.49 to 8.53. One of the things that happens is that some date columns in the Oracle database become timestamps.
Timestamps were introduced by Oracle in version 10g of the database, and provide the ability to store times accurate to the nanosecond (although the default is microsecond). Dates are accurate to the whole second.
There are 3 types of temporal column in PeopleSoft as defined on PSDBFIELD. Prior to PeopleTools 8.50 they all become Oracle date columns in the database. However, from PeopleTools 8.50; Time and DateTime fields are built as TimeStamp columns.if bit 5 of PSSTATUS.DATABASE_OPTIONS (value 32) is set.
PeopleTools Field Type |
Database Column Type
|
||
PeopleTools <= 8.49 | PeopleTools >= 8.50 | ||
4 | Date | DATE | DATE |
5 | Time | DATE | TIMESTAMP |
6 | DateTime | DATE | TIMESTAMP |
Timestamps must be handled differently to dates in SQL. Some date arithmetic must be done differently, in particular the difference between two timestamps is a timestamp rather than a number of days. Therefore this setting also controls how PeopleCode date macros expand on Oracle.
During the upgrade, PeopleSoft Change Assistant simply alters all the Time and DateTime columns from dates to timestamps. This generally works well. The data value doesn't appear to get longer, so the block doesn't run out of room leading to row migration, and so it isn't necessary to rebuild every table that is affected.
However, there are some limitations. If the column being converted to a timestamp falls into one of the following categories you will get an error.
- The column is a key column in a function-based index.
- The table or index is partitioned by the column.
However, dropping and recreating all these indexes can be very time consuming and increases the duration of the outage required to perform the upgrade. This has been my incentive to find a better way.
Function-Based Indexes
PeopleSoft Application Designer defines some key and search fields as descending. The rows in components and the results of search dialogue are sorted on the key fields in the order specified. Application Designer then indexes these columns in descending order (prior to PeopleTools 8 and since PeopleTools 8.47). If any column in an Oracle index is in descending order the index is created as a function-based index. Consequently, there can be a lot of descending indexes in a PeopleSoft system! HR systems are particularly affected because many tables are effective-dated, and the field EFFDT is usually a descending key field.
It is not possible to alter a column to a timestamp if it appears anywhere in a function-based index. You get the following error:
ORA-30556: functional index is defined on the column to be modified
Partitioning
Partitioning is not something that you usually encounter in a vanilla PeopleSoft system, but it can be added by customisation. You generate the necessary DDL yourself if you want to use it. However, from PeopleTools 8.51 Application Designer will preserve existing partitioning.
In the system on which I am working, when partitioned the audit tables by AUDIT_STAMP which is a DateTime field.
ORA-14060: data type or length of an table partitioning column may not be changed
We have had no alternative but to rebuild these tables and repopulate the data. This has also dealt with all locally partitioned indexes.We have also found that we have one global index partitioned on a timestamp.
ORA-14061: data type or length of an index partitioning column may not be changed
We also have had to drop this index in order to alter the table.My Approach
We have had no alternative but to rebuild and repopulate our partitioned audit tables which are partitioned by a DateTime field. However, that is what we did when we first partitioned them. The scripts are very similar to those generated by Application Designer. The table is renamed, a new one is built, and the data is copied. In our case these scripts are built with a PL/SQL utility. This also addressed the need to rebuild the locally partitioned indexes..
To minimize the number of indexes which must be rebuilt I have written a PL/SQL script (http://www2.go-faster.co.uk/scripts/gfc_desc_timestamp_index.sql) that:
- identifies the indexes that need to be dropped.
- captures the DDL to recreate the indexes using DBMS_METADATA and stores it in a table,
- drops the indexes,
- alters the columns that cannot be altered with the index in place,
- recreates the index.
On this particular HR system we only rebuilt about 400 indexes instead of over 10000. Now the standard PeopleSoft upgrade template can be run without dropping or recreating any further indexes.
2 comments :
minor typo
"...Prior to PeopleTools 8.50 they all become Oracle data columns in the database..."
should read
"...Prior to PeopleTools 8.50 they all become Oracle DATE columns in the database...."
Thanks - I am glad somebody reads this!
Post a Comment