Re: [SQL] value from max row in group by

2013-07-26 Thread Gary Stainburn
Sorry, but I never thought.

I'm developing this on my server I'm developing it for someone else who wants 
it in a WordPress / MySQL environment (I don't know MySQL).

Would this or something similar work in mysql?

(Sorry for going O.T.)

On Thursday 25 July 2013 19:53:06 Marc Mamin wrote:
 
 Von: pgsql-sql-ow...@postgresql.org [pgsql-sql-ow...@postgresql.org]quot;
  im Auftrag von quot;Venky Kandaswamy [ve...@adchemy.com]
 
 You can use Postgres WINDOW functions for this in several different ways.
  For example, one way of doing it:
 
 select stts_id,   last_value(stts_offset) over (partition by stts_id order
  by stts_offset desc) + last_value(stts_duration) over (partition by
  stts_id order by stts_offset desc) from table
 group by stts_id;

 another simple solution with distinct on:

 select distinct on (stts_id, stts_offset) stts_id,
 stts_offset+stts_duration from table
 order by stts_id, stts_offset desc

 Marc Mamin


-- 
Gary Stainburn
Group I.T. Manager
Ringways Garages
http://www.ringways.co.uk 


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


Re: [SQL] value from max row in group by

2013-07-25 Thread Gary Stainburn
As usual, once I've asked the question, I find the answer myself.

However, it *feels* like there should be a more efficient way. Can anyone 
comment or suggest a better method?

timetable= select stts_id, stts_offset+stts_duration as total_duration 
timetable- from standard_trip_sections 
timetable- where (stts_id, stts_offset) in 
timetable- (select stts_id, max(stts_offset) from standard_trip_sections 
group by stts_id);
 stts_id | total_duration 
-+
   1 | 01:35:00
   2 | 01:35:00
   3 | 01:08:00
   4 | 01:38:00
   5 | 01:03:00
   6 | 01:06:00
(6 rows)

timetable= 


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


Re: [SQL] value from max row in group by

2013-07-25 Thread bricklen
On Thu, Jul 25, 2013 at 10:45 AM, Gary Stainburn 
gary.stainb...@ringways.co.uk wrote:

 Hi folks,

 I need help please.

 I have a table of trip section details which includes a trip ID, start
 time as
 an offset, and a duration for that section.

 I need to extract the full trip duration by adding the highest offset to
 it's
 duration. I can't simply use sum() on the duation as that would not include
 standing time.

 Using the data below I would like to get:

 1  | 01:35:00
 2  | 01:35:00
 3  | 01:06:00
 4  | 01:38:00
 5  | 01:03:00
 6  | 01:06:00


How about using a WINDOW function?

Eg.

select  stts_id, total
from (select stts_id, stts_offset+stts_duration as total, row_number() over
(partition by stts_id order by stts_offset desc) as rank from sts) s
where rank = 1
order by stts_id;


Re: [SQL] value from max row in group by

2013-07-25 Thread Venky Kandaswamy
You can use Postgres WINDOW functions for this in several different ways. For 
example, one way of doing it:

select stts_id,   last_value(stts_offset) over (partition by stts_id order by 
stts_offset desc) 
   + last_value(stts_duration) over (partition by stts_id order 
by stts_offset desc)
from table
group by stts_id;



Venky Kandaswamy

Principal Engineer, Adchemy Inc.

925-200-7124


From: pgsql-sql-ow...@postgresql.org pgsql-sql-ow...@postgresql.org on behalf 
of Gary Stainburn gary.stainb...@ringways.co.uk
Sent: Thursday, July 25, 2013 10:57 AM
To: pgsql-sql@postgresql.org
Subject: Re: [SQL] value from max row in group by

As usual, once I've asked the question, I find the answer myself.

However, it *feels* like there should be a more efficient way. Can anyone
comment or suggest a better method?

timetable= select stts_id, stts_offset+stts_duration as total_duration
timetable- from standard_trip_sections
timetable- where (stts_id, stts_offset) in
timetable- (select stts_id, max(stts_offset) from standard_trip_sections
group by stts_id);
 stts_id | total_duration
-+
   1 | 01:35:00
   2 | 01:35:00
   3 | 01:08:00
   4 | 01:38:00
   5 | 01:03:00
   6 | 01:06:00
(6 rows)

timetable=


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


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


Re: [SQL] value from max row in group by

2013-07-25 Thread Marc Mamin


Von: pgsql-sql-ow...@postgresql.org [pgsql-sql-ow...@postgresql.org]quot; im 
Auftrag von quot;Venky Kandaswamy [ve...@adchemy.com]

You can use Postgres WINDOW functions for this in several different ways. For 
example, one way of doing it:

select stts_id,   last_value(stts_offset) over (partition by stts_id order by 
stts_offset desc)
  + last_value(stts_duration) over (partition by stts_id order 
 by stts_offset desc)
from table
group by stts_id;

another simple solution with distinct on:

select distinct on (stts_id, stts_offset) stts_id, stts_offset+stts_duration
from table
order by stts_id, stts_offset desc

Marc Mamin


From: pgsql-sql-ow...@postgresql.org pgsql-sql-ow...@postgresql.org on behalf 
of Gary Stainburn gary.stainb...@ringways.co.uk
Sent: Thursday, July 25, 2013 10:57 AM
To: pgsql-sql@postgresql.org
Subject: Re: [SQL] value from max row in group by

As usual, once I've asked the question, I find the answer myself.

However, it *feels* like there should be a more efficient way. Can anyone
comment or suggest a better method?

timetable= select stts_id, stts_offset+stts_duration as total_duration
timetable- from standard_trip_sections
timetable- where (stts_id, stts_offset) in
timetable- (select stts_id, max(stts_offset) from standard_trip_sections
group by stts_id);
 stts_id | total_duration
-+
   1 | 01:35:00
   2 | 01:35:00
   3 | 01:08:00
   4 | 01:38:00
   5 | 01:03:00
   6 | 01:06:00
(6 rows)

timetable=


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


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


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