Re: recursive sql

From: Samed YILDIRIM <samed(at)reddoc(dot)net>
To: "ml(at)ft-c(dot)de" <ml(at)ft-c(dot)de>, "pgsql-sql(at)lists(dot)postgresql(dot)org" <pgsql-sql(at)lists(dot)postgresql(dot)org>
Subject: Re: recursive sql
Date: 2020-08-09 12:08:57
Message-ID: 187651596974558@mail.yandex.com.tr
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

<div>Hi Frank,</div><div> </div><div>It seems I need to read more carefully :)</div><div> </div><div>With window functions;</div><div><div><div>pgsql-sql=# select *,sum(c) over (order by ts) from tt;</div><div>ts | c | sum</div><div>---------------------+---+-----</div><div>2019-12-31 00:00:00 | 1 | 1</div><div>2020-01-01 00:00:00 | 2 | 3</div><div>2020-07-02 00:00:00 | 3 | 6</div><div>2020-07-06 00:00:00 | 4 | 10</div><div>2020-07-07 00:00:00 | 5 | 15</div><div>2020-07-08 00:00:00 | 6 | 21</div><div>(6 rows)</div><div> </div><div><br />With recursive query:</div></div><div><div>pgsql-sql=# with recursive rc as (</div><div>select * from (select ts,c,c as c2 from tt order by ts asc limit 1) sq1</div><div>union</div><div>select * from (select tt.ts,tt.c,tt.c+rc.c2 as c2 from tt, lateral (select * from rc order by ts desc limit 1) rc where tt.ts &gt; rc.ts order by tt.ts asc limit 1) sq2</div><div>)</div><div>select * from rc;</div><div>ts | c | c2</div><div>---------------------+---+----</div><div>2019-12-31 00:00:00 | 1 | 1</div><div>2020-01-01 00:00:00 | 2 | 3</div><div>2020-07-02 00:00:00 | 3 | 6</div><div>2020-07-06 00:00:00 | 4 | 10</div><div>2020-07-07 00:00:00 | 5 | 15</div><div>2020-07-08 00:00:00 | 6 | 21</div><div>(6 rows)</div></div></div><div> </div><div>Best regards.</div><div>Samed YILDIRIM</div><div> </div><div> </div><div> </div><div>09.08.2020, 14:57, "ml(at)ft-c(dot)de" &lt;ml(at)ft-c(dot)de&gt;:</div><blockquote><p>Hallo,<br /><br />with the window function lag there is a shift of one or more rows. Every<br />row connects to the previous row := lag(column,1).<br /><br />What I am looking for:<br />ts c c2<br />.. 1 1 -- or null in the first row<br />.. 2 3 -- it is the result of 1 + 2<br />.. 3 6 -- it is the result of 3 + 3<br />.. 4 10 -- it is the result of 6 + 4<br /><br /><br />Franz<br /><br />On 8/9/20 12:38 PM, Samed YILDIRIM wrote:</p><blockquote> Hi Franz,<br /> Simply you can use window functions[1][2].<br /> pgsql-sql=# select *, lag(c) over (order by ts) as c2 from tt;<br /> ts | c | c2<br /> ---------------------+---+----<br /> 2019-12-31 00:00:00 | 1 |<br /> 2020-01-01 00:00:00 | 2 | 1<br /> 2020-07-02 00:00:00 | 3 | 2<br /> 2020-07-06 00:00:00 | 4 | 3<br /> 2020-07-07 00:00:00 | 5 | 4<br /> 2020-07-08 00:00:00 | 6 | 5<br /> (6 rows)<br /> I personally prefer to use window functions due to their simplicity. If<br /> you still want to use recursive query: [3]<br /> pgsql-sql=# with recursive rc as (<br /> select * from (select ts,c,null::numeric as c2 from tt order by ts asc<br /> limit 1) k1<br /> union<br /> select * from (select tt.ts,tt.c,rc.c as c2 from tt, lateral (select *<br /> from rc) rc where tt.ts &gt; rc.ts order by tt.ts asc limit 1) k2<br /> )<br /> select * from rc;<br /> ts | c | c2<br /> ---------------------+---+----<br /> 2019-12-31 00:00:00 | 1 |<br /> 2020-01-01 00:00:00 | 2 | 1<br /> 2020-07-02 00:00:00 | 3 | 2<br /> 2020-07-06 00:00:00 | 4 | 3<br /> 2020-07-07 00:00:00 | 5 | 4<br /> 2020-07-08 00:00:00 | 6 | 5<br /> (6 rows)<br /> [1]: <a href="https://www.postgresql.org/docs/12/functions-window.html">https://www.postgresql.org/docs/12/functions-window.html</a><br /> [2]: <a href="https://www.postgresql.org/docs/12/tutorial-window.html">https://www.postgresql.org/docs/12/tutorial-window.html</a><br /> [3]: <a href="https://www.postgresql.org/docs/12/queries-with.html">https://www.postgresql.org/docs/12/queries-with.html</a><br /> Best regards.<br /> Samed YILDIRIM<br /> 09.08.2020, 09:29, "<a href="mailto:ml(at)ft-c(dot)de">ml(at)ft-c(dot)de</a>" &lt;<a href="mailto:ml(at)ft-c(dot)de">ml(at)ft-c(dot)de</a>&gt;:<br /> <br />     Hello,<br /> <br />     the table<br />     create table tt (<br />         ts timestamp,<br />         c numeric) ;<br /> <br />     insert into tt values<br />        ('2019-12-31',1), ('2020-01-01',2),<br />        ('2020-07-02',3), ('2020-07-06',4),<br />        ('2020-07-07',5), ('2020-07-08',6);<br /> <br />     My question: It is possible to get an<br />         additional column (named c2)<br />         with<br />         ( c from current row ) + ( c2 from the previous row ) as c2<br /> <br />     the result:<br />     ts c c2<br />     .. 1 1 -- or null in the first row<br />     .. 2 3<br />     .. 3 6<br />     .. 4 10<br />     ...<br /> <br />     with recursive ema as ()<br />     select ts, c,<br />         -- many many computed_rows<br />         -- &lt;code&gt; as c2<br />     from tt -- &lt;- I need tt on this place<br /> <br /> <br />     thank you for help<br />     Franz<br /> </blockquote><p><br /> </p></blockquote>

Attachment Content-Type Size
unknown_filename text/html 4.7 KB

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Igor Andriychuk 2020-08-09 12:18:03 Re: recursive sql
Previous Message ml 2020-08-09 11:57:43 Re: recursive sql