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



Views are performance-neutral, in the sense that the view definition is
effectively "inserted into" the SQL query at the point of the reference.
The view object itself is not a "thing" from the query engine's view. It's
simply a bit of shorthand to make writing the query easier.

However, a CTE is a bit different from a view in its meaning and
*potentially* in its implementation. Real simple example of a difference
is when the CTE references a user-defined function. If you reference that
CTE twice in a query, that UDF will only be run once per the CTEs result
set, not twice. If you make that CTE into a view and reference the view
twice in a query, the UDF will be run for each reference.

with cte (x) as ( select col1 from t1 where somefunction()=42)
select * from cte union all select * from cte; --somefunction() runs
once for every row in t1

vs.

create view v1 as ( select col1 from t1 where somefunction()=42);
select * from v1 union all select * from v1; --somefunction() runs
twice for every row in t1

So, your case1 and case2 would be identical, but case3 could be subtly
different.
In practice, for many queries, there won't be a difference, but it *is*
possible.

Thank you,

Tim Clark
DB2 for IBM i / SQL Optimizer


"MIDRANGE-L" <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> wrote on 12/01/2021
05:19:36 PM:

From: "Charles Wilt" <charles.wilt@xxxxxxxxx>
To: "Midrange Systems Technical Discussion"
<midrange-l@xxxxxxxxxxxxxxxxxx>,
Date: 12/01/2021 05:20 PM
Subject: [EXTERNAL] Re: SQL View vs CTE
Sent by: "MIDRANGE-L" <midrange-l-bounces@xxxxxxxxxxxxxxxxxx>

Greg,

IBM'ers have always told me that a view is performance neutral, is that
no
longer the case?

Or is it really the difference between having the SELECT <whaterver>
inside
or outside a CTE?

To clarify:
--case 1
with cte1 as (SELECT1)
, cte2 as (select <...> from cte1 join <...>)
<...>

--case 2
create view myview as (SELECT1);

with cte1 as (select from myview)
, cte2 as (select <...> from cte1 join <...>)
<...>

--case 3
create view myview as (SELECT1);

with cte2 as (select <...> from myview join <...>)
<...>

Could there be a difference between case 1 & 2, or is it only if at all
in
case 3?

Thanks,
Charles



On Wed, Dec 1, 2021 at 3:36 PM Timothy P Clark <timclark@xxxxxxxxxx>
wrote:

Hi Greg,

The answer is a solid "maybe"... Although from an end-user perspective
a
CTE and a view can help to solve the same problem (i.e. separating a
complex query into manageable pieces), they have slightly different
semantics from an SQL language perspective. As a result, the optimizer
may
end up implementing them somewhat differently. Without knowing more
details about the query and seeing the VE, it's impossible to say for
sure
whether a view would improve performance, but it is worth a try.

Thank you,

Tim Clark
DB2 for IBM i / SQL Optimizer

"MIDRANGE-L" <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> wrote on
12/01/2021
03:24:58 PM:

From: "Greg Wilburn" <gwilburn@xxxxxxxxxxxxxxxxxxxxxxx>
To: "Midrange Systems Technical Discussion"
<midrange-l@xxxxxxxxxxxxxxxxxx>,
Date: 12/01/2021 03:25 PM
Subject: [EXTERNAL] SQL View vs CTE
Sent by: "MIDRANGE-L" <midrange-l-bounces@xxxxxxxxxxxxxxxxxx>

I have a complex SQL statement that I'm going to use as a data
source for a browser application. In ACS Run SQL scripts it
consistently takes about 22 seconds to run. The statement contains
a CTE followed by a join to the CTE. The files involved have a
large number of records.

So I'm wondering if someone can tell me whether creating an SQL View
in place of the CTE would yield any performance increase (I haven't
spent much time looking at the Visual Explain in ACS).
I'm thinking it wouldn't make much difference.

TIA
Greg
[Logo]<INVALID URI REMOVED
u=https-3A__www.totalbizfulfillment.com_&d=DwICAg&c=jf_iaSHvJObTbx-




siA1ZOg&r=oCmVbiwufH6yM8U29GriOcB5LKDoEG8y1HZD-01RVtc&m=WBKqmJteet6e501ZLxcZk-

_9XSXrAi-Zgz0os-kr7fk&s=K4gHcy_mh6pHQ0nK-cjRjUGSHzMi_rDbnJrM52kdql0&e=
Greg Wilburn
Director of IT
301.895.3792 ext. 1231
301.895.3895 direct
gwilburn@xxxxxxxxxxxxxxxxxxxxxxx<
mailto:gwilburn@xxxxxxxxxxxxxxxxxxxxxxx

1 Corporate Dr
Grantsville, MD 21536
www.totalbizfulfillment.com<https://urldefense.proofpoint.com/v2/
url?
u=http-3A__www.totalbizfulfillment.com&d=DwICAg&c=jf_iaSHvJObTbx-




siA1ZOg&r=oCmVbiwufH6yM8U29GriOcB5LKDoEG8y1HZD-01RVtc&m=WBKqmJteet6e501ZLxcZk-

_9XSXrAi-Zgz0os-kr7fk&s=pvTy86UcIeCfu8fWED6C0xlgFHnoWkEXt6jWSP1yQMY&e= >





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.