Re: proposal: window function - change_number
| От | Andrew Gierth |
|---|---|
| Тема | Re: proposal: window function - change_number |
| Дата | |
| Msg-id | 87d2apm2q2.fsf@news-spur.riddles.org.uk обсуждение исходный текст |
| Ответ на | proposal: window function - change_number (Pavel Stehule <pavel.stehule@gmail.com>) |
| Ответы |
Re: proposal: window function - change_number
Re: proposal: window function - change_number |
| Список | pgsql-hackers |
>>>>> "Pavel" == Pavel Stehule <pavel.stehule@gmail.com> writes:
Pavel> HiPavel> I tried to solve following task:
Pavel> I have a table
Pavel> start, reason, kmPavel> =============Pavel> 2014-01-01 08:00:00, private, 10Pavel> 2014-01-01 09:00:00,
commerc,20Pavel> 2014-01-01 10:00:00, commerc, 20Pavel> 2014-01-01 11:00:00, private, 8
Pavel> and I would reduce these rows to
Pavel> 2014-01-01 08:00:00, private, 10Pavel> 2014-01-01 09:00:00, commerc, 20 + 20 = 40Pavel> 2014-01-01 11:00:00,
private,8
Pavel> It is relative hard to it now with SQL only.
Only relatively. My standard solution is something like this:
select start_time, reason, sum(km) as km from (select max(label_time) over (order by start) as start_time,
reason,km from (select start, reason, km, case when reason
isdistinct from lag(reason) over (order by start) then start
end as label_time from yourtable ) s2 ) s1group by start_time,
reasonorderby start_time;
(Your change_number idea is essentially equivalent to doing
sum(case when x is distinct from lag(x) over w then 1 end) over w,
except that since window functions can't be nested, that expression
requires a subquery.)
--
Andrew (irc:RhodiumToad)
В списке pgsql-hackers по дате отправления: