Re: proposal: window function - change_number

Поиск
Список
Период
Сортировка
От Rémi Cura
Тема Re: proposal: window function - change_number
Дата
Msg-id CAJvUf_smqKnqY5ZiFVS8+kuWfZhM+WqMbLVkeEYvJbS93FSqYA@mail.gmail.com
обсуждение исходный текст
Ответ на Re: proposal: window function - change_number  (Andrew Gierth <andrew@tao11.riddles.org.uk>)
Ответы Re: proposal: window function - change_number  (Pavel Stehule <pavel.stehule@gmail.com>)
Список pgsql-hackers
Hey, sorry I what I say is obvious for you .

If I understood your problem correctly, it is strictly equivalent to this one :
http://postgresql.1045698.n5.nabble.com/Count-of-records-in-a-row-td5775363.html

there is a postgres trick to solve this problem :
what you want is essentially generate a unique group_id,
but one that depends of an order of row not defined in the group.

The solution
is to generate a row number by the order you want , then a row number by the group ,
then a subtraction of the 2 row number gives you an unique id per group.

The cost is that you have to use 2 windows function., hence 2 scans I guess.

Cheers,
Rémi-C

2014-09-21 17:51 GMT+02:00 Andrew Gierth <andrew@tao11.riddles.org.uk>:
>>>>> "Pavel" == Pavel Stehule <pavel.stehule@gmail.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)


--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers

В списке pgsql-hackers по дате отправления:

Предыдущее
От: Andrew Gierth
Дата:
Сообщение: Re: proposal: window function - change_number
Следующее
От: Pavel Stehule
Дата:
Сообщение: Re: proposal: window function - change_number