Skip to Main Content

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, Duke.

Asked: February 06, 2008 - 3:51 pm UTC

Last updated: February 08, 2008 - 7:28 am UTC

Version: 10.2.0

Viewed 1000+ times

You Asked

Simple question, I hope. I'm trying to remember which function or mask is indeterminate when appled, for example, to SYSDATE. As I recall, it couldn't be used in a function-based index. But I can't seem to spot it while trawling the site.

and Tom said...

it isn't when applied to SYSDATE, it is when turning strings into dates.

For example, YYYY is not deterministic as a date input format. to_date(x,'YYYY') returns a date in that year, but the date is the 1st day of the current month. You'd need to use

to_date( x||'01','fxYYYYMM')

to get a deterministic result


ops$tkyte%ORA10GR2> create table t ( yyyy varchar(2) );

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create index t_idx on t(to_date(yyyy,'fxYYYY'));
create index t_idx on t(to_date(yyyy,'fxYYYY'))
                                *
ERROR at line 1:
ORA-01743: only pure functions can be indexed


ops$tkyte%ORA10GR2> create index t_idx on t(to_date(yyyy||'01','fxYYYYMM'));

Index created.


Rating

  (5 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

That's it!

Duke Ganote, February 07, 2008 - 1:00 pm UTC

Thanks! You've got a sharp memory!
Tom Kyte
February 07, 2008 - 1:38 pm UTC

hah, I just did a seminar where I talk about function based indexes and the purity requirement and this is an example I use in it :)

Exactly!

Duke Ganote, February 07, 2008 - 2:18 pm UTC

As I was racking my brains, I was thinking... "here's a stump-the-candidate interview question! (And I'm failing myself)"

Pure as the driven slush.

Gary, February 07, 2008 - 11:21 pm UTC

Being picky but, even though to_date(yyyy||'01','fxYYYYMM')) is accepted by Oracle as 'pure', it actually isn't if you change nls_calendar. Because it isn't pure, you can get a different answer between a query using the index and one that doesn't.

>drop table t;
Table dropped.
>create table t ( yyyy number(4) not null, text_date varchar2(30) );
Table created.
>create index t_idx on t(to_date(yyyy||'01','fxYYYYMM'));
Index created.
>insert into t (yyyy, text_date) values (2008, to_char(sysdate,'MM YYYY') );
1 row created.
>alter session set NLS_CALENDAR="Arabic Hijrah" ;
Session altered.
>select count(*) from t
2 where to_date(yyyy||'01','fxYYYYMM') = date '2008-01-01';
COUNT(*)
--------
1

>select /*+FULL(t) */ count(*) from t
2 where to_date(yyyy||'01','fxYYYYMM') = date '2008-01-01';
COUNT(*)
--------
0

Tom Kyte
February 08, 2008 - 7:28 am UTC

interesting, thats a bug.

please explain

USKasturi, February 11, 2008 - 3:35 am UTC

Tom
I am really sorry to sak this
I dont understand the Question above and waht exactly is being done
Please explain


RE: please explain

Duke Ganote, February 11, 2008 - 9:20 am UTC

Here's an example:
SQL> alter session set nls_date_format= 'YYYY MONTH DD';

Session altered.

SQL> select sysdate TODAY, to_date('2008','YYYY') "1st_OF_YR?" from dual;

TODAY             1st_OF_YR?
----------------- -----------------
2008 FEBRUARY  11 2008 <b>FEBRUARY</b>  01 -- <b>NOT january!</b>