Thread: Skip Orderby Execution for Materialized Views

Skip Orderby Execution for Materialized Views

From
Zhang Mingli
Date:
Hi, all


When create  or refresh a Materialized View, if the view’s query has order by, we may sort and insert the sorted data into view.

Create Materialized View mv1 as select c1, c2 from t1 order by c2;
Refresh Materialized View mv1;

And it appears that we could get ordered data  when select from Materialized View;

Select * from mv1;

But it’s not true if we use other access methods, or we choose a parallel seqscan plan.
A non-parallel seqscan on heap table appears ordered as we always create new rel file and swap them, in my opinion, it’s more like a free lunch.

So, conclusion1:  We couldn’t rely on the `ordered-data` even the mv’s sql has order by clause, is it right?

And if it’s true, shall we skip the order by clause for Materialized View  when executing create/refresh statement?

Materialized View’s order by clause could be skipped if 
  1. Order by clause is on the top query level
  2. There is no real limit clause
The benefit is the query may be speeded up without sort nodes each time creating/refreshing Materialized View.


A simple results:

create table t1 as select i as c1 , i/2 as c2 , i/5 as c3 from generate_series(1, 100000) i;
create materialized view mvt1_order as select c1, c2, c3 from t1 order by c2, c3, c1 asc

Without this patch: 
zml=# refresh materialized view mvt1_order;
REFRESH MATERIALIZED VIEW
Time: 228.548 ms
zml=# refresh materialized view mvt1_order;
REFRESH MATERIALIZED VIEW
Time: 230.374 ms
zml=# refresh materialized view mvt1_order;
REFRESH MATERIALIZED VIEW
Time: 217.079 ms


With this patch:

zml=# refresh materialized view mvt1_order;
REFRESH MATERIALIZED VIEW
Time: 192.409 ms
zml=# refresh materialized view mvt1_order;
REFRESH MATERIALIZED VIEW
Time: 204.398 ms
zml=# refresh materialized view mvt1_order;
REFRESH MATERIALIZED VIEW
Time: 197.510 ms



Zhang Mingli
www.hashdata.xyz
Attachment

Re: Skip Orderby Execution for Materialized Views

From
Tom Lane
Date:
Zhang Mingli <zmlpostgres@gmail.com> writes:
> When create  or refresh a Materialized View, if the view’s query has order by, we may sort and insert the sorted data
intoview. 

Indeed.

> And if it’s true, shall we skip the order by clause for Materialized View  when executing create/refresh statement?

No.  The intent of a materialized view is to execute the query
as presented.  If the user doesn't understand the consequences
of that, it's not our job to think we are smarter than they are.

I think this patch should be rejected.

BTW, I'm pretty certain that this patch breaks some valid cases
even if we take your point of view as correct.  For one example,
you can't just remove the sort clause if the query uses DISTINCT ON.

            regards, tom lane



Re: Skip Orderby Execution for Materialized Views

From
Zhang Mingli
Date:
HI,

On Oct 1, 2023, at 22:54, Tom Lane <tgl@sss.pgh.pa.us> wrote:

 For one example,
you can't just remove the sort clause if the query uses DISTINCT ON

Hi, Tom, got it, thanks, 

Zhang Mingli
HashData https://www.hashdata.xyz

Re: Skip Orderby Execution for Materialized Views

From
"David G. Johnston"
Date:
On Sun, Oct 1, 2023 at 8:57 AM Zhang Mingli <zmlpostgres@gmail.com> wrote:
And if it’s true, shall we skip the order by clause for Materialized View  when executing create/refresh statement?

We tend to do precisely what the user writes into their query.  If they don't want an order by they can remove it.  I don't see any particular reason we should be second-guessing them here. And what makes the trade-off worse is the reasonable expectation that we'd provide a way to force an ordering of the inserts should the user actually want it after we defaulted to ignoring that part of their query.

But yes, you are correct that adding an order by to a materialized view is typically pointless.  To the extent it is detrimental varies since even partially ordered results can save on processing time.

David J.