Skip to Main Content
  • Questions
  • Treating null dates as beginning/end of time

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, mike.

Asked: September 01, 2009 - 10:03 am UTC

Last updated: March 25, 2013 - 2:16 pm UTC

Version: 11g

Viewed 10K+ times! This question is

You Asked

Hello, Tom!

We have many tables with start/end dates, and we often query rows where a particular date, say sysdate, falls between them.

I've always seen done this way:

A: select * from table where (end_date is null or end_date >= sysdate)

Sometimes I found this tedious to write, like when the column name was really long, so I started doing it this way:

B: select * from table where nvl(end_date, to_date('31-DEC-9999', 'dd-mon-yyyy')) >= sysdate

Now I know B is longer, but it is shorter when I use it in stored procedures where I've declared date d_eot and set it to to_date('31-DEC-9999', 'dd-mon-yyyy') so I can do:

C: select * from table where nvl(end_date, d_eot) >= sysdate

I like C, I think it's more lean and readable than A.

Then I got to wondering, what's the performance difference? A few saved keystrokes do not justify sub-optimal sql. I compared explain plans and B/C performed better.

What's the best way?

and Tom said...

I think personally, A is the most readable. It actually says to me "get all of the rows such that end_date is not set or end_date >= right now"

C says "take end_date, if null set it to some value I cannot see, and then compare to sysdate"

The first says precisely what you mean, the second, not so much.


But that aside, if you are not planning on using an index as an access path for this (A) would get my vote. If you wanted an index access path then:

ops$tkyte%ORA11GR1> create table t
  2  as
  3  select all_objects.*, decode( mod(rownum,100), 0, to_date(null), created+1 ) end_date
  4    from stage all_objects
  5  /

Table created.

ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> create index t_idx on t( nvl(end_date,to_date('31-dec-9999','dd-mon-yyyy') ) );

Index created.

ops$tkyte%ORA11GR1> exec dbms_stats.gather_table_stats( user, 'T', method_opt=>'for all indexed columns' );

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> variable x varchar2(30)
ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> set autotrace traceonly explain
ops$tkyte%ORA11GR1> select * from t where nvl(end_date,to_date('31-dec-9999','dd-mon-yyyy')) >= sysdate;

Execution Plan
----------------------------------------------------------
Plan hash value: 470836197

-------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |   913 |   104K|    31   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| T     |   913 |   104K|    31   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | T_IDX |   913 |       |     4   (0)| 00:00:01 |
-------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access(NVL("END_DATE",TO_DATE(' 9999-12-31 00:00:00', 'syyyy-mm-dd
              hh24:mi:ss'))>=SYSDATE@!)

ops$tkyte%ORA11GR1> set autotrace off



that would be my approach and you can hide the complexity if you wish by adding a virtual column:

ops$tkyte%ORA11GR1> drop index t_idx;

Index dropped.

ops$tkyte%ORA11GR1> alter table t add end_date_nvl as (nvl(end_date,to_date('31-dec-9999','dd-mon-yyyy')));

Table altered.

ops$tkyte%ORA11GR1> create index t_idx on t(end_date_nvl);

Index created.

ops$tkyte%ORA11GR1> exec dbms_stats.gather_table_stats( user, 'T', method_opt=>'for all indexed columns' );

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> set autotrace traceonly explain
ops$tkyte%ORA11GR1> select * from t where end_date_nvl >= sysdate;

Execution Plan
----------------------------------------------------------
Plan hash value: 470836197

-------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |   913 |   104K|    31   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| T     |   913 |   104K|    31   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | T_IDX |   913 |       |     4   (0)| 00:00:01 |
-------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("END_DATE_NVL">=SYSDATE@!)

ops$tkyte%ORA11GR1> set autotrace off

Rating

  (1 rating)

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

Comments

stick to nulls?

Cem, March 14, 2013 - 2:24 pm UTC

Hi Tom,
I read in another post from you where you say keep null if it is null and don't go for Defaulting the values which might match a real value in the future.
Also the 9999 date can confuse the optimizer for between predicates which you also mentioned (ok maybe with histograms it is not a big deal)
Here you are doing NVL column to defaul the date. Can we say in DW environments, especially for slowly changing dimension type 2 tables, defaulting the date to future is acceptable by you? Is this only one exception where we can not stick to null?
Thanks in advance
Tom Kyte
March 25, 2013 - 2:16 pm UTC

.. (ok maybe with histograms it is not a big deal) ..


Ok, maybe it can be much worse with histograms actually!!!!!!



I would stick with nulls when null is the appropriate value. do not fear outer joins, I know you've been brought up to be afraid of them (most everyone is) but it is OK. really - they are.


If the date is missing, unknown then NULL is the right 'value' (or lack thereof actually) in practice.

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library