× 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.



Chris,

I can imagine the optimizer deciding to rewrite the query to "fetch first row", but only after it has scanned the field for cardinality. This could be REALLY fast if the field happens to be a primary key in an access path. The optimizer queries the access path for a count of distinct key values... Normally, whenever I see DISTINCT I think of this as a table scan, with a check to see of "this" row already exists in the result set. Or maybe the optimizer creates a temporary access path to support the analysis. Either way, not a great performer...

In this case, where the accessed table is not really used for anything, I can also see the optimizer realizing that the result set is completely disconnected from the table, so I suppose I can accept a forced fetch first row might be applied. I believe you when you say optimization time is much higher for distinct syntax.

-Eric DeLong

-----Original Message-----
From: rpg400-l-bounces@xxxxxxxxxxxx [mailto:rpg400-l-bounces@xxxxxxxxxxxx] On Behalf Of Hiebert, Chris
Sent: Wednesday, April 25, 2012 12:07 PM
To: RPG programming on the IBM i / System i
Subject: RE: sqlrpgle question

I ran a similar statement through the Visual explain option in
iNavigator and found that the select distinct solution is not as optimal
as the Fetch first 1 rows only statement.

Exec sql
Select '1' into :indicator
From MyTable
Fetch First 1 Rows Only;

In both cases it appears the optimizer actually runs a "Fetch First 1
Rows Only", however when Distinct is specified the Optimizer has to add
logic to re-write the statement to match the "Fetch First 1 Rows"
example.

So, while the estimated runtimes were very close, the optimization time
for the Distinct clause was about 1000 to 100000 times more than just
coding the Fetch First 1 Rows Only.


Chris Hiebert

-----Original Message-----
From: rpg400-l-bounces@xxxxxxxxxxxx
[mailto:rpg400-l-bounces@xxxxxxxxxxxx] On Behalf Of Colpaert, Peter
Sent: Tuesday, April 24, 2012 10:51 PM
To: RPG programming on the IBM i / System i
Subject: RE: sqlrpgle question

Exec sql
Select distinct '1' into :indicator
From MyTable;

HTH,

Peter Colpaert
Software Engineer - PLM Development Team Philips Consumer Luminaires
Tel: (+32) 3/459 13 17
Fax: (+32) 3/450 74 33
Address: Industrieterrein Satenrozen 11, 2550 Kontich, Belgium
Email: Peter.Colpaert@xxxxxxxxxxx


-----Original Message-----
From: rpg400-l-bounces@xxxxxxxxxxxx
[mailto:rpg400-l-bounces@xxxxxxxxxxxx] On Behalf Of Dave
Sent: dinsdag 24 april 2012 16:48
To: RPG programming on the IBM i / System i
Subject: sqlrpgle question

Hi,

I want to set the value of an indicator to *on if I find at least one
record matching my search criteria and *off otherwise.

What's the best way?

eg :

indicator = *off;

exec sql
Select '1' into : indicator
from mytable

where ....err.. what goes here? what if there are many rows returned?

Thanks!
--
This is the RPG programming on the IBM i / System i (RPG400-L) mailing
list To post a message email: RPG400-L@xxxxxxxxxxxx To subscribe,
unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives at
http://archive.midrange.com/rpg400-l.


________________________________
The information contained in this message may be confidential and
legally protected under applicable law. The message is intended solely
for the addressee(s). If you are not the intended recipient, you are
hereby notified that any use, forwarding, dissemination, or reproduction
of this message is strictly prohibited and may be unlawful. If you are
not the intended recipient, please contact the sender by return e-mail
and destroy all copies of the original message.

--
This is the RPG programming on the IBM i / System i (RPG400-L) mailing
list To post a message email: RPG400-L@xxxxxxxxxxxx To subscribe,
unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives at
http://archive.midrange.com/rpg400-l.


As an Amazon Associate we earn from qualifying purchases.

This thread ...

Follow-Ups:
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.