Re: Add RESPECT/IGNORE NULLS and FROM FIRST/LAST options

From: Krasiyan Andreev <krasiyan(at)gmail(dot)com>
To: Tatsuo Ishii <ishii(at)postgresql(dot)org>
Cc: ojford(at)gmail(dot)com, tgl(at)sss(dot)pgh(dot)pa(dot)us, vik(at)postgresfriends(dot)org, pgsql-hackers(at)postgresql(dot)org, andrew(at)tao11(dot)riddles(dot)org(dot)uk, david(at)fetter(dot)org
Subject: Re: Add RESPECT/IGNORE NULLS and FROM FIRST/LAST options
Date: 2025-01-23 06:08:39
Message-ID: CAN1PwokSDfSkOmDk6sfdEOUz_mTm333-gkLOBPK=JrVsMJFZ1g@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-hackers

Hi,
I was able to reproduce exactly the problem, with clean compile
and --enable-cassert:
test=# SELECT x,y,lead(y) IGNORE NULLS OVER (ORDER BY x) FROM
(VALUES(1,NULL),(2,2),(3,NULL)) AS v(x,y);
x | y | lead
---+---+------
1 | | 2
2 | 2 | 2
3 | | 2
(3 rows)

test=#
Also, make check errors out at window test (without --enable-cassert it was
passed in previous compile):
krasiyan(at)fedora:~/pgsql-src/postgresql$ cat
/home/krasiyan/pgsql-src/postgresql/src/test/regress/regression.diffs
diff -U3
/home/krasiyan/pgsql-src/postgresql/src/test/regress/expected/window.out
/home/krasiyan/pgsql-src/postgresql/src/test/regress/results/window.out
---
/home/krasiyan/pgsql-src/postgresql/src/test/regress/expected/window.out
2025-01-22 21:25:47.114508215 +0200
+++ /home/krasiyan/pgsql-src/postgresql/src/test/regress/results/window.out
2025-01-23 07:58:26.784659592 +0200
@@ -5477,12 +5477,12 @@
name | orbit | lead | lead_respect | lead_ignore
---------+-------+-------+--------------+-------------
earth | | 4332 | 4332 | 4332
- jupiter | 4332 | | | 88
+ jupiter | 4332 | | |
mars | | 88 | 88 | 88
mercury | 88 | 60182 | 60182 | 60182
neptune | 60182 | 90560 | 90560 | 90560
pluto | 90560 | 24491 | 24491 | 24491
- saturn | 24491 | | | 224
+ saturn | 24491 | | |
uranus | | 224 | 224 | 224
venus | 224 | | |
xyzzy | | | |
@@ -5577,13 +5577,13 @@
name | orbit | first_value | last_value | nth_value | lead_ignore |
lag_ignore
---------+-------+-------------+------------+-----------+-------------+------------
earth | | 4332 | 4332 | | 4332 |

- jupiter | 4332 | 88 | 88 | | 88 |

- mars | | 4332 | 60182 | 88 | 88 |
4332
- mercury | 88 | 4332 | 90560 | 60182 | 60182 |
4332
+ jupiter | 4332 | 88 | 88 | | 60182 |

+ mars | | 88 | 60182 | 60182 | 60182 |
4332
+ mercury | 88 | 4332 | 90560 | 90560 | 90560 |
4332
neptune | 60182 | 88 | 24491 | 90560 | 90560 |
88
- pluto | 90560 | 88 | 24491 | 60182 | 24491 |
60182
- saturn | 24491 | 60182 | 224 | 90560 | 224 |
90560
- uranus | | 90560 | 224 | 24491 | 224 |
24491
+ pluto | 90560 | 88 | 24491 | 60182 | 60182 |
60182
+ saturn | 24491 | 60182 | 224 | 90560 | 90560 |
90560
+ uranus | | 90560 | 224 | 24491 | 24491 |
24491
venus | 224 | 24491 | 24491 | | |
24491
xyzzy | | 224 | 224 | | |
224
(10 rows)
@@ -5646,14 +5646,14 @@
name | orbit | first_value | last_value | nth_value | lead_ignore |
lag_ignore
---------+-------+-------------+------------+-----------+-------------+------------
earth | | | | | 88 |

- jupiter | | 88 | 88 | | 88 |

- mars | | 88 | 60182 | 60182 | 88 |

+ jupiter | | 88 | 88 | | 60182 |

+ mars | | 88 | 60182 | 60182 | 60182 |

mercury | 88 | 88 | 90560 | 60182 | 60182 |

- neptune | 60182 | 88 | 24491 | 60182 | 90560 |
88
- pluto | 90560 | 88 | 24491 | 60182 | 24491 |
60182
- saturn | 24491 | 60182 | 224 | 90560 | 224 |
90560
- uranus | | 90560 | 224 | 24491 | 224 |
24491
- venus | 224 | 24491 | 224 | 224 | |
24491
+ neptune | 60182 | 88 | 24491 | 60182 | 60182 |
88
+ pluto | 90560 | 88 | 24491 | 60182 | 60182 |
60182
+ saturn | 24491 | 60182 | 224 | 90560 | 90560 |
90560
+ uranus | | 90560 | 224 | 24491 | 24491 |
24491
+ venus | 224 | 24491 | 224 | 224 | 224 |
24491
xyzzy | | 224 | 224 | | |
224
(10 rows)

На чт, 23.01.2025 г. в 6:25 Tatsuo Ishii <ishii(at)postgresql(dot)org> написа:

> > Hello,
> > I also played with the v4 patch and it produces correct result:
> > test=# SELECT x,y,lead(y) IGNORE NULLS OVER (ORDER BY x) FROM
> > (VALUES(1,NULL),(2,2),(3,NULL)) AS v(x,y);
> > x | y | lead
> > ---+---+------
> > 1 | | 2
> > 2 | 2 |
> > 3 | |
> > (3 rows)
> >
> > test=#
> > It is from today's git, clean compile and install with only v4 patch
> > applied, make check also passes without errors.
>
> I guess you are just lucky. In my case I enabled --enable-cassert to
> build PostgreSQL and it automatically turn on CLOBBER_FREED_MEMORY and
> freed memory area is scrambled. If I look the patch closer, I found a
> problem:
>
> +void
> +WinCheckAndInitializeNullTreatment(WindowObject winobj,
> :
> :
> + winobj->win_nonnulls = palloc_array(int64, 16);
>
> WinCheckAndInitializeNullTreatment is called in each built-in window
> function. Window functions are called in the per tuple memory context,
> which means win_nonnulls disappears when next tuple is supplied to the
> window function. If my understanding is correct, winobj->win_nonnulls
> needs to survive across processing tuples.
>
> Best reagards,
> --
> Tatsuo Ishii
> SRA OSS K.K.
> English: http://www.sraoss.co.jp/index_en/
> Japanese:http://www.sraoss.co.jp
>

In response to

Responses

Browse pgsql-hackers by date

  From Date Subject
Next Message Tatsuo Ishii 2025-01-23 06:27:41 Re: Add RESPECT/IGNORE NULLS and FROM FIRST/LAST options
Previous Message Peter Smith 2025-01-23 05:47:38 Re: Pgoutput not capturing the generated columns