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



That fact has already been discussed.

The code is for example purposes only.

Charles

On Fri, Jun 4, 2021 at 8:39 AM Birgitta Hauser <Hauser@xxxxxxxxxxxxxxx>
wrote:

If we are talking about performance, ... in this case an UNION clause is
not necessary at all:

With CTE_Temp
as (Select Fld01, Fld02
From Table1
Where Fld03 = ABC)
Select Fld01
From CTE_TEMP
Where Fld2 in ('X', 'Y');

Mit freundlichen Grüßen / Best regards

Birgitta Hauser


"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training them
and keeping them!"
„Train people well enough so they can leave, treat them well enough so
they don't want to.“ (Richard Branson)


-----Original Message-----
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of
Charles Wilt
Sent: Freitag, 4. Juni 2021 15:29
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxxxxxxxx>
Subject: Re: CTE in SQL

While not a bad to consider a CTE as a "temp run-time view", it's
important to understand the performance differences.

In the below, if the system decides to materialize the CTE, it will do so
once.
with cte_temp as (
select fld01, fld02
from table1
where fld3 = 'ABCD'
)
select fld01
from cte_temp
where fld2 = 'X'
UNION ALL
select fld01
from cte_temp
where fld2 = 'Z';

whereas, if a view is used, the results of that view would be materialized
twice.
create view myview as (
select fld01, fld02
from table1
where fld3 = 'ABCD'
);

select fld01
from myview
where fld2 = 'X'
UNION ALL
select fld01
from myview
where fld2 = 'Z';

A view is performance neutral compared to it's equivalent Nested Table
Expression (NTE) select fld01 from (
select fld01, fld02
from table1
where fld3 = 'ABCD'
)
where fld2 = 'X'
UNION ALL
select fld01
from (
select fld01, fld02
from table1
where fld3 = 'ABCD'
)
where fld2 = 'Z';
Whereas a CTE is not. Thus the preference for CTEs.

Charles



On Fri, Jun 4, 2021 at 5:53 AM K Crawford <kscx3ksc@xxxxxxxxx> wrote:

Thanks for the replies.
My example was just for show. The union would work in this example
but not in my real application.

I think I understand it much better. Just a temp run-time view. As
Brigitta said create a view if needed more.

Thanks to everyone on these list I learn so much...

Kerwin

On Fri, Jun 4, 2021 at 5:25 AM Niels Liisberg <nli@xxxxxxxxxxxxxxxxx>
wrote:

In your particular case a view in qtemp made with “create or replace”
would
do the trick.


fre. 4. jun. 2021 kl. 08.16 skrev Birgitta Hauser <
Hauser@xxxxxxxxxxxxxxx
:

If these are not adhoc queries and the CTE can be used for
multiple SQL statements, I'd suggest to create a view, which is
kind of a logical file based on
a
select statement that can be used in SQL where ever a table can be
used.
I'd also prefer a view over a temporary table!

Mit freundlichen Grüßen / Best regards

Birgitta Hauser


"Shoot for the moon, even if you miss, you'll land among the stars."
(Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not
training
them
and keeping them!"
„Train people well enough so they can leave, treat them well
enough so
they
don't want to.“ (Richard Branson)


-----Original Message-----
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf
Of Charles Wilt
Sent: Donnerstag, 3. Juni 2021 22:42
To: Midrange Systems Technical Discussion <
midrange-l@xxxxxxxxxxxxxxxxxx

Subject: Re: CTE in SQL

No.

A CTE only exists for a single statement.

DECLARE GLOBAL TEMPORARY TABLE allows you to build a work file
that can
be
used by multiple statements. But there's significant downsides to
doing
so,
namely the fact such a table has no indexes. You can of course
add
some
before you start working with it. In general, IBM recommends
staying
away
from them as they are easily abused. (see
https://www.itjungle.com/2015/06/02/fhg060215-story02/) But they
do
make
sense sometimes.

In your example, there's really no need for either two statements
or
even
the CTE select fld01
from table1
where fld3 = 'ABCD'
and fld2 in ('X','Z');

Now maybe it was a simple example, and the above won't work for
real...or
maybe you're just experimenting with CTE's.

UNION (or preferably UNION ALL) as Carel suggests is something to
keep
in
mind to join together the results of two separate SELECT.

Charles


On Thu, Jun 3, 2021 at 2:21 PM K Crawford <kscx3ksc@xxxxxxxxx>
wrote:

I am teaching myself the CTE of SQL. Got it working great.
Have one question.
I have one CTE that I want to use for two separate SQL statements.
In ACS Run SQL Scripts it would look something like this.

with cte_temp as (
select fld01, fld02
from table1
where fld3 = 'ABCD'
)
select fld01
from cte_temp
where fld2 = 'X'
;stop;
select fld01
from cte_temp
where fld2 = 'Z'

Can this be done? I ended up copy the cte_temp to the second SQL.

--
KCrawford
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L)
mailing
list To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx To
subscribe, unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription
related questions.

Help support midrange.com by shopping at amazon.com with our
affiliate
link: https://amazon.midrange.com

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L)
mailing
list
To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx To
subscribe, unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription
related
questions.

Help support midrange.com by shopping at amazon.com with our
affiliate
link:
https://amazon.midrange.com

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L)
mailing
list
To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx To
subscribe, unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription
related
questions.

Help support midrange.com by shopping at amazon.com with our
affiliate
link: https://amazon.midrange.com

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L)
mailing
list
To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx To subscribe,
unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription
related questions.

Help support midrange.com by shopping at amazon.com with our
affiliate
link: https://amazon.midrange.com



--
KCrawford
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing
list To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx To
subscribe, unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription
related questions.

Help support midrange.com by shopping at amazon.com with our affiliate
link: https://amazon.midrange.com

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing
list To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx To subscribe,
unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription related
questions.

Help support midrange.com by shopping at amazon.com with our affiliate
link: https://amazon.midrange.com

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives
at https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription related
questions.

Help support midrange.com by shopping at amazon.com with our affiliate
link: https://amazon.midrange.com


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.