Re: Window function for get the last value to extend missing rows - Mailing list pgsql-general
From | Andrew Gierth |
---|---|
Subject | Re: Window function for get the last value to extend missing rows |
Date | |
Msg-id | 87ilcwg4gm.fsf@news-spur.riddles.org.uk Whole thread Raw |
In response to | Window function for get the last value to extend missing rows (Durumdara <durumdara@gmail.com>) |
Responses |
Re: Window function for get the last value to extend missing rows
|
List | pgsql-general |
>>>>> "Durumdara" == Durumdara <durumdara@gmail.com> writes: Durumdara> I have to make a virtual table which is minute based. Durumdara> I thought I would make a generated temp table Durumdara> (generate_series) and then join these values based on minue. Durumdara> 03:00 10 Durumdara> 03:01 NULL Durumdara> 03:02 12 Durumdara> 03:03 11 Durumdara> 03:04 NULL Durumdara> 03:05 13 Durumdara> I need a code to replace the value to the last value on Durumdara> NULL. It is possible to do this, even without the IGNORE NULLS option for window functions, but it's somewhat awkward. Someone else already mentioned using generate_series in lateral position to fill in values; in most cases this is probably the best approach, though it requires a little care. There is also a window function approach based on using the non-null values to delimit partitions: create table tmp_test_table(mmin,val) as select o, v from unnest(array[1,5,NULL,3,NULL,NULL,10,7,NULL,NULL,NULL,4]) with ordinality as u(v,o); select * from tmp_test_table order by mmin; mmin | val ------+----- 1 | 1 2 | 5 3 | 4 | 3 5 | 6 | 7 | 10 8 | 7 9 | 10 | 11 | 12 | 4 (12 rows) First we take advantage of the fact that mmin is increasing to generate a distinguishing value for each block of nulls: select *, max(case when val is not null then mmin end) over (order by mmin) as grp from tmp_test_table order by mmin; mmin | val | grp ------+-----+----- 1 | 1 | 1 2 | 5 | 2 3 | | 2 4 | 3 | 4 5 | | 4 6 | | 4 7 | 10 | 7 8 | 7 | 8 9 | | 8 10 | | 8 11 | | 8 12 | 4 | 12 (12 rows) Then we can fill in the missing vals by using the fact that there is at most one non-null val in each group: select *, max(val) over (partition by grp) as val2 from (select *, max(case when val is not null then mmin end) over (order by mmin) as grp from tmp_test_table) s order by mmin; mmin | val | grp | val2 ------+-----+-----+------ 1 | 1 | 1 | 1 2 | 5 | 2 | 5 3 | | 2 | 5 4 | 3 | 4 | 3 5 | | 4 | 3 6 | | 4 | 3 7 | 10 | 7 | 10 8 | 7 | 8 | 7 9 | | 8 | 7 10 | | 8 | 7 11 | | 8 | 7 12 | 4 | 12 | 4 (12 rows) This _really_ isn't efficient, though; you end up with typically three sorts of the data. For a one-off operation or for generating a materialized view it might be acceptable. -- Andrew (irc:RhodiumToad)
pgsql-general by date: