Re: Seeking help with a query....

Поиск
Список
Период
Сортировка
От Christoph Haller
Тема Re: Seeking help with a query....
Дата
Msg-id 3E7F14A5.EBB5EB9@rodos.fzk.de
обсуждение исходный текст
Ответ на Seeking help with a query....  ("Dan Winslow" <danwinslow@cox.net>)
Список pgsql-sql
>
> Hi folks, seeking help with a query that I thought was simple, but
> apparantly isn't, at least for someone with my knowledge level.
>
> Given a table :
>
> create table atable (
>   code1 char,
>   code2 char,
>   cost    int
> );
>
> And the rows
>
> code1    code2    cost
> -----------------------------
> a            b            2
> d            e            4
> b            a            6
> f            g            1
>
> I need a ( preferably single ) query that will sum the costs for any
> matching pairs of codes regardless of order. That is, row 1 and row 3
> concern the same pair of unordered codes (a,b), and the result should
show
> that the (a,b) pair had a summed cost of 8. I am not able to change
any of
> the environment or preconditions other than the query itself. I have
tried
> so many approaches that they aren't even worth listing. Any
suggestions
> would be very much appreciated.
>
My approach is inspired by PostgreSQL 7.3 Set Returning Functions by
Stephan Szabo
( http://techdocs.postgresql.org/guides/SetReturningFunctions )

Use a set returning function to get ordered pairs and do a group by then
as

create type aholder as ( code1 char, code2 char, cost    int
);

create or replace function aordered() returns setof aholder as '
declare
myrow aholder%ROWTYPE;
codex char;
begin
for myrow in select code1,code2,cost from atable
loop
if myrow.code1 > myrow.code2 thencodex := myrow.code1;myrow.code1 := myrow.code2;myrow.code2 := codex;
end if;
return next myrow;
end loop;
return;
end ' language 'plpgsql';

select code1,code2,sum(cost) from aordered() group by code1,code2 ;code1 | code2 | sum
-------+-------+-----a     | b     |   8d     | e     |   4f     | g     |   1
(3 rows)

In addition if you want only matching pairs (eliminate single pairs) try

create or replace function amatched() returns setof aholder as '
declare
myrow aholder%ROWTYPE;
codex char;
begin
for myrow in select t1.code1,t1.code2,t1.cost from atable t1,atable t2where t1.code1=t2.code2 and t1.code2=t2.code1
loop
if myrow.code1 > myrow.code2 thencodex := myrow.code1;myrow.code1 := myrow.code2;myrow.code2 := codex;
end if;
return next myrow;
end loop;
return;
end ' language 'plpgsql';

select code1,code2,sum(cost) from amatched() group by code1,code2 ;code1 | code2 | sum
-------+-------+-----a     | b     |   8
(1 row)

Hope this helps.
Regards, Christoph



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

Предыдущее
От: "Correia, Carla"
Дата:
Сообщение: Re: Complex outer joins?
Следующее
От: Andreas Pflug
Дата:
Сообщение: UPDATE FROM portability