Re: SQL syntax for concating values in different rows together - Mailing list pgsql-sql

From Joe Conway
Subject Re: SQL syntax for concating values in different rows together
Date
Msg-id 3DF6330D.1090900@joeconway.com
Whole thread Raw
In response to SQL syntax for concating values in different rows together  ("Elizabeth O'Neill's Office Mail" <elizabeth.oneill@abcmail.co.uk>)
List pgsql-sql
Elizabeth O'Neill's Office Mail wrote:
> I have two tables in my database a complaint table and a resolution table.
> One complaint may have several resolutions. I am trying to build a report
> that will give me the complaint details and all the resolution descriptions
> for a complaint in one text area/row (concated together).
> 
> At the moment it is repeating the complaint details for each resolution.

As someone else mentioned I think, you can use a plpgsql function. Here is a 
contrived example:

create table complaint(cid int, descr text);
insert into complaint values(1,'my #1 complaint');
insert into complaint values(2,'my #2 complaint');
create table resolution(rid int, cid int, res text);
insert into resolution values (1,1,'fixed it');
insert into resolution values (2,1,'really fixed it!');
insert into resolution values (3,2,'pbkbac again');

create or replace function my_concat(int) returns text as'
declare  ret text;  comp text;  rec record;  cntr int = 0;
begin  select into comp descr from complaint where cid = $1;  ret := ''Comp = '' || comp;  for rec in select res from
resolutionwhere cid = $1 loop    cntr := cntr + 1;    ret := ret || '': Res# '' || cntr::text || '' = '' || rec.res;
endloop;  return ret;
 
end;
' language 'plpgsql';

regression=# select my_concat(cid) from complaint;                              my_concat
---------------------------------------------------------------------- Comp = my #1 complaint: Res# 1 = fixed it: Res#
2= really fixed it! Comp = my #2 complaint: Res# 1 = pbkbac again
 
(2 rows)

In the past I think I remember someone trying to solve this kind of problem 
with a custom aggregate, but the plpgsql approach is probably simpler.

HTH,

Joe



pgsql-sql by date:

Previous
From: "mark carew"
Date:
Subject: Re: import sql script
Next
From: "jack"
Date:
Subject: is numeric relational operator problem fixed in v7.3