Thread: Selecting rows as if they were columns?

Selecting rows as if they were columns?

From
Kurt Overberg
Date:
Gang,

I've got what I think should be a pretty simple problem- I just can't 
figure out how I'd do it.  Heck, I can't even figure out how I'd search 
for an answer to this problem.

I've got 2 tables: member and member_attr

Member is just a standard entry for a member.  Very simple:

table member {
id    integer,
name  character varying(30)
}

Member_attr is just a table of name/value pairs, such as:


table memberextra {
memberid     integer,
param1       character varying(512),
param2       character varying(512),
}

where param1 is the name, param2 is the value.

Right now, I can:

select member.id, member.name, member_attr.param1, member_attr.param2 
from member, member_attr where member.id = member_attr.memberid;

...this gives me n rows per member where n = # of attributes for that 
member, like this:

id   |  name   |   param1    |  param2
=======================================
1    |  dave   |  home       |  /home/dave
1    |  dave   |  testing    |  1
2    |  john   |  home       |  /home/john

...is there some way to make this return like this:

id  |  name    |     home   |  testing
======================================
1   |  dave    | /home/dave |  1
2   |  john    | /home/john |

...where it sort of "expands" the rows out into columns?  Am I just 
going about this the wrong way?  Thoughts on the subject would be 
greatly appreciated.

thanks!

/kurt



Re: Selecting rows as if they were columns?

From
Harald Fuchs
Date:
In article <3F855F38.9070803@hotdogrecords.com>,
Kurt Overberg <kurt@hotdogrecords.com> writes:

> Gang,
> I've got what I think should be a pretty simple problem- I just can't
> figure out how I'd do it.  Heck, I can't even figure out how I'd
> search for an answer to this problem.


> I've got 2 tables: member and member_attr

> Member is just a standard entry for a member.  Very simple:

> table member {
> id    integer,
> name  character varying(30)
> }

> Member_attr is just a table of name/value pairs, such as:


> table memberextra {
> memberid     integer,
> param1       character varying(512),
> param2       character varying(512),
> }

> where param1 is the name, param2 is the value.

> Right now, I can:

> select member.id, member.name, member_attr.param1, member_attr.param2
> from member, member_attr where member.id = member_attr.memberid;


> ...this gives me n rows per member where n = # of attributes for that
> member, like this:


> id   |  name   |   param1    |  param2
> =======================================
> 1    |  dave   |  home       |  /home/dave
> 1    |  dave   |  testing    |  1
> 2    |  john   |  home       |  /home/john

> ...is there some way to make this return like this:

> id  |  name    |     home   |  testing
> ======================================
> 1   |  dave    | /home/dave |  1
> 2   |  john    | /home/john |

> ...where it sort of "expands" the rows out into columns?  Am I just
> going about this the wrong way?  Thoughts on the subject would be
> greatly appreciated.

This should work fine as long as you know all possible values of
param1 in advance:

SELECT m.id, m.name, m1.param2, m2.param2
FROM member m
LEFT JOIN memberextra m1 ON m1.memberid = m.id AND m1.param1 = 'home'
LEFT JOIN memberextra m2 ON m2.memberid = m.id AND m2.param1 = 'testing'



Re: Selecting rows as if they were columns?

From
Josh Berkus
Date:
Kurt,

> I've got what I think should be a pretty simple problem- I just can't
> figure out how I'd do it.  Heck, I can't even figure out how I'd search
> for an answer to this problem.

This is an old common SQL problem ... the "crosstab" table.   There are 3 
standard ways to solve it, depending on the exact circumstances of your case.   
It's probably best if you buy Joe Celko's "SQL for Smarties, 2nd Ed.", which 
has a 50-page chapter on the topic and explores the methods in detail.

-- 
Josh Berkus
Aglio Database Solutions
San Francisco


Re: Selecting rows as if they were columns?

From
Richard Huxton
Date:
On Thursday 09 October 2003 18:14, Josh Berkus wrote:
> Kurt,
>
> > I've got what I think should be a pretty simple problem- I just can't
> > figure out how I'd do it.  Heck, I can't even figure out how I'd search
> > for an answer to this problem.
>
> This is an old common SQL problem ... the "crosstab" table.   There are 3
> standard ways to solve it, depending on the exact circumstances of your
> case. It's probably best if you buy Joe Celko's "SQL for Smarties, 2nd
> Ed.", which has a 50-page chapter on the topic and explores the methods in
> detail.

Or see the contrib/tablefunc functions which can do this sort of thing for 
you.

--  Richard Huxton Archonet Ltd