阐明
此性能只在测试环境论证过,没有在生产环境论证,如需应用,请自行评估危险
HAWQ 版本
PostgreSQL 8.2.15 (Greenplum Database 4.2.0 build 1) (HAWQ 2.4.0.0 build dev) on x86_64-unknown-linux-gnu, compiled by GCC gcc (G
CC) 4.8.5 20150623 (Red Hat 4.8.5-39) compiled on Mar 28 2020 17:33:50
获取和编译 tablefunc
>$ mkdir -p /home/demo/tablefunc
>$ cd /home/demo/tablefunc
>$ wget https://ftp.postgresql.org/pub/source/v8.2.15/postgresql-8.2.15.tar.gz
>$ tar zxvf postgresql-8.2.15.tar.gz
tablefunc 装置
>$ source /usr/local/hawq/greenplum_path.sh
>$ cd /home/demo/tablefunc/postgresql-8.2.15/contrib/tablefunc
>$ make USE_PGXS=1 install
gcc -O3 -std=gnu99 -Wall -Wmissing-prototypes -Wpointer-arith -Wendif-labels -Wformat-security -fno-strict-aliasing -fwrapv -fno-aggressive-loop-optimizations -I/usr/include/libxml2 -fpic -I. -I/usr/local/hawq.my_rh7.x/include/postgresql/server -I/usr/local/hawq.my_rh7.x/include/postgresql/internal -D_GNU_SOURCE -I/opt/script/hawq-9c7ca3c2ce0b825c7236eaf208abf2475d9c992f/depends/libhdfs3/build/install/include -I/opt/script/hawq-9c7ca3c2ce0b825c7236eaf208abf2475d9c992f/depends/libyarn/build/install/include -c -o tablefunc.o tablefunc.c
gcc -O3 -std=gnu99 -Wall -Wmissing-prototypes -Wpointer-arith -Wendif-labels -Wformat-security -fno-strict-aliasing -fwrapv -fno-aggressive-loop-optimizations -I/usr/include/libxml2 -fpic -L/usr/local/hawq.my_rh7.x/lib -L/usr/local/hawq.my_rh7.x/lib -Wl,--as-needed -L/opt/script/hawq-9c7ca3c2ce0b825c7236eaf208abf2475d9c992f/depends/libhdfs3/build/install/lib -L/opt/script/hawq-9c7ca3c2ce0b825c7236eaf208abf2475d9c992f/depends/libyarn/build/install/lib -Wl,-rpath,'/usr/local/hawq.my_rh7.x/lib',--enable-new-dtags -shared -o tablefunc.so tablefunc.o
/bin/sh /usr/local/hawq.my_rh7.x/lib/postgresql/pgxs/src/makefiles/../../config/install-sh -c -m 644 ./uninstall_tablefunc.sql '/usr/local/hawq.my_rh7.x/share/postgresql/contrib'
/bin/sh /usr/local/hawq.my_rh7.x/lib/postgresql/pgxs/src/makefiles/../../config/install-sh -c -m 644 tablefunc.sql '/usr/local/hawq.my_rh7.x/share/postgresql/contrib'
/bin/sh /usr/local/hawq.my_rh7.x/lib/postgresql/pgxs/src/makefiles/../../config/install-sh -c -m 755 tablefunc.so '/usr/local/hawq.my_rh7.x/lib/postgresql'
/bin/sh /usr/local/hawq.my_rh7.x/lib/postgresql/pgxs/src/makefiles/../../config/install-sh -c -m 644 ./README.tablefunc '/usr/local/hawq.my_rh7.x/docs/contrib'
rm tablefunc.o
tablefunc.so 包发送到其余机器
>$ gpscp -f all_nomaster /usr/local/hawq/lib/postgresql/tablefunc.so =:/usr/local/hawq/lib/postgresql/
>$ gpssh -f all_nomaster "chmod 755 /usr/local/hawq/lib/postgresql/tablefunc.so"
>$ psql postgres -f /usr/local/hawq/share/postgresql/contrib/tablefunc.sql
行列转换
测试表
create table score(
name varchar,
subject varchar,
score bigint
);
测试数据
insert into score values
('Lucy','English',100),
('Lucy','Physics',90),
('Lucy','Math',85),
('Lily','English',76),
('Lily','Physics',57),
('Lily','Math',86),
('David','English',57),
('David','Physics',86),
('David','Math',100),
('Simon','English',88),
('Simon','Physics',99),
('Simon','Math',65);
原数据查问
select * from score;
name | subject | score
-------+---------+-------
Lucy | English | 100
Lucy | Physics | 90
Lucy | Math | 85
Lily | English | 76
Lily | Physics | 57
Lily | Math | 86
David | English | 57
David | Physics | 86
David | Math | 100
Simon | English | 88
Simon | Physics | 99
Simon | Math | 65
(12 rows)
sql 规范实现
select name,
sum(case when subject='English' then score else 0 end) as "English",
sum(case when subject='Physics' then score else 0 end) as "Physics",
sum(case when subject='Math' then score else 0 end) as "Math"
from score
group by name order by name desc;
name | English | Physics | Math
-------+---------+---------+------
Simon | 88 | 99 | 65
Lucy | 100 | 90 | 85
Lily | 76 | 57 | 86
David | 57 | 86 | 100
(4 rows)
postgres 内嵌函数实现
select * from
crosstab('select name,subject,score from score order by name desc', --name: 分组规范,subject: 聚合规范,score: 聚合规范下通过计算的值
$$values('English'::text),('Physics'::text),('Math'::text)$$
)
as score(name text,English bigint,Physics bigint,Math bigint); -- 显示字段 name,English,Physics,Math [name 是分组规范;English,Physics,Math 是聚合规范产生的字段名]
name | english | physics | math
-------+---------+---------+------
Simon | 88 | 99 | 65
Lucy | 100 | 90 | 85
Lily | 76 | 57 | 86
David | 57 | 86 | 100
(4 rows)
报错汇总
报错
/usr/local/hawq/include/postgresql/server/storage/fd.h:61:23: 致命谬误:hdfs/hdfs.h:没有那个文件或目录
#include "hdfs/hdfs.h"
^
编译中断。make: *** [tablefunc.o] 谬误 1
解决办法
文件中 /usr/local/hawq.my_rh7.x/include/postgresql/server/storage/fd.h
将
#include "hdfs/hdfs.h"
替换成
#include "/usr/local/hawq.my_rh7.x/include/hdfs/hdfs.h"
参考:
http://www.bubuko.com/infodet…