Transpose a table by converting columns to rows
Asked Answered
I

5

44

I have a PostgreSQL function (or table) which gives me the following output:

Sl.no    username    Designation    salary   etc..
 1        A           XYZ            10000    ...
 2        B           RTS            50000    ...
 3        C           QWE            20000    ...
 4        D           HGD            34343    ...

Now I want the Output as below:

Sl.no            1       2        3       4       ...
 Username        A       B        C       D       ...
 Designation     XYZ     RTS      QWE     HGD     ...
 Salary          10000   50000    20000   34343   ...

How to do this?

Inae answered 29/12, 2012 at 18:7 Comment(4)
I think https://mcmap.net/q/28892/-transpose-column-headers-to-rows-in-postgresql is what you're looking for.Salvador
Have a look at the contrib module "tablefunc" it contains a "crosstab" function which should do what you want.Unjaundiced
Hey buddy, what have you tried anyways?Ephram
hi i have not yet tried the crosstab function ......but I have tried the answers which are given below but still looking for something more.Inae
N
39

Basing my answer on a table of the form:

CREATE TABLE tbl (
  sl_no int
, username text
, designation text
, salary int
);

Each row results in a new column to return. With a dynamic return type like this, it's hardly possible to make this completely dynamic with a single call to the database. Demonstrating solutions with two steps:

  1. Generate query
  2. Execute generated query

Generally, this is limited by the maximum number of columns a table can hold. So not an option for tables with more than 1600 rows (or fewer). Details:

Postgres 9.4+

Dynamic solution with crosstab()

Use the first one if you can. Beats the rest.

SELECT 'SELECT *
FROM   crosstab(
       $ct$SELECT u.attnum, t.rn, u.val
        FROM  (SELECT row_number() OVER () AS rn, * FROM '
                              || attrelid::regclass || ') t
             , unnest(ARRAY[' || string_agg(quote_ident(attname)
                              || '::text', ',') || '])
                 WITH ORDINALITY u(val, attnum)
        ORDER  BY 1, 2$ct$
   ) t (attnum bigint, '
     || (SELECT string_agg('r'|| rn ||' text', ', ')
         FROM  (SELECT row_number() OVER () AS rn FROM tbl) t)
     || ')' AS sql
FROM   pg_attribute
WHERE  attrelid = 'tbl'::regclass
AND    attnum > 0
AND    NOT attisdropped
GROUP  BY attrelid;

Operating with attnum instead of actual column names. Simpler and faster. Join the result to pg_attribute once more or integrate column names like in the pg 9.3 example.
Generates a query of the form:

SELECT *
FROM   crosstab(
   $ct$
   SELECT u.attnum, t.rn, u.val
   FROM  (SELECT row_number() OVER () AS rn, * FROM tbl) t
       , unnest(ARRAY[sl_no::text,username::text,designation::text,salary::text]) WITH ORDINALITY u(val, attnum)
   ORDER  BY 1, 2$ct$
   ) t (attnum bigint, r1 text, r2 text, r3 text, r4 text);

This uses a whole range of advanced features. Just too much to explain.

Simple solution with unnest()

One unnest() can now take multiple arrays to unnest in parallel.

SELECT 'SELECT * FROM unnest(
  ''{sl_no, username, designation, salary}''::text[]
, ' || string_agg(quote_literal(ARRAY[sl_no::text, username::text, designation::text, salary::text])
              || '::text[]', E'\n, ')
    || E') \n AS t(col,' || string_agg('row' || sl_no, ',') || ')' AS sql
FROM   tbl;

Result:

SELECT * FROM unnest(
 '{sl_no, username, designation, salary}'::text[]
,'{10,Joe,Music,1234}'::text[]
,'{11,Bob,Movie,2345}'::text[]
,'{12,Dave,Theatre,2356}'::text[])
 AS t(col,row1,row2,row3,row4);

db<>fiddle here
Old sqlfiddle

Postgres 9.3 or older

Dynamic solution with crosstab()

  • Completely dynamic, works for any table. Provide the table name in two places:
SELECT 'SELECT *
FROM   crosstab(
       ''SELECT unnest(''' || quote_literal(array_agg(attname))
                           || '''::text[]) AS col
             , row_number() OVER ()
             , unnest(ARRAY[' || string_agg(quote_ident(attname)
                              || '::text', ',') || ']) AS val
        FROM   ' || attrelid::regclass || '
        ORDER  BY generate_series(1,' || count(*) || '), 2''
   ) t (col text, '
     || (SELECT string_agg('r'|| rn ||' text', ',')
         FROM (SELECT row_number() OVER () AS rn FROM tbl) t)
     || ')' AS sql
FROM   pg_attribute
WHERE  attrelid = 'tbl'::regclass
AND    attnum > 0
AND    NOT attisdropped
GROUP  BY attrelid;

Could be wrapped into a function with a single parameter ...
Generates a query of the form:

SELECT *
FROM   crosstab(
       'SELECT unnest(''{sl_no,username,designation,salary}''::text[]) AS col
             , row_number() OVER ()
             , unnest(ARRAY[sl_no::text,username::text,designation::text,salary::text]) AS val
        FROM   tbl
        ORDER  BY generate_series(1,4), 2'
   ) t (col text, r1 text,r2 text,r3 text,r4 text);

Produces the desired result:

col         r1    r2      r3     r4
-----------------------------------
sl_no       1      2      3      4
username    A      B      C      D
designation XYZ    RTS    QWE    HGD
salary      10000  50000  20000  34343

Simple solution with unnest()

SELECT 'SELECT unnest(''{sl_no, username, designation, salary}''::text[] AS col)
     , ' || string_agg('unnest('
                    || quote_literal(ARRAY[sl_no::text, username::text, designation::text, salary::text])
                    || '::text[]) AS row' || sl_no, E'\n     , ') AS sql
FROM   tbl;
  • Slow for tables with more than a couple of columns.

Generates a query of the form:

SELECT unnest('{sl_no, username, designation, salary}'::text[]) AS col
     , unnest('{10,Joe,Music,1234}'::text[]) AS row1
     , unnest('{11,Bob,Movie,2345}'::text[]) AS row2
     , unnest('{12,Dave,Theatre,2356}'::text[]) AS row3
     , unnest('{4,D,HGD,34343}'::text[]) AS row4

Same result.

Neptune answered 30/12, 2012 at 0:32 Comment(6)
This is great ... haven't quite figured it out yet though :). NB the "dynamic solution with crosstabs" doesn't work when the column names have special characters in them.Aegospotami
@shaunc: It should work for any column names, since they are escaped with quote_ident(attname). (But you best don't have special characters in column names to begin with.)Neptune
Try create table tbl ("'" int); insert into tbl select 1; then run the snippet -- the resulting sql is not executable as the single quote in the quoted sql for crosstab is unescaped. NB "best don't have special characters" -- if only it was my dataset. :)Aegospotami
changing quote_ident(attname) to btrim(quote_literal(quote_ident(attname)), '''') gets that working... though now I get ERROR invalid return type: DETAIL: SQL rowid datatype does not match return rowid datatype.Aegospotami
@shaunc: I see, you are right. The problem is with the outer layer of quotes. I replaced the single quotes with dollar quoting. To defend against any possible folly in column names, you can concatenate the string argument for crosstab() and escape it with format() or quote_literal(). Also changed to attnum bigint since WITH ORDINALITY returns bigint. All that aside: never use single quotes in identifiers, that's a loaded footgun.Neptune
Is it possible to configure the first solution to work with CTEs instead of a table?Czardas
B
43
SELECT
   unnest(array['Sl.no', 'username', 'Designation','salary']) AS "Columns",
   unnest(array[Sl.no, username, value3Count,salary]) AS "Values"
FROM view_name
ORDER BY "Columns"

Reference : convertingColumnsToRows

Bandurria answered 29/12, 2012 at 18:34 Comment(1)
+ this is the best imoWinfrid
N
39

Basing my answer on a table of the form:

CREATE TABLE tbl (
  sl_no int
, username text
, designation text
, salary int
);

Each row results in a new column to return. With a dynamic return type like this, it's hardly possible to make this completely dynamic with a single call to the database. Demonstrating solutions with two steps:

  1. Generate query
  2. Execute generated query

Generally, this is limited by the maximum number of columns a table can hold. So not an option for tables with more than 1600 rows (or fewer). Details:

Postgres 9.4+

Dynamic solution with crosstab()

Use the first one if you can. Beats the rest.

SELECT 'SELECT *
FROM   crosstab(
       $ct$SELECT u.attnum, t.rn, u.val
        FROM  (SELECT row_number() OVER () AS rn, * FROM '
                              || attrelid::regclass || ') t
             , unnest(ARRAY[' || string_agg(quote_ident(attname)
                              || '::text', ',') || '])
                 WITH ORDINALITY u(val, attnum)
        ORDER  BY 1, 2$ct$
   ) t (attnum bigint, '
     || (SELECT string_agg('r'|| rn ||' text', ', ')
         FROM  (SELECT row_number() OVER () AS rn FROM tbl) t)
     || ')' AS sql
FROM   pg_attribute
WHERE  attrelid = 'tbl'::regclass
AND    attnum > 0
AND    NOT attisdropped
GROUP  BY attrelid;

Operating with attnum instead of actual column names. Simpler and faster. Join the result to pg_attribute once more or integrate column names like in the pg 9.3 example.
Generates a query of the form:

SELECT *
FROM   crosstab(
   $ct$
   SELECT u.attnum, t.rn, u.val
   FROM  (SELECT row_number() OVER () AS rn, * FROM tbl) t
       , unnest(ARRAY[sl_no::text,username::text,designation::text,salary::text]) WITH ORDINALITY u(val, attnum)
   ORDER  BY 1, 2$ct$
   ) t (attnum bigint, r1 text, r2 text, r3 text, r4 text);

This uses a whole range of advanced features. Just too much to explain.

Simple solution with unnest()

One unnest() can now take multiple arrays to unnest in parallel.

SELECT 'SELECT * FROM unnest(
  ''{sl_no, username, designation, salary}''::text[]
, ' || string_agg(quote_literal(ARRAY[sl_no::text, username::text, designation::text, salary::text])
              || '::text[]', E'\n, ')
    || E') \n AS t(col,' || string_agg('row' || sl_no, ',') || ')' AS sql
FROM   tbl;

Result:

SELECT * FROM unnest(
 '{sl_no, username, designation, salary}'::text[]
,'{10,Joe,Music,1234}'::text[]
,'{11,Bob,Movie,2345}'::text[]
,'{12,Dave,Theatre,2356}'::text[])
 AS t(col,row1,row2,row3,row4);

db<>fiddle here
Old sqlfiddle

Postgres 9.3 or older

Dynamic solution with crosstab()

  • Completely dynamic, works for any table. Provide the table name in two places:
SELECT 'SELECT *
FROM   crosstab(
       ''SELECT unnest(''' || quote_literal(array_agg(attname))
                           || '''::text[]) AS col
             , row_number() OVER ()
             , unnest(ARRAY[' || string_agg(quote_ident(attname)
                              || '::text', ',') || ']) AS val
        FROM   ' || attrelid::regclass || '
        ORDER  BY generate_series(1,' || count(*) || '), 2''
   ) t (col text, '
     || (SELECT string_agg('r'|| rn ||' text', ',')
         FROM (SELECT row_number() OVER () AS rn FROM tbl) t)
     || ')' AS sql
FROM   pg_attribute
WHERE  attrelid = 'tbl'::regclass
AND    attnum > 0
AND    NOT attisdropped
GROUP  BY attrelid;

Could be wrapped into a function with a single parameter ...
Generates a query of the form:

SELECT *
FROM   crosstab(
       'SELECT unnest(''{sl_no,username,designation,salary}''::text[]) AS col
             , row_number() OVER ()
             , unnest(ARRAY[sl_no::text,username::text,designation::text,salary::text]) AS val
        FROM   tbl
        ORDER  BY generate_series(1,4), 2'
   ) t (col text, r1 text,r2 text,r3 text,r4 text);

Produces the desired result:

col         r1    r2      r3     r4
-----------------------------------
sl_no       1      2      3      4
username    A      B      C      D
designation XYZ    RTS    QWE    HGD
salary      10000  50000  20000  34343

Simple solution with unnest()

SELECT 'SELECT unnest(''{sl_no, username, designation, salary}''::text[] AS col)
     , ' || string_agg('unnest('
                    || quote_literal(ARRAY[sl_no::text, username::text, designation::text, salary::text])
                    || '::text[]) AS row' || sl_no, E'\n     , ') AS sql
FROM   tbl;
  • Slow for tables with more than a couple of columns.

Generates a query of the form:

SELECT unnest('{sl_no, username, designation, salary}'::text[]) AS col
     , unnest('{10,Joe,Music,1234}'::text[]) AS row1
     , unnest('{11,Bob,Movie,2345}'::text[]) AS row2
     , unnest('{12,Dave,Theatre,2356}'::text[]) AS row3
     , unnest('{4,D,HGD,34343}'::text[]) AS row4

Same result.

Neptune answered 30/12, 2012 at 0:32 Comment(6)
This is great ... haven't quite figured it out yet though :). NB the "dynamic solution with crosstabs" doesn't work when the column names have special characters in them.Aegospotami
@shaunc: It should work for any column names, since they are escaped with quote_ident(attname). (But you best don't have special characters in column names to begin with.)Neptune
Try create table tbl ("'" int); insert into tbl select 1; then run the snippet -- the resulting sql is not executable as the single quote in the quoted sql for crosstab is unescaped. NB "best don't have special characters" -- if only it was my dataset. :)Aegospotami
changing quote_ident(attname) to btrim(quote_literal(quote_ident(attname)), '''') gets that working... though now I get ERROR invalid return type: DETAIL: SQL rowid datatype does not match return rowid datatype.Aegospotami
@shaunc: I see, you are right. The problem is with the outer layer of quotes. I replaced the single quotes with dollar quoting. To defend against any possible folly in column names, you can concatenate the string argument for crosstab() and escape it with format() or quote_literal(). Also changed to attnum bigint since WITH ORDINALITY returns bigint. All that aside: never use single quotes in identifiers, that's a loaded footgun.Neptune
Is it possible to configure the first solution to work with CTEs instead of a table?Czardas
C
15

If (like me) you were needing this information from a bash script, note there is a simple command-line switch for psql to tell it to output table columns as rows:

psql mydbname -x -A -F= -c "SELECT * FROM foo WHERE id=123"

The -x option is the key to getting psql to output columns as rows.

Cimbri answered 16/3, 2016 at 18:57 Comment(1)
From within psql you can toggle "Expanded display" using \xHierarchize
B
9

I have a simpler approach than Erwin pointed above, that worked for me with Postgres (and I think that it should work with all major relational databases whose support SQL standard)

You can use simply UNION instead of crosstab:

SELECT text 'a' AS "text" UNION SELECT 'b';

 text
------
 a
 b
(2 rows)

Of course that depends on the case in which you are going to apply this. Considering that you know beforehand what fields you need, you can take this approach even for querying different tables. I.e.:

SELECT 'My first metric' as name, count(*) as total from first_table UNION
SELECT 'My second metric' as name, count(*) as total from second_table 

 name             | Total
------------------|--------
 My first metric  |     10
 My second metric |     20
(2 rows)

It's a more maintainable approach, IMHO. Look at this page for more information: https://www.postgresql.org/docs/current/typeconv-union-case.html

Bergschrund answered 5/2, 2019 at 17:21 Comment(0)
S
1

There is no proper way to do this in plain SQL or PL/pgSQL.

It will be way better to do this in the application, that gets the data from the DB.

Sushi answered 29/12, 2012 at 19:0 Comment(0)

© 2022 - 2024 — McMap. All rights reserved.