× The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.



Ran one more test:

with temp1 as (
select * from hlthprdfil/finvhdp
)
select * from temp1
where invdat = current_date
-->uses an index probe (yea!)

So the SQE was able handle the WHERE outside of the CTE. At least in
this simple case.

You'd still be better off moving the WHERE into the CTE as a general
practice. IMHO.

Charles


On Mon, Nov 8, 2010 at 3:35 PM, Charles Wilt <charles.wilt@xxxxxxxxx> wrote:
No, the use of the CTE in your example wouldn't change the fact that
an index can't be used.

In fact, I'm pretty sure just moving the WHERE criteria out of the CTE
could cause an index to not be used.  It depends of if the SQE can
optimize out the CTE or not.  In other words:

while this will use an index:
select * from ech
where hedte < datetonum(CURRENT_DATE - 30 days)


I wouldn't be surprise to see that this wouldn't (after all you told
it to build a temporary table, which isn't going to have an index)
with temp1 as
 (select * from ech )
select * from temp1
where hedte < datetonum(CURRENT_DATE - 30 days)

As to your second question, numtodate() certainly prevents the use of
an index and the + 30 days may do so.  (It does at v5r4 at least,
perhaps later versions are a bit smarter and can rewrite +30 on one
side to - 30 on the other)

Running some actual tests at v5r4
select * from hlthprdfil/finvhdp
where invdat = current_date
--->uses an index probe (fastest)

select * from hlthprdfil/finvhdp
where invdat = current_date - 7 days
--->uses an index probe (fastest)

select * from hlthprdfil/finvhdp
where invdat + 7 days = current_date
--->uses an index scan (slow, but not as slow as a table scan)


Rule of thumb, try not to do anything to the data in a column in the
WHERE clause.

HTH,
Charles



On Mon, Nov 8, 2010 at 2:47 PM, Tom E Stieger <testieger@xxxxxxxxxxxx> wrote:
Charles-

If you did
With temp1 as
       (select numtodate(hord)+30 days as testdate
       from ...
       )
Select * from temp1 where testdate < current_date

Would that make any difference to the index selection?  I'm pretty sure it wouldn't but I thought I would ask.  Also is it the numtodate UDF or the "+ 30 days" on the field that cause the full table scan, or both?

Thanks

-Tom Stieger
Engineer
California Fine Wire



As an Amazon Associate we earn from qualifying purchases.

This thread ...

Replies:

Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].

Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.