Re: proposal: window function - change_number

From: Andrew Gierth <andrew(at)tao11(dot)riddles(dot)org(dot)uk>
To: Pavel Stehule <pavel(dot)stehule(at)gmail(dot)com>
Cc: PostgreSQL Hackers <pgsql-hackers(at)postgresql(dot)org>
Subject: Re: proposal: window function - change_number
Date: 2014-09-21 15:51:34
Message-ID: 87d2apm2q2.fsf@news-spur.riddles.org.uk
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-hackers

>>>>> "Pavel" == Pavel Stehule <pavel(dot)stehule(at)gmail(dot)com> writes:

Pavel> Hi
Pavel> I tried to solve following task:

Pavel> I have a table

Pavel> start, reason, km
Pavel> =============
Pavel> 2014-01-01 08:00:00, private, 10
Pavel> 2014-01-01 09:00:00, commerc, 20
Pavel> 2014-01-01 10:00:00, commerc, 20
Pavel> 2014-01-01 11:00:00, private, 8

Pavel> and I would reduce these rows to

Pavel> 2014-01-01 08:00:00, private, 10
Pavel> 2014-01-01 09:00:00, commerc, 20 + 20 = 40
Pavel> 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
is distinct from
lag(reason) over (order by start)
then start
end as label_time
from yourtable
) s2
) s1
group by start_time, reason
order by 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)

In response to

Responses

Browse pgsql-hackers by date

  From Date Subject
Next Message Rémi Cura 2014-09-21 16:08:02 Re: proposal: window function - change_number
Previous Message Pavel Stehule 2014-09-21 15:20:28 Re: proposal: window function - change_number