Monthly Archives: August 2017

UKOUG Apps 2017

Just a short note to say that I am proud to be selected as a speaker for UKOUG Apps 2017!

I will even give 2 presentations. On Monday I will present ‘Customizing Autoconfig/RapidClone’. Then on Tuesday I will present ‘Auditing the Oracle eBusiness Suite’.

The first presentation is about further optimizing the Autoconfig and RapidClone processes. Oracle allows users to customize these processes to match their specific requirements / environments. This allows for a very flexible process. Especially since you can add your own parameters to the XML Config file. Then you can add additional templates, or customize the existing templates with (conditional) changes / additions.

In this presentation, I will walk you through the whole process of customizing Autoconfig based on a fictional post-clone script that we’ll incorporate in the Autoconfig process.

The second presentation is of course about Auditing eBusiness Suite. We’ll go over the different options (the eBS provided signon Audit Trail and transaction Audit Trail, database audit trail, audit vault, OS level auditing). Each auditing option has a different purpose. And you will need different options to provide a meaningful and comprehensive audit trail.

One presentation is too short to build a full auditing solution. But I’ll try to give you a headstart on designing your own auditing.

 

eBS Flexfields and Canonical values

CANONICAL VALUES

 

Since I have been working a lot on NUMBER and DATE conversions lately, it’s time to write a short note about canonicals.

Oracle eBS Flexfields (and by extension concurrent program parameters) store all values in a VARCHAR2 column. In general it is a bad idea to store NUMBER and DATE in a VARCHAR2 type. See Datatypes and ORA-1722

 

But for Flexfields we have a controlled environment. Oracle solves problems related to conversions by storing the NUMBER and DATE format as so called ‘canonicals’. This means that all NUMBER and DATE values are stored in a fixed format. It is up tot he application to guarantee that only values in this canonical format are stored in the Flexfields.

Customizations

Especially for DFF values, they will often be used in customized software units. These customizations are also responsible for keeping the data in the canonical format. Best practice is to use the packages FND_NUMBER and FND_DATE. This will assure that your customizations don’t break when Oracle changes the canonical format. (e.g. change the precision on NUMBER).

 

FND_NUMBER

The FND_NUMBER package contains 2 procedures: NUMBER_TO_CANONICAL and CANONICAL_TO_NUMBER. Both take 1 parameter which is a NUMBER respectively a VARCHAR2.

The NUMBER canonical format is ‘FM999999999999999999999.99999999999999999999’. Those are 21 positions left and 20 positions right of the decimal ‘.’. Both functions round the result to 20 decimal positions.

For some reason FND development used a TRANSLATE statement to switch between te decimal separator fort he session and the ‘.’ used in the canonical format. (Hint: TO_NUMBER and TO_CHAR (number) accept the parameter ‘nls_numeric_characters’).

Example:

SQL> alter session set nls_numeric_characters=',.';

Session altered.



SQL> select fnd_number.number_to_canonical(to_number('12345,12')) from dual;

FND_NUMBER.NUMBER_TO_CANONICAL(TO_NUMBER('12345,12'))

--------------------------------------------------------------------------------

12345.12



SQL> select fnd_number.canonical_to_number('12345.12') from dual;

FND_NUMBER.CANONICAL_TO_NUMBER('12345.12')

------------------------------------------

12345,12



SQL> alter session set nls_numeric_characters='.,';

Session altered.



SQL> select fnd_number.number_to_canonical(to_number('12345.12')) from dual;

FND_NUMBER.NUMBER_TO_CANONICAL(TO_NUMBER('12345.12'))

--------------------------------------------------------------------------------

12345.12

 

FND_DATE

The FND_DATE package contains a lot of procedures for backward compatibility. But for canonical values in Flexfields we need CANONICAL_TO_DATE and DATE_TO_CANONICAL.

Since to TO_CHAR(date) and TO_DATE both accept a date mask, the procedure only contain a TO_CHAR/TO_DATE function.

The canonical mask for DATE is: ‘YYYY/MM/DD HH24:MI:SS’.

Example:

SQL> alter session set nls_date_format='DD-MON-YYYY HH:MI:SSAM';

Session altered.



SQL> select fnd_date.date_to_canonical(to_date('5-apr-2017 3:21:45PM','dd-mon-yyyy hh:mi:ssam')) from  dual;

FND_DATE.DATE_TO_CANONICAL(TO_DATE('5-APR-20173:21:45PM','DD-MON-YYYYHH:MI:SSAM'

--------------------------------------------------------------------------------

2017/04/05 15:21:45



SQL> select fnd_date.canonical_to_date('2017/02/03 21:32:54') from dual;

FND_DATE.CANONICAL_TO_

----------------------

03-FEB-2017 09:32:54PM

 

More goodies

Two other functions that are convenient to use when dealing with string values and dates are STRING_TO_DATE and STRING_TO_CANONICAL.

For dates MONTH, AM/PM and AD/BC values are language dependent. So based on the session settings they may return different results. STRING_TO_DATE and STRING_TO_CANONICAL handle this by trying different language settings. In order they try NLS_DATE_FORMAT (default), NLS_NUMERIC_LANGUAGE and the installed eBS languages from FND_LANGUAGES.

Both take a string that represents a date and the date-mask for the string. STRING_TO_DATE returns a DATE value, while STRING_TO_CANONICAL uses STRING_TO_DATE but converts the result to a canonical VARCHAR2.

Example:

SQL> alter session set nls_date_language=AMERICAN;

Session altered.



SQL> select nls_language

2  from fnd_languages

3  where installed_flag in ('B','I');

NLS_LANGUAGE

------------------------------

DUTCH

AMERICAN



SQL> select to_date('3-mrt-2017 23:45:12','dd-mon-yyyy hh24:mi:ss') from dual;

select to_date('3-mrt-2017 23:45:12','dd-mon-yyyy hh24:mi:ss') from dual

*

ERROR at line 1:

ORA-01843: not a valid month



SQL> select fnd_date.string_to_date('3-mrt-2017 23:45:12','dd-mon-yyyy hh24:mi:ss') from dual;

FND_DATE.STRING_TO_DAT

----------------------

03-MAR-2017 11:45:12PM



SQL> select fnd_date.string_to_canonical('3-mrt-2017 23:45:12','dd-mon-yyyy hh24:mi:ss') from dual;

FND_DATE.STRING_TO_CANONICAL('3-MRT-201723:45:12','DD-MON-YYYYHH24:MI:SS')

--------------------------------------------------------------------------------

2017/03/03 23:45:12

 

HTH. As always, feel free to leave comments and questions.

NLS_DATE_LANGUAGE and ORA-1856

Trying to write some information about the DATE datatype, I ran into the following problem:

SQL> insert into ot_dt values (to_date('1-jan-4712 BC','dd-mon-yyyy BC'));
insert into ot_dt values (to_date('1-jan-4712 BC','dd-mon-yyyy BC'))
*
ERROR at line 1:
ORA-01856: BC/B.C. or AD/A.D. required

Also different varieties (B.C. , bc, AD, A.D.) with or without a space, with different seperators all gave the same ORA-1856: BC/B.C. or AD/A.D. required.

Excuse me. That is what I just entered. What is going on here?

Enter the parameter NLS_DATE_LANGUAGE.

From the Database Globalization Support Guide:

NLS_DATE_LANGUAGE also determines the language used for:

  • Month and day abbreviations returned by the TO_CHAR and TO_DATE functions
  • Month and day abbreviations used by the default date format (NLS_DATE_FORMAT)
  • Abbreviations for AM, PM, AD, and BC” (emphasis added)

 

The abbreviation that you can use in to_date for AD/BC is dependent on the parameter NLS_DATE_LANGUAGE. Accidentally my setting was DUTCH. Let’s change it to AMERICAN:

SQL> alter session set nls_date_language=AMERICAN;

Session altered.

SQL>

SQL> insert all into ot_dt values (to_date('1-jan-4712 BC','dd-mon-yyyy BC'))
2 into ot_dt values (to_date('1-jan-2017 AD','dd-mon-yyyy BC'))
3 select * from dual;

2 rows created.

SQL> select to_char(dummy,'dd-mon-yyyy B.C.') from ot_dt;

TO_CHAR(DUMMY,'DD-MON-YYY
-------------------------
01-jan-4712 B.C.
01-jan-2017 A.D.

SQL> alter session set nls_date_language=DUTCH;

Session altered.

SQL> select to_char(dummy,'dd-mon-yyyy BC') from ot_dt;

TO_CHAR(DUMMY,'DD-MON-YYYYB
---------------------------
01-jan-4712 V.CHR.
01-jan-2017 N.CHR.

SQL> select to_char(dummy,'dd-mon-yyyy B.C.') from ot_dt;

TO_CHAR(DUMMY,'DD-MON-YYYYB
---------------------------
01-jan-4712 V.CHR.
01-jan-2017 N.CHR.

SQL> select to_char(dummy,'dd-mon-yyyy bc') from ot_dt;

TO_CHAR(DUMMY,'DD-MON-YYYYB
---------------------------
01-jan-4712 v.Chr.
01-jan-2017 n.Chr.

The values for Dutch AD/BC are V.CHR/N.CHR or in lowercaps v.Chr. and n.Chr.

And that is also what you can use in your INSERT:

SQL> insert into ot_dt values (to_date('1-jan-4712 v.Chr.','dd-mon-yyyy bc'));

1 row created.

 

Good to know, #LearnSomethingNewEveryDay

 

Datatypes and ORA-1722

Datatypes

Introduction

The first new blog entry on the site is about ‘Datatypes’. Or more precisely  about datatype (implicit)  conversions. It was triggered by the too-often-seen ORA-1722 Invalid Number. But the root cause is valid for numbers as well as dates (/timestamps). In this article I will investigate some of the causes for ORA-1722 in NUMBER and DATE conversions.

<Disclaimer: All test use the tables defined in base_tables
Unless stated otherwise each example is executed in SQL*Plus and starts with an empty table
Database version used: Oracle XE 11.2.0.2
SQL*Plus version used: SQL*Plus: Release 11.2.0.2.0 Production
Please test and reproduce on your own system for validation
End disclaimer>

Consider:

SQL> insert into ot_vc_nb values (32.5,32.5);
1 row created.

SQL> select dummy_vc+1, dummy_nb+1 from ot_vc_nb;
DUMMY_VC+1 DUMMY_NB+1
---------- ----------
33,5             33,5

SQL> alter session set nls_numeric_characters='.,';
Session altered.

SQL> select dummy_vc+1 from ot_vc_nb;
select dummy_vc+1 from ot_vc_nb
*
ERROR at line 1:
ORA-01722: invalid number

SQL> select dummy_nb+1 from ot_vc_nb;
DUMMY_NB+1
----------
33.5

And for DATE values:

SQL> insert into ot_vc_dt values ('9-mar-2017','9-mar-2017');
1 row created.

SQL> select dummy_vc, dummy_dt from ot_vc_dt;
DUMMY_VC      DUMMY_DT
------------- ---------
9-mar-2017    09-MAR-17

SQL> select add_months(dummy_vc,1),add_months(dummy_dt,1) from ot_vc_dt;
ADD_MONTH ADD_MONTH
--------- ---------
09-apr-17 09-apr-17

SQL> select dummy_vc+1 from ot_vc_dt;
select dummy_vc+1 from ot_vc_dt
*
ERROR at line 1:
ORA-01722: invalid number

SQL> select dummy_dt+1 from ot_vc_dt;
DUMMY_DT+1
----------
10-03-2017

And one of my personal favorites:

SQL> select to_date(sysdate,'dd mm yyyy'), to_date(sysdate,'yyyy/mm/dd') from dual;
TO_DATE(S TO_DATE(S
--------- ---------
18-aug-17 17-aug-18

SQL> select to_date(sysdate,'dd mm yyyy')+1, to_date(sysdate,'yyyy/mm/dd')+1 from dual;
TO_DATE(S TO_DATE(S
--------- ---------
19-aug-17 18-aug-18

All errors above have the same root cause: implicit conversions.
In all cases we execute operations that are not valid for the data type that we use. Oracle needs to convert the data to a different data type to execute the operation.
This conversion can fail, resulting in an ORA-1722. Or it can succeed with unexpected results.

Reminder: Implicit conversions are a BAD idea. They’re guaranteed to come back and bite you.

So when do implicit conversion happen, and why can they fail? Let’s look at:

Data Types

The Oracle RDBMS provides a number of data types for SQL operations and a few extra for PL/SQL operations. In this article, we’ll focus on VARCHAR2, NUMBER and DATE types.

Each data type is stored in a particular way in the database. The stored value is not what you see in your GUI or reporting tool. VARCHAR2 values add extra complexity because of different character sets that can be used. But let’s take a look at NUMBER values first.

NUMBER

Check the Knowledgebase for more details about NUMBER

Consider:

SQL> insert into ot_cmp (dummy_vc, dummy_nb) values (1,1);
1 row created.

SQL> insert into ot_cmp (dummy_vc, dummy_nb) values (1.314,1.314);
1 row created.

SQL> select dummy_vc, dump(dummy_vc), dummy_nb, dump(dummy_nb) from ot_cmp;
DUMMY_VC    DUMP(DUMMY_VC)
----------  ---------------------------------------------
DUMMY_NB    DUMP(DUMMY_NB)
----------  ---------------------------------------------
1           Typ=1 Len=1: 49
1           Typ=2 Len=2: 193,2
1,314       Typ=1 Len=5: 49,44,51,49,52
1,314       Typ=2 Len=4: 193,2,32,41

We inserted the values 1 and 1.314 in a NUMBER and a VARCHAR2 column. And we can see that they are stored very differently.

When we query the values, they look the same (except for the alignment). But they are obviously not the same to the Oracle RDBMS.

That difference becomes apparent when we change the context:

SQL> select dummy_vc + 1, dummy_nb + 1 from ot_cmp;
DUMMY_VC+1  DUMMY_NB+1
----------  ----------
2                    2
2,314            2,314

SQL> alter session set nls_numeric_characters='.,';
Session altered.

SQL> select dummy_vc,dummy_nb from ot_cmp;
DUMMY_VC    DUMMY_NB
----------  ----------
1                    1
1,314            1.314

SQL> select dummy_vc + 1 from ot_cmp;
ERROR:
ORA-01722: invalid number

SQL> select dummy_nb + 1 from ot_cmp;
DUMMY_NB+1
----------
         2
     2.314

We can use a numeric operation ‘+’ on the values after we inserted them.

But when we change the parameter NLS_NUMERIC_CHARACTERS, the VARCHAR2 value is not suitable for numeric operations anymore.

It is now truly a string value. How is this possible?

On insert / update Oracle needs to convert all data to the internal storage format. When the data is retrieved again, it needs to be converted to whatever format the client is requesting.

Initially the parameter NLS_NUMERIC_CHARACTERS was set to ‘,.’.  That means that we use a decimal ‘,’ (comma).

On inserting a number value in the table Oracle converted the number 1.314 accordingly to 1,314.

Then it inserted this in DUMMY_VC as a VARCHAR2 value and in DUMMY_NB as a NUMBER value.

When we query the values with the same settings, Oracle does not convert DUMMY_VC. (Remember it is a VARCHAR2 value, so a text string).

DUMMY_NB is a NUMBER type, so Oracle converts it to 1,314 as requested by the client.

When we change NLS_NUMERIC_PARAMETERS to ‘.,’ we tell Oracle that we will be using numbers with a decimal ‘.’ (period).

When we now query the values, DUMMY_VC is still unchanged (1,314) and therefore not a valid number. DUMMY_NB is duly converted to 1.314 as requested by the client.

  • Note that NLS_NUMERIC_CHARACTERS is the most obvious parameter for this change. But all NLS parameters are interdependent. So changing NLS_TERRITORY can also implicitly change NLS_NUMERIC_CHARACTERS.

In the last query, we try to execute a numeric operation ‘+’ on the DUMMY_VC value. Oracle has retrieved this value as a VARCHAR2 type.

But to perform the ‘+’ it needs to be treated as a number value. But it is not a valid number, because it does not match the format with a decimal ‘.’.

When Oracle tries this, it fails with ORA-1722. Now we know it makes sense. Because it is still in the VARCHAR2 format: ‘1,314’ instead of 1.314.

As an exercise to the reader: How did the following happen?

SQL> delete from ot_cmp;
0 rows deleted.

SQL> insert into ot_cmp (dummy_vc, dummy_nb) values (1314, 1314);
1 row created.

SQL> select dummy_vc, dummy_nb from ot_cmp;
DUMMY_VC  DUMMY_NB
--------  --------
1314           522

 

DATE

Check the Knowledgebase for more details about DATE

Let’s take a look at DATE types next. As we have seen, each data type has its own specific storage in the Oracle database. Dates are stored in a 7 byte string. Let’s take a look:

SQL> insert into ot_cmp (dummy_vc,dummy_dt)
          values (to_date('19-aug-2017 22:15:30','dd-mon-yyyy hh24:mi:ss')
                 ,to_date('19-aug-2017 22:15:30','dd-mon-yyyy hh24:mi:ss'));
1 row created.

SQL> select dummy_vc,dump(dummy_vc), dummy_dt, dump(dummy_dt) from ot_cmp;
DUMMY_VC    DUMP(DUMMY_VC)
----------  --------------------------------------------------------------------
19-AUG-17   Typ=1 Len=9: 49,57,45,65,85,71,45,49,55

DUMMY_DT    DUMP(DUMMY_DT)
---------   --------------------------------------------------------------------
19-AUG-17   Typ=12 Len=7: 120,117,8,19,23,16,31

There is a lot going on in that demo. Let’s start with the insert statement. A VARCHAR2 or in general a string is placed in single quotes ‘ ‘. A number without quotes is just that: a number. Place a number in quotes, and it becomes a text string / VARCHAR2. A date in quotes is also just a VARCHAR2. To make a date, you need to use the to_date command. TO_DATE will convert a VARCHAR2 to a DATE. However, Oracle needs to know how to convert the date. That is what the format string is for. Without the format string, Oracle will guess the date format. And guesses can be right or wrong. To avoid errors, always use a format string.

So I inserted a DATE value in a VARCHAR2 (bad idea!) and in a DATE. When I query the table, we see that the VARCHAR2 value has lost the timestamp and century. And what’s worse, it is stored as a text string with the text ’19-AUG-17’.

The date value also doesn’t show the time and century. However, when we look at the dump we see that they have been stored anyway.

The date is stored in 7 bytes. The century, year, hour, minute and second values have increased by 100 or 1. So we have 120 instead of 20, 117 instead of 17, 8 for August, 19 for the day.

The time is stored in the last 3 bytes, each number increased by 1.

So why did the VARCHAR2 loose the data on century and time. And why are they not shown for the DATE? That is because of parameter NLS_DATE_FORMAT. This is the date-format that the client will use. The default is DD-MON-RR.

I created a date to insert into the VARCHAR2. Oracle converted this to the format ‘DD-MON-RR’ then inserted it into the VARCHAR2. The DATE was inserted correctly as a date. But when we query the data the DATE is again displayed in the format ‘DD-MON-RR’. To see the full date, we need to convert it into a string again with the correct format. Or we change the NLS_DATE_FORMAT to the required format.

SQL> select to_char(dummy_dt,'dd-mon-yyyy hh24:mi:ss') from ot_cmp;

TO_CHAR(DUMMY_DT,'DD-MON-YYYY
-----------------------------
19-aug-2017 22:15:30

So what can happen when we don’t use an explicit format? Consider:

SQL> select to_char(to_date(to_char(to_date('1-jan-1817'))),'dd-mon-yyyy') "When
?" from dual;

When?
--------------------
01-jan-2017

 

But back to the ORA-1722 message. How does this error happen with date conversions? Consider:

SQL> insert into ot_cmp (dummy_vc, dummy_dt) values ('3-mar-2017','3-mar-2017');
1 row created.

SQL> select add_months(dummy_vc,1), add_months(dummy_dt,1) from ot_cmp;
ADD_MONTH  ADD_MONTH
---------  ---------
03-APR-17  03-APR-17

SQL> select dummy_vc + 1 from ot_cmp;
select dummy_vc + 1 from ot_cmp
*
ERROR at line 1:
ORA-01722: invalid number

We inserted a string value that looks like a date into a VARCHAR2. When we use a date-function on it (ADD_MONTHS), it works correctly. But when we want to add 1 day to it, it returns an ORA-1722.

This is caused by implicit conversion again. ADD_MONTHS does an implicit conversion to a DATE on the input parameter, then executes the function and returns a DATE. The ‘+’ operator can accept both NUMBER and DATE values. But in this case Oracle will first check if the value can be converted to a NUMBER. As we see, this fails.

By now you should be convinced that implicit conversions are almost always a bad idea. Storing dates or numbers in a VARCHAR2 is even worse. In case you need some more convincing, here are some more examples:

SQL> alter session set nls_date_format='dd-mm-yyyy';

Session altered.

SQL> insert into ot_cmp (dummy_vc,dummy_dt) values ('12-03-2017','12-03-2017');

1 row created.

SQL> alter session set nls_date_format='mm-dd-yyyy';

Session altered.

SQL> select add_months(dummy_vc,1),add_months(dummy_dt,1) from ot_cmp;

ADD_MONTHS ADD_MONTHS
---------- ----------
01-03-2018 04-12-2017

It might be silly to change the date-format from ‘dd-mm-yyyy’ to ‘mm-dd-yyyy’. But remember that it is the client who sets the nls_date_format. No privileges are involved in setting the format! The only way to be safe from changing NLS_DATE_FORMATS is to use DATE types for dates and proper format strings on the conversions.

On date conversions without a format string:

SQL> alter session set nls_date_format='dd-mon-rr';  --Default setting

Session altered.

SQL> insert into ot_cmp (dummy_vc,dummy_dt) values (to_date('15-mar-1817'),to_date('15-mar-1817','dd-mon-yyyy'));

1 row created.

SQL> select dummy_vc, dummy_dt from ot_cmp;

DUMMY_VC   DUMMY_DT
---------  ---------
15-mar-17  15-mar-17

SQL> select dummy_vc from ot_cmp where dummy_vc>to_date('1-jan-2017','dd-mon-yyyy');

DUMMY_VC
---------
15-mar-17

SQL> select dummy_dt from ot_cmp where dummy_dt>to_date('1-jan-2017','dd-mon-yyyy');

no rows selected

 

The VARCHAR2 string lost the century. So Oracle will just use the current century when it is converted back to a DATE again.

 

SQL> select dummy_dt from ot_cmp where to_date(to_char(dummy_dt),'dd-mon-yy')>
          to_date('1-jan-2017', 'dd-mon-yyyy');

DUMMY_DT
---------
15-mar-17

SQL> select to_char(to_date(to_char(dummy_dt),'dd-mon-yyyy'),'dd-mon-yyyy') from ot_cmp;

TO_CHAR(TO_DATE(TO_C
--------------------
15-mar-0017

 

Even the DATE is not safe without a good format string. In this case, we use a TO_CHAR without a format string. So the NLS_DATE_FORMAT will be used (‘DD-MON-RR’). When we convert the VARCHAR2 back to a DATE we lose the century again. Which results in:

SQL> select dummy_dt from ot_cmp where to_date(to_char(dummy_dt),'dd-mon-yy')
          >to_date('1-jan-2017','dd-mon-yyyy')

DUMMY_DT
---------
15-mar-17

 

By now I hope you have sufficient information to troubleshoot (or avoid) ORA-1722 and avoid implicit conversions entirely in your code.

Feel free to leave any comments, and keep implicit conversions in mind when you encounter ORA-1722.

HTH