Re: Converting Rows to Columns

From: Ian Barwick <barwick(at)gmail(dot)com>
To: Joshua Berry <yoberi(at)gmail(dot)com>
Cc: pgsql-general(at)postgresql(dot)org
Subject: Re: Converting Rows to Columns
Date: 2009-05-05 15:01:38
Message-ID: 1d581afe0905050801kc6454ccm41a212eb7ac8311@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

2009/5/5 Joshua Berry <yoberi(at)gmail(dot)com>:
> Greetings all,
> I know that this is an elementary question, so I'm just asking for a pointer
> in the right direction.
> I have a query like this that tries to link Retail shops (from the table
> aliased as 'a') to sales reps (from the table aliased as 'e') that service
> the given Retail shop:
> select a.id_pdv, e.apellido ||', ' || e.nombre as seller_name from tbl_pdvs
> a join tbl_circuitos b using (id_circuito) join tbl_frecuencias c on
> b.id_circuito = c.id_circuito join tbl_rutas d on c.id_ruta = d.id_ruta join
> tbl_vendedores e on d.vendedor = e.id_vendedor order by a.id_pdv limit 4;
>
>  id_pdv  |   seller_name
> ---------+-------------------
>  1000001 | COLON, CRISTOBOL
>  1000001 | LOPEZ, CARLOS
>  1000002 | COLON, CRISTOBOL
>  1000002 | LUGO, FERNANDO
>
> As you can see, there are two salesmen that service this shop.
> What I need is to be able to create a report that has each unique id_pdv as
> a row of the result set, with three columns available to show up to three
> salemen that are assigned to the route.
> So this would give something like this:
>  id_pdv  |  seller_name1    | seller_name2   | seller_name3
> ---------+------------------+----------------+----------------
>  1000001 | COLON, CRISTOBOL | LOPEZ, CARLOS  | (\N or '')
>  1000002 | COLON, CRISTOBOL | LUGO, FERNANDO | (\N or '')
>
> Note that the order of the sellers does not matter.
> Any tips? I've googled 'sql convert rows to columns' and got some results
> that appear to be mssql specific. On Stackoverflow there is an example of
> how to convert columns to rows using UNION, but not visa versa.

Quick and dirty solution off the top of my head for the problem described:

CREATE TABLE salesperson (
id SERIAL PRIMARY KEY,
name TEXT
);

CREATE TABLE salesperson_store (
salesperson_id INT NOT NULL,
store_id INT NOT NULL,
PRIMARY KEY (salesperson_id, store_id)
);

INSERT INTO salesperson VALUES
(1, 'COLON, CRISTOBOL'),
(2, 'OPEZ, CARLOS'),
(3, 'LUGO, FERNANDO');

INSERT INTO salesperson_store VALUES
(1, 1000001),
(1, 1000002),
(2, 1000001),
(3, 1000002);

SELECT store_id,
(SELECT sp.name FROM salesperson sp
INNER JOIN salesperson_store sps
ON sp.id=sps.salesperson_id
AND sps.store_id=store.store_id
ORDER BY sp.name LIMIT 1 OFFSET 0)
AS seller_name1,
(SELECT sp.name FROM salesperson sp
INNER JOIN salesperson_store sps
ON sp.id=sps.salesperson_id
AND sps.store_id=store.store_id
ORDER BY sp.name LIMIT 1 OFFSET 1)
AS seller_name2,
(SELECT sp.name FROM salesperson sp
INNER JOIN salesperson_store sps
ON sp.id=sps.salesperson_id
AND sps.store_id=store.store_id
ORDER BY sp.name LIMIT 1 OFFSET 2)
AS seller_name3
FROM (SELECT DISTINCT(store_id) FROM salesperson_store) store
ORDER BY store_id;

store_id | seller_name1 | seller_name2 | seller_name3
----------+------------------+----------------+--------------
1000001 | COLON, CRISTOBOL | OPEZ, CARLOS |
1000002 | COLON, CRISTOBOL | LUGO, FERNANDO |
(2 rows)

(No doubt there are probably more elegant ways of doing this)

HTH

Ian Barwick

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Andreas Kretschmer 2009-05-05 15:04:59 Re: Converting Rows to Columns
Previous Message Relyea, Mike 2009-05-05 14:53:04 Re: Converting Rows to Columns