1\set HIDE_TOAST_COMPRESSION false 2 3-- ensure we get stable results regardless of installation's default 4SET default_toast_compression = 'pglz'; 5 6-- test creating table with compression method 7CREATE TABLE cmdata(f1 text COMPRESSION pglz); 8CREATE INDEX idx ON cmdata(f1); 9INSERT INTO cmdata VALUES(repeat('1234567890', 1000)); 10\d+ cmdata 11CREATE TABLE cmdata1(f1 TEXT COMPRESSION lz4); 12INSERT INTO cmdata1 VALUES(repeat('1234567890', 1004)); 13\d+ cmdata1 14 15-- verify stored compression method in the data 16SELECT pg_column_compression(f1) FROM cmdata; 17SELECT pg_column_compression(f1) FROM cmdata1; 18 19-- decompress data slice 20SELECT SUBSTR(f1, 200, 5) FROM cmdata; 21SELECT SUBSTR(f1, 2000, 50) FROM cmdata1; 22 23-- copy with table creation 24SELECT * INTO cmmove1 FROM cmdata; 25\d+ cmmove1 26SELECT pg_column_compression(f1) FROM cmmove1; 27 28-- copy to existing table 29CREATE TABLE cmmove3(f1 text COMPRESSION pglz); 30INSERT INTO cmmove3 SELECT * FROM cmdata; 31INSERT INTO cmmove3 SELECT * FROM cmdata1; 32SELECT pg_column_compression(f1) FROM cmmove3; 33 34-- test LIKE INCLUDING COMPRESSION 35CREATE TABLE cmdata2 (LIKE cmdata1 INCLUDING COMPRESSION); 36\d+ cmdata2 37DROP TABLE cmdata2; 38 39-- try setting compression for incompressible data type 40CREATE TABLE cmdata2 (f1 int COMPRESSION pglz); 41 42-- update using datum from different table 43CREATE TABLE cmmove2(f1 text COMPRESSION pglz); 44INSERT INTO cmmove2 VALUES (repeat('1234567890', 1004)); 45SELECT pg_column_compression(f1) FROM cmmove2; 46UPDATE cmmove2 SET f1 = cmdata1.f1 FROM cmdata1; 47SELECT pg_column_compression(f1) FROM cmmove2; 48 49-- test externally stored compressed data 50CREATE OR REPLACE FUNCTION large_val() RETURNS TEXT LANGUAGE SQL AS 51'select array_agg(md5(g::text))::text from generate_series(1, 256) g'; 52CREATE TABLE cmdata2 (f1 text COMPRESSION pglz); 53INSERT INTO cmdata2 SELECT large_val() || repeat('a', 4000); 54SELECT pg_column_compression(f1) FROM cmdata2; 55INSERT INTO cmdata1 SELECT large_val() || repeat('a', 4000); 56SELECT pg_column_compression(f1) FROM cmdata1; 57SELECT SUBSTR(f1, 200, 5) FROM cmdata1; 58SELECT SUBSTR(f1, 200, 5) FROM cmdata2; 59DROP TABLE cmdata2; 60 61--test column type update varlena/non-varlena 62CREATE TABLE cmdata2 (f1 int); 63\d+ cmdata2 64ALTER TABLE cmdata2 ALTER COLUMN f1 TYPE varchar; 65\d+ cmdata2 66ALTER TABLE cmdata2 ALTER COLUMN f1 TYPE int USING f1::integer; 67\d+ cmdata2 68 69--changing column storage should not impact the compression method 70--but the data should not be compressed 71ALTER TABLE cmdata2 ALTER COLUMN f1 TYPE varchar; 72ALTER TABLE cmdata2 ALTER COLUMN f1 SET COMPRESSION pglz; 73\d+ cmdata2 74ALTER TABLE cmdata2 ALTER COLUMN f1 SET STORAGE plain; 75\d+ cmdata2 76INSERT INTO cmdata2 VALUES (repeat('123456789', 800)); 77SELECT pg_column_compression(f1) FROM cmdata2; 78 79-- test compression with materialized view 80CREATE MATERIALIZED VIEW compressmv(x) AS SELECT * FROM cmdata1; 81\d+ compressmv 82SELECT pg_column_compression(f1) FROM cmdata1; 83SELECT pg_column_compression(x) FROM compressmv; 84 85-- test compression with partition 86CREATE TABLE cmpart(f1 text COMPRESSION lz4) PARTITION BY HASH(f1); 87CREATE TABLE cmpart1 PARTITION OF cmpart FOR VALUES WITH (MODULUS 2, REMAINDER 0); 88CREATE TABLE cmpart2(f1 text COMPRESSION pglz); 89 90ALTER TABLE cmpart ATTACH PARTITION cmpart2 FOR VALUES WITH (MODULUS 2, REMAINDER 1); 91INSERT INTO cmpart VALUES (repeat('123456789', 1004)); 92INSERT INTO cmpart VALUES (repeat('123456789', 4004)); 93SELECT pg_column_compression(f1) FROM cmpart1; 94SELECT pg_column_compression(f1) FROM cmpart2; 95 96-- test compression with inheritance, error 97CREATE TABLE cminh() INHERITS(cmdata, cmdata1); 98CREATE TABLE cminh(f1 TEXT COMPRESSION lz4) INHERITS(cmdata); 99 100-- test default_toast_compression GUC 101SET default_toast_compression = ''; 102SET default_toast_compression = 'I do not exist compression'; 103SET default_toast_compression = 'lz4'; 104SET default_toast_compression = 'pglz'; 105 106-- test alter compression method 107ALTER TABLE cmdata ALTER COLUMN f1 SET COMPRESSION lz4; 108INSERT INTO cmdata VALUES (repeat('123456789', 4004)); 109\d+ cmdata 110SELECT pg_column_compression(f1) FROM cmdata; 111 112ALTER TABLE cmdata2 ALTER COLUMN f1 SET COMPRESSION default; 113\d+ cmdata2 114 115-- test alter compression method for materialized views 116ALTER MATERIALIZED VIEW compressmv ALTER COLUMN x SET COMPRESSION lz4; 117\d+ compressmv 118 119-- test alter compression method for partitioned tables 120ALTER TABLE cmpart1 ALTER COLUMN f1 SET COMPRESSION pglz; 121ALTER TABLE cmpart2 ALTER COLUMN f1 SET COMPRESSION lz4; 122 123-- new data should be compressed with the current compression method 124INSERT INTO cmpart VALUES (repeat('123456789', 1004)); 125INSERT INTO cmpart VALUES (repeat('123456789', 4004)); 126SELECT pg_column_compression(f1) FROM cmpart1; 127SELECT pg_column_compression(f1) FROM cmpart2; 128 129-- VACUUM FULL does not recompress 130SELECT pg_column_compression(f1) FROM cmdata; 131VACUUM FULL cmdata; 132SELECT pg_column_compression(f1) FROM cmdata; 133 134-- test expression index 135DROP TABLE cmdata2; 136CREATE TABLE cmdata2 (f1 TEXT COMPRESSION pglz, f2 TEXT COMPRESSION lz4); 137CREATE UNIQUE INDEX idx1 ON cmdata2 ((f1 || f2)); 138INSERT INTO cmdata2 VALUES((SELECT array_agg(md5(g::TEXT))::TEXT FROM 139generate_series(1, 50) g), VERSION()); 140 141-- check data is ok 142SELECT length(f1) FROM cmdata; 143SELECT length(f1) FROM cmdata1; 144SELECT length(f1) FROM cmmove1; 145SELECT length(f1) FROM cmmove2; 146SELECT length(f1) FROM cmmove3; 147 148CREATE TABLE badcompresstbl (a text COMPRESSION I_Do_Not_Exist_Compression); -- fails 149CREATE TABLE badcompresstbl (a text); 150ALTER TABLE badcompresstbl ALTER a SET COMPRESSION I_Do_Not_Exist_Compression; -- fails 151DROP TABLE badcompresstbl; 152 153\set HIDE_TOAST_COMPRESSION true 154