POSTGRESQL交叉表的实现

时间:2021-03-20 22:56:50
这里我来演示下在POSTGRESQL里面如何实现交叉表的展示,至于什么是交叉表,我就不多说了,度娘去哦。
原始表数据如下:
t_girl=# select * from score; name  | subject | score 
-------+---------+-------
Lucy | English | 100
Lucy | Physics | 90
Lucy | Math | 85
Lily | English | 95
Lily | Physics | 81
Lily | Math | 84
David | English | 100
David | Physics | 86
David | Math | 89
Simon | English | 90
Simon | Physics | 76
Simon | Math | 79
(12 rows)


Time: 2.066 ms




想要实现以下的结果:
 name  | English | Physics | Math -------+---------+---------+------ Simon |      90 |      76 |   79 Lucy  |     100 |      90 |   85 Lily  |      95 |      81 |   84 David |     100 |      86 |   89




大致有以下几种方法:


1、用标准SQL展现出来
t_girl=# select name, t_girl-#  sum(case when subject = 'English' then score else 0 end) as "English",t_girl-#  sum(case when subject = 'Physics' then  score else 0 end) as "Physics",t_girl-#  sum(case when subject = 'Math'   then score else 0 end) as "Math" t_girl-#  from scoret_girl-#  group by name order by name desc; name  | English | Physics | Math -------+---------+---------+------ Simon |      90 |      76 |   79 Lucy  |     100 |      90 |   85 Lily  |      95 |      81 |   84 David |     100 |      86 |   89(4 rows)Time: 1.123 ms




2、用PostgreSQL 提供的第三方扩展 tablefunc 带来的函数实现
以下函数crosstab 里面的SQL必须有三个字段,name, 分类以及分类值来作为起始参数,必须以name,分类值作为输出参数。
t_girl=# SELECT *FROM crosstab('select name,subject,score from score order by name desc',$$values ('English'::text),('Physics'::text),('Math'::text)$$)AS score(name text, English int, Physics int, Math int); name  | english | physics | math -------+---------+---------+------ Simon |      90 |      76 |   79 Lucy  |     100 |      90 |   85 Lily  |      95 |      81 |   84 David |     100 |      86 |   89(4 rows)Time: 2.059 ms




3、用PostgreSQL 自身的聚合函数实现

t_girl=# select name,split_part(split_part(tmp,',',1),':',2) as "English",t_girl-# split_part(split_part(tmp,',',2),':',2) as "Physics",t_girl-# split_part(split_part(tmp,',',3),':',2) as "Math"t_girl-# fromt_girl-# (t_girl(# select name,string_agg(subject||':'||score,',') as tmp from score group by name order by name desct_girl(# ) as T; name  | English | Physics | Math -------+---------+---------+------ Simon | 90      | 76      | 79 Lucy  | 100     | 90      | 85 Lily  | 95      | 81      | 84 David | 100     | 86      | 89(4 rows)Time: 2.396 ms






4、 存储函数实现

create or replace function func_ytt_crosstab_py ()returns setof ytt_crosstabas $ytt$  for row in plpy.cursor("select name,string_agg(subject||':'||score,',') as tmp from score group by name order by name desc"):      a = row['tmp'].split(',')      yield (row['name'],a[0].split(':')[1],a[1].split(':')[1],a[2].split(':')[1])$ytt$ language plpythonu;t_girl=# select name,english,physics,math from  func_ytt_crosstab_py(); name  | english | physics | math -------+---------+---------+------ Simon | 90      | 76      | 79 Lucy  | 100     | 90      | 85 Lily  | 95      | 81      | 84 David | 100     | 86      | 89(4 rows)Time: 2.687 ms




5、 用PLPGSQL来实现

t_girl=# create type ytt_crosstab as (name text, English text, Physics text, Math text);CREATE TYPETime: 22.518 mscreate or replace function func_ytt_crosstab ()returns setof ytt_crosstabas $ytt$  declare v_name text := '';                v_english text := '';v_physics text := '';v_math text := '';v_tmp_result text := '';  declare cs1 cursor for select name,string_agg(subject||':'||score,',') from score group by name order by name desc;begin  open cs1;  loop    fetch cs1 into v_name,v_tmp_result;    exit when not found;    v_english = split_part(split_part(v_tmp_result,',',1),':',2);    v_physics = split_part(split_part(v_tmp_result,',',2),':',2);    v_math = split_part(split_part(v_tmp_result,',',3),':',2);    return query select v_name,v_english,v_physics,v_math;  end loop;end;$ytt$ language plpgsql;t_girl=# select name,English,Physics,Math from func_ytt_crosstab(); name  | english | physics | math -------+---------+---------+------ Simon | 90      | 76      | 79 Lucy  | 100     | 90      | 85 Lily  | 95      | 81      | 84 David | 100     | 86      | 89(4 rows)Time: 2.127 ms