Add columnar regression tests (#4727)

* Add cursor tests for columnar tables

* Add columnar tests for data types w/out comp. operators

* Add more prepared statements with columnar tables

* Add constraint tests for columnar tables

* Add row level security, detach partition and rename columnar tests

* Add some ORDER BYs
pull/4741/head
Naisila Puka 2021-02-23 14:16:38 +03:00 committed by GitHub
parent b6f5d98bee
commit 105bb580e1
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
15 changed files with 1159 additions and 17 deletions

View File

@ -15,6 +15,7 @@ test: columnar_permissions
test: am_empty test: am_empty
test: am_insert test: am_insert
test: am_update_delete test: am_update_delete
test: columnar_cursor
test: am_copyto test: am_copyto
test: am_alter test: am_alter
test: am_alter_set_type test: am_alter_set_type
@ -23,6 +24,7 @@ test: am_rollback
test: am_truncate test: am_truncate
test: am_vacuum test: am_vacuum
test: am_clean test: am_clean
test: columnar_types_without_comparison
test: am_chunk_filtering test: am_chunk_filtering
test: am_join test: am_join
test: am_trigger test: am_trigger

View File

@ -172,7 +172,11 @@ ALTER TABLE test_alter_table ALTER COLUMN j TYPE int;
-- text / varchar conversion is valid both ways -- text / varchar conversion is valid both ways
ALTER TABLE test_alter_table ALTER COLUMN k TYPE varchar(20); ALTER TABLE test_alter_table ALTER COLUMN k TYPE varchar(20);
ALTER TABLE test_alter_table ALTER COLUMN k TYPE text; ALTER TABLE test_alter_table ALTER COLUMN k TYPE text;
DROP TABLE test_alter_table; -- rename column
ALTER TABLE test_alter_table RENAME COLUMN k TO k_renamed;
-- rename table
ALTER TABLE test_alter_table RENAME TO test_alter_table_renamed;
DROP TABLE test_alter_table_renamed;
-- https://github.com/citusdata/citus/issues/4602 -- https://github.com/citusdata/citus/issues/4602
create domain str_domain as text not null; create domain str_domain as text not null;
create table domain_test (a int, b int) using columnar; create table domain_test (a int, b int) using columnar;
@ -334,5 +338,95 @@ SELECT * FROM zero_col_columnar;
-- --
(8 rows) (8 rows)
-- Add constraints
-- Add a CHECK constraint
CREATE TABLE products (
product_no integer,
name text,
price int CONSTRAINT price_constraint CHECK (price > 0)
) USING columnar;
-- first insert should fail
INSERT INTO products VALUES (1, 'bread', 0);
ERROR: new row for relation "products" violates check constraint "price_constraint"
DETAIL: Failing row contains (1, bread, 0).
INSERT INTO products VALUES (1, 'bread', 10);
ALTER TABLE products ADD CONSTRAINT dummy_constraint CHECK (price > product_no);
-- first insert should fail
INSERT INTO products VALUES (2, 'shampoo', 1);
ERROR: new row for relation "products" violates check constraint "dummy_constraint"
DETAIL: Failing row contains (2, shampoo, 1).
INSERT INTO products VALUES (2, 'shampoo', 20);
ALTER TABLE products DROP CONSTRAINT dummy_constraint;
INSERT INTO products VALUES (3, 'pen', 2);
SELECT * FROM products ORDER BY 1;
product_no | name | price
---------------------------------------------------------------------
1 | bread | 10
2 | shampoo | 20
3 | pen | 2
(3 rows)
-- Add a UNIQUE constraint (should fail)
CREATE TABLE products_fail (
product_no integer UNIQUE,
name text,
price numeric
) USING columnar;
ERROR: indexes not supported for columnar tables
ALTER TABLE products ADD COLUMN store_id text UNIQUE;
ERROR: indexes not supported for columnar tables
-- Add a PRIMARY KEY constraint (should fail)
CREATE TABLE products_fail (
product_no integer PRIMARY KEY,
name text,
price numeric
) USING columnar;
ERROR: indexes not supported for columnar tables
ALTER TABLE products ADD COLUMN store_id text PRIMARY KEY;
ERROR: indexes not supported for columnar tables
-- Add an EXCLUSION constraint (should fail)
CREATE TABLE circles (
c circle,
EXCLUDE USING gist (c WITH &&)
) USING columnar;
ERROR: indexes not supported for columnar tables
-- Row level security
CREATE TABLE public.row_level_security_col (id int, pgUser CHARACTER VARYING) USING columnar;
CREATE USER user1;
NOTICE: not propagating CREATE ROLE/USER commands to worker nodes
HINT: Connect to worker nodes directly to manually create all necessary users and roles.
CREATE USER user2;
NOTICE: not propagating CREATE ROLE/USER commands to worker nodes
HINT: Connect to worker nodes directly to manually create all necessary users and roles.
INSERT INTO public.row_level_security_col VALUES (1, 'user1'), (2, 'user2');
GRANT SELECT, UPDATE, INSERT, DELETE ON public.row_level_security_col TO user1;
GRANT SELECT, UPDATE, INSERT, DELETE ON public.row_level_security_col TO user2;
CREATE POLICY policy_col ON public.row_level_security_col FOR ALL TO PUBLIC USING (pgUser = current_user);
ALTER TABLE public.row_level_security_col ENABLE ROW LEVEL SECURITY;
SELECT * FROM public.row_level_security_col ORDER BY 1;
id | pguser
---------------------------------------------------------------------
1 | user1
2 | user2
(2 rows)
SET ROLE user1;
SELECT * FROM public.row_level_security_col;
id | pguser
---------------------------------------------------------------------
1 | user1
(1 row)
SET ROLE user2;
SELECT * FROM public.row_level_security_col;
id | pguser
---------------------------------------------------------------------
2 | user2
(1 row)
RESET ROLE;
DROP TABLE public.row_level_security_col;
DROP USER user1;
DROP USER user2;
SET client_min_messages TO WARNING; SET client_min_messages TO WARNING;
DROP SCHEMA columnar_alter CASCADE; DROP SCHEMA columnar_alter CASCADE;

View File

@ -209,16 +209,17 @@ SELECT * FROM t ORDER BY a;
-- --
-- Prepared statements -- Prepared statements
-- --
PREPARE p1(int) AS INSERT INTO t VALUES (8, $1), (9, $1+2); -- INSERT INTO with 0 params
EXPLAIN (COSTS OFF) EXECUTE p1(16); PREPARE p0 AS INSERT INTO t VALUES (8, 8), (9, 9);
EXPLAIN (COSTS OFF) EXECUTE p0;
QUERY PLAN QUERY PLAN
--------------------------------------------------------------------- ---------------------------------------------------------------------
Insert on t Insert on t
-> Values Scan on "*VALUES*" -> Values Scan on "*VALUES*"
(2 rows) (2 rows)
EXECUTE p1(16); EXECUTE p0;
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p1(20); EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p0;
QUERY PLAN QUERY PLAN
--------------------------------------------------------------------- ---------------------------------------------------------------------
Insert on t (actual rows=0 loops=1) Insert on t (actual rows=0 loops=1)
@ -235,10 +236,248 @@ SELECT * FROM t ORDER BY a;
5 | 10 5 | 10
6 | 13 6 | 13
7 | 15 7 | 15
8 | 16 8 | 8
8 | 20 8 | 8
9 | 18 9 | 9
9 | 22 9 | 9
(11 rows) (11 rows)
-- INSERT INTO with 1 param
PREPARE p1(int) AS INSERT INTO t VALUES (10, $1), (11, $1+2);
EXPLAIN (COSTS OFF) EXECUTE p1(16);
QUERY PLAN
---------------------------------------------------------------------
Insert on t
-> Values Scan on "*VALUES*"
(2 rows)
EXECUTE p1(16);
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p1(20);
QUERY PLAN
---------------------------------------------------------------------
Insert on t (actual rows=0 loops=1)
-> Values Scan on "*VALUES*" (actual rows=2 loops=1)
(2 rows)
SELECT * FROM t ORDER BY a;
a | b
---------------------------------------------------------------------
1 | 2
2 | 4
3 | 6
4 | 8
5 | 10
6 | 13
7 | 15
8 | 8
8 | 8
9 | 9
9 | 9
10 | 16
10 | 20
11 | 22
11 | 18
(15 rows)
-- INSERT INTO with >1 params
PREPARE p2(int, int) AS INSERT INTO t VALUES (12, $1), (13, $1+2), (14, $2), ($1+1, $2+1);
EXPLAIN (COSTS OFF) EXECUTE p2(30, 40);
QUERY PLAN
---------------------------------------------------------------------
Insert on t
-> Values Scan on "*VALUES*"
(2 rows)
EXECUTE p2(30, 40);
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p2(50, 60);
QUERY PLAN
---------------------------------------------------------------------
Insert on t (actual rows=0 loops=1)
-> Values Scan on "*VALUES*" (actual rows=4 loops=1)
(2 rows)
SELECT * FROM t ORDER BY a;
a | b
---------------------------------------------------------------------
1 | 2
2 | 4
3 | 6
4 | 8
5 | 10
6 | 13
7 | 15
8 | 8
8 | 8
9 | 9
9 | 9
10 | 16
10 | 20
11 | 22
11 | 18
12 | 50
12 | 30
13 | 52
13 | 32
14 | 40
14 | 60
31 | 41
51 | 61
(23 rows)
-- SELECT with 0 params
PREPARE p3 AS SELECT * FROM t WHERE a = 8;
EXPLAIN (COSTS OFF) EXECUTE p3;
QUERY PLAN
---------------------------------------------------------------------
Custom Scan (ColumnarScan) on t
Filter: (a = 8)
(2 rows)
EXECUTE p3;
a | b
---------------------------------------------------------------------
8 | 8
8 | 8
(2 rows)
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p3;
QUERY PLAN
---------------------------------------------------------------------
Custom Scan (ColumnarScan) on t (actual rows=2 loops=1)
Filter: (a = 8)
Rows Removed by Filter: 2
Columnar Chunk Groups Removed by Filter: 8
(4 rows)
SELECT * FROM t ORDER BY a;
a | b
---------------------------------------------------------------------
1 | 2
2 | 4
3 | 6
4 | 8
5 | 10
6 | 13
7 | 15
8 | 8
8 | 8
9 | 9
9 | 9
10 | 16
10 | 20
11 | 22
11 | 18
12 | 50
12 | 30
13 | 52
13 | 32
14 | 40
14 | 60
31 | 41
51 | 61
(23 rows)
-- SELECT with 1 param
PREPARE p5(int) AS SELECT * FROM t WHERE a = $1;
EXPLAIN (COSTS OFF) EXECUTE p5(16);
QUERY PLAN
---------------------------------------------------------------------
Custom Scan (ColumnarScan) on t
Filter: (a = 16)
(2 rows)
EXECUTE p5(16);
a | b
---------------------------------------------------------------------
(0 rows)
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p5(9);
QUERY PLAN
---------------------------------------------------------------------
Custom Scan (ColumnarScan) on t (actual rows=2 loops=1)
Filter: (a = 9)
Rows Removed by Filter: 2
Columnar Chunk Groups Removed by Filter: 8
(4 rows)
SELECT * FROM t ORDER BY a;
a | b
---------------------------------------------------------------------
1 | 2
2 | 4
3 | 6
4 | 8
5 | 10
6 | 13
7 | 15
8 | 8
8 | 8
9 | 9
9 | 9
10 | 16
10 | 20
11 | 22
11 | 18
12 | 50
12 | 30
13 | 52
13 | 32
14 | 40
14 | 60
31 | 41
51 | 61
(23 rows)
-- SELECT with >1 params
PREPARE p6(int, int) AS SELECT * FROM t WHERE a = $1+1 AND b = $2+1;
EXPLAIN (COSTS OFF) EXECUTE p6(30, 40);
QUERY PLAN
---------------------------------------------------------------------
Custom Scan (ColumnarScan) on t
Filter: ((a = 31) AND (b = 41))
(2 rows)
EXECUTE p6(30, 40);
a | b
---------------------------------------------------------------------
31 | 41
(1 row)
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p6(50, 60);
QUERY PLAN
---------------------------------------------------------------------
Custom Scan (ColumnarScan) on t (actual rows=1 loops=1)
Filter: ((a = 51) AND (b = 61))
Rows Removed by Filter: 3
Columnar Chunk Groups Removed by Filter: 9
(4 rows)
SELECT * FROM t ORDER BY a;
a | b
---------------------------------------------------------------------
1 | 2
2 | 4
3 | 6
4 | 8
5 | 10
6 | 13
7 | 15
8 | 8
8 | 8
9 | 9
9 | 9
10 | 16
10 | 20
11 | 22
11 | 18
12 | 50
12 | 30
13 | 52
13 | 32
14 | 40
14 | 60
31 | 41
51 | 61
(23 rows)
DROP TABLE t; DROP TABLE t;

View File

@ -90,4 +90,7 @@ SELECT * FROM parent;
Sun Mar 15 00:00:00 2020 PDT | 32 | 300 | three thousand Sun Mar 15 00:00:00 2020 PDT | 32 | 300 | three thousand
(4 rows) (4 rows)
-- detach partition
ALTER TABLE parent DETACH PARTITION p0;
DROP TABLE p0;
DROP TABLE parent; DROP TABLE parent;

View File

@ -0,0 +1,208 @@
--
-- Testing cursors on columnar tables.
--
CREATE TABLE test_cursor (a int, b int) USING columnar;
INSERT INTO test_cursor SELECT i, j FROM generate_series(0, 100)i, generate_series(100, 200)j;
-- A case where the WHERE clause might filter out some chunks
EXPLAIN (analyze on, costs off, timing off, summary off) SELECT * FROM test_cursor WHERE a = 25;
QUERY PLAN
---------------------------------------------------------------------
Custom Scan (ColumnarScan) on test_cursor (actual rows=101 loops=1)
Filter: (a = 25)
Rows Removed by Filter: 9899
Columnar Chunk Groups Removed by Filter: 1
(4 rows)
BEGIN;
DECLARE a_25 SCROLL CURSOR
FOR SELECT * FROM test_cursor WHERE a = 25 ORDER BY 2;
FETCH 3 FROM a_25;
a | b
---------------------------------------------------------------------
25 | 100
25 | 101
25 | 102
(3 rows)
FETCH PRIOR FROM a_25;
a | b
---------------------------------------------------------------------
25 | 101
(1 row)
FETCH NEXT FROM a_25;
a | b
---------------------------------------------------------------------
25 | 102
(1 row)
FETCH NEXT FROM a_25;
a | b
---------------------------------------------------------------------
25 | 103
(1 row)
FETCH RELATIVE -2 FROM a_25;
a | b
---------------------------------------------------------------------
25 | 101
(1 row)
FETCH LAST FROM a_25;
a | b
---------------------------------------------------------------------
25 | 200
(1 row)
FETCH RELATIVE -25 FROM a_25;
a | b
---------------------------------------------------------------------
25 | 175
(1 row)
MOVE a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
25 | 177
(1 row)
MOVE LAST FROM a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
(0 rows)
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
25 | 199
(1 row)
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
25 | 197
(1 row)
MOVE FORWARD 2 FROM a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
25 | 200
(1 row)
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
25 | 198
(1 row)
UPDATE test_cursor SET a = 8000 WHERE CURRENT OF a_25;
ERROR: UPDATE and CTID scans not supported for ColumnarScan
COMMIT;
-- A case where the WHERE clause doesn't filter out any chunks
EXPLAIN (analyze on, costs off, timing off, summary off) SELECT * FROM test_cursor WHERE a > 25;
QUERY PLAN
---------------------------------------------------------------------
Custom Scan (ColumnarScan) on test_cursor (actual rows=7575 loops=1)
Filter: (a > 25)
Rows Removed by Filter: 2626
Columnar Chunk Groups Removed by Filter: 0
(4 rows)
BEGIN;
DECLARE a_25 SCROLL CURSOR
FOR SELECT * FROM test_cursor WHERE a > 25 ORDER BY 1, 2;
FETCH 3 FROM a_25;
a | b
---------------------------------------------------------------------
26 | 100
26 | 101
26 | 102
(3 rows)
FETCH PRIOR FROM a_25;
a | b
---------------------------------------------------------------------
26 | 101
(1 row)
FETCH NEXT FROM a_25;
a | b
---------------------------------------------------------------------
26 | 102
(1 row)
FETCH NEXT FROM a_25;
a | b
---------------------------------------------------------------------
26 | 103
(1 row)
FETCH RELATIVE -2 FROM a_25;
a | b
---------------------------------------------------------------------
26 | 101
(1 row)
FETCH LAST FROM a_25;
a | b
---------------------------------------------------------------------
100 | 200
(1 row)
FETCH RELATIVE -25 FROM a_25;
a | b
---------------------------------------------------------------------
100 | 175
(1 row)
MOVE a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
100 | 177
(1 row)
MOVE LAST FROM a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
(0 rows)
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
100 | 199
(1 row)
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
100 | 197
(1 row)
MOVE FORWARD 2 FROM a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
100 | 200
(1 row)
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
a | b
---------------------------------------------------------------------
100 | 198
(1 row)
UPDATE test_cursor SET a = 8000 WHERE CURRENT OF a_25;
ERROR: UPDATE and CTID scans not supported for ColumnarScan
COMMIT;
DROP TABLE test_cursor CASCADE;

View File

@ -353,10 +353,11 @@ SELECT * FROM ij_col_col;
(1 row) (1 row)
SET columnar.enable_custom_scan TO DEFAULT; SET columnar.enable_custom_scan TO DEFAULT;
-- remove the child table from the inheritance hierarchy table
ALTER TABLE ij_row_row NO INHERIT i_row;
DROP TABLE ij_row_row;
DROP TABLE i_row CASCADE; DROP TABLE i_row CASCADE;
NOTICE: drop cascades to 2 other objects NOTICE: drop cascades to table ij_row_col
DETAIL: drop cascades to table ij_row_row
drop cascades to table ij_row_col
DROP TABLE i_col CASCADE; DROP TABLE i_col CASCADE;
NOTICE: drop cascades to 2 other objects NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to table ij_col_row DETAIL: drop cascades to table ij_col_row

View File

@ -353,10 +353,11 @@ SELECT * FROM ij_col_col;
(1 row) (1 row)
SET columnar.enable_custom_scan TO DEFAULT; SET columnar.enable_custom_scan TO DEFAULT;
-- remove the child table from the inheritance hierarchy table
ALTER TABLE ij_row_row NO INHERIT i_row;
DROP TABLE ij_row_row;
DROP TABLE i_row CASCADE; DROP TABLE i_row CASCADE;
NOTICE: drop cascades to 2 other objects NOTICE: drop cascades to table ij_row_col
DETAIL: drop cascades to table ij_row_row
drop cascades to table ij_row_col
DROP TABLE i_col CASCADE; DROP TABLE i_col CASCADE;
NOTICE: drop cascades to 2 other objects NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to table ij_col_row DETAIL: drop cascades to table ij_col_row

View File

@ -0,0 +1,176 @@
--
-- Testing data types without comparison operators
-- If a data type doesn't have comparison operators, we should store NULL for min/max values
-- Verify that (1) min/max entries in columnar.chunk is NULL as expected
-- (2) we can run queries which has equality conditions in WHERE clause for that column with correct results
--
-- varchar
CREATE TABLE test_varchar (a varchar) USING columnar;
INSERT INTO test_varchar VALUES ('Hello');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_varchar WHERE a = 'Hello';
a
---------------------------------------------------------------------
Hello
(1 row)
DROP TABLE test_varchar;
-- cidr
CREATE TABLE test_cidr (a cidr) USING columnar;
INSERT INTO test_cidr VALUES ('192.168.100.128/25');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_cidr WHERE a = '192.168.100.128/25';
a
---------------------------------------------------------------------
192.168.100.128/25
(1 row)
DROP TABLE test_cidr;
-- json
CREATE TABLE test_json (a json) USING columnar;
INSERT INTO test_json VALUES ('5'::json);
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_json WHERE a::text = '5'::json::text;
a
---------------------------------------------------------------------
5
(1 row)
DROP TABLE test_json;
-- line
CREATE TABLE test_line (a line) USING columnar;
INSERT INTO test_line VALUES ('{1, 2, 3}');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_line WHERE a = '{1, 2, 3}';
a
---------------------------------------------------------------------
{1,2,3}
(1 row)
DROP TABLE test_line;
-- lseg
CREATE TABLE test_lseg (a lseg) USING columnar;
INSERT INTO test_lseg VALUES ('( 1 , 2 ) , ( 3 , 4 )');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_lseg WHERE a = '( 1 , 2 ) , ( 3 , 4 )';
a
---------------------------------------------------------------------
[(1,2),(3,4)]
(1 row)
DROP TABLE test_lseg;
-- path
CREATE TABLE test_path (a path) USING columnar;
INSERT INTO test_path VALUES ('( 1 , 2 ) , ( 3 , 4 ) , ( 5 , 6 )');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_path WHERE a = '( 1 , 2 ) , ( 3 , 4 ) , ( 5 , 6 )';
a
---------------------------------------------------------------------
((1,2),(3,4),(5,6))
(1 row)
DROP TABLE test_path;
-- txid_snapshot
CREATE TABLE test_txid_snapshot (a txid_snapshot) USING columnar;
INSERT INTO test_txid_snapshot VALUES ('10:20:10,14,15');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_txid_snapshot WHERE a::text = '10:20:10,14,15'::txid_snapshot::text;
a
---------------------------------------------------------------------
10:20:10,14,15
(1 row)
DROP TABLE test_txid_snapshot;
-- xml
CREATE TABLE test_xml (a xml) USING columnar;
INSERT INTO test_xml VALUES ('<foo>bar</foo>'::xml);
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_xml WHERE a::text = '<foo>bar</foo>'::xml::text;
a
---------------------------------------------------------------------
<foo>bar</foo>
(1 row)
DROP TABLE test_xml;
-- user defined
CREATE TYPE user_defined_color AS ENUM ('red', 'orange', 'yellow',
'green', 'blue', 'purple');
CREATE TABLE test_user_defined_color (a user_defined_color) USING columnar;
INSERT INTO test_user_defined_color VALUES ('red');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_user_defined_color WHERE a = 'red';
a
---------------------------------------------------------------------
red
(1 row)
DROP TABLE test_user_defined_color;
DROP TYPE user_defined_color;
SHOW server_version \gset
SELECT substring(:'server_version', '\d+')::int > 12 AS server_version_above_twelve
\gset
\if :server_version_above_twelve
\else
\q
\endif
-- pg_snapshot
CREATE TABLE test_pg_snapshot (a pg_snapshot) USING columnar;
INSERT INTO test_pg_snapshot VALUES ('10:20:10,14,15');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_pg_snapshot WHERE a::text = '10:20:10,14,15'::pg_snapshot::text;
a
---------------------------------------------------------------------
10:20:10,14,15
(1 row)
DROP TABLE test_pg_snapshot;

View File

@ -0,0 +1,159 @@
--
-- Testing data types without comparison operators
-- If a data type doesn't have comparison operators, we should store NULL for min/max values
-- Verify that (1) min/max entries in columnar.chunk is NULL as expected
-- (2) we can run queries which has equality conditions in WHERE clause for that column with correct results
--
-- varchar
CREATE TABLE test_varchar (a varchar) USING columnar;
INSERT INTO test_varchar VALUES ('Hello');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_varchar WHERE a = 'Hello';
a
---------------------------------------------------------------------
Hello
(1 row)
DROP TABLE test_varchar;
-- cidr
CREATE TABLE test_cidr (a cidr) USING columnar;
INSERT INTO test_cidr VALUES ('192.168.100.128/25');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_cidr WHERE a = '192.168.100.128/25';
a
---------------------------------------------------------------------
192.168.100.128/25
(1 row)
DROP TABLE test_cidr;
-- json
CREATE TABLE test_json (a json) USING columnar;
INSERT INTO test_json VALUES ('5'::json);
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_json WHERE a::text = '5'::json::text;
a
---------------------------------------------------------------------
5
(1 row)
DROP TABLE test_json;
-- line
CREATE TABLE test_line (a line) USING columnar;
INSERT INTO test_line VALUES ('{1, 2, 3}');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_line WHERE a = '{1, 2, 3}';
a
---------------------------------------------------------------------
{1,2,3}
(1 row)
DROP TABLE test_line;
-- lseg
CREATE TABLE test_lseg (a lseg) USING columnar;
INSERT INTO test_lseg VALUES ('( 1 , 2 ) , ( 3 , 4 )');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_lseg WHERE a = '( 1 , 2 ) , ( 3 , 4 )';
a
---------------------------------------------------------------------
[(1,2),(3,4)]
(1 row)
DROP TABLE test_lseg;
-- path
CREATE TABLE test_path (a path) USING columnar;
INSERT INTO test_path VALUES ('( 1 , 2 ) , ( 3 , 4 ) , ( 5 , 6 )');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_path WHERE a = '( 1 , 2 ) , ( 3 , 4 ) , ( 5 , 6 )';
a
---------------------------------------------------------------------
((1,2),(3,4),(5,6))
(1 row)
DROP TABLE test_path;
-- txid_snapshot
CREATE TABLE test_txid_snapshot (a txid_snapshot) USING columnar;
INSERT INTO test_txid_snapshot VALUES ('10:20:10,14,15');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_txid_snapshot WHERE a::text = '10:20:10,14,15'::txid_snapshot::text;
a
---------------------------------------------------------------------
10:20:10,14,15
(1 row)
DROP TABLE test_txid_snapshot;
-- xml
CREATE TABLE test_xml (a xml) USING columnar;
INSERT INTO test_xml VALUES ('<foo>bar</foo>'::xml);
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_xml WHERE a::text = '<foo>bar</foo>'::xml::text;
a
---------------------------------------------------------------------
<foo>bar</foo>
(1 row)
DROP TABLE test_xml;
-- user defined
CREATE TYPE user_defined_color AS ENUM ('red', 'orange', 'yellow',
'green', 'blue', 'purple');
CREATE TABLE test_user_defined_color (a user_defined_color) USING columnar;
INSERT INTO test_user_defined_color VALUES ('red');
SELECT minimum_value, maximum_value FROM columnar.chunk;
minimum_value | maximum_value
---------------------------------------------------------------------
|
(1 row)
SELECT * FROM test_user_defined_color WHERE a = 'red';
a
---------------------------------------------------------------------
red
(1 row)
DROP TABLE test_user_defined_color;
DROP TYPE user_defined_color;
SHOW server_version \gset
SELECT substring(:'server_version', '\d+')::int > 12 AS server_version_above_twelve
\gset
\if :server_version_above_twelve
\else
\q

View File

@ -85,7 +85,13 @@ ALTER TABLE test_alter_table ALTER COLUMN j TYPE int;
ALTER TABLE test_alter_table ALTER COLUMN k TYPE varchar(20); ALTER TABLE test_alter_table ALTER COLUMN k TYPE varchar(20);
ALTER TABLE test_alter_table ALTER COLUMN k TYPE text; ALTER TABLE test_alter_table ALTER COLUMN k TYPE text;
DROP TABLE test_alter_table; -- rename column
ALTER TABLE test_alter_table RENAME COLUMN k TO k_renamed;
-- rename table
ALTER TABLE test_alter_table RENAME TO test_alter_table_renamed;
DROP TABLE test_alter_table_renamed;
-- https://github.com/citusdata/citus/issues/4602 -- https://github.com/citusdata/citus/issues/4602
create domain str_domain as text not null; create domain str_domain as text not null;
@ -178,5 +184,65 @@ VACUUM FULL zero_col_columnar;
SELECT * FROM zero_col_columnar; SELECT * FROM zero_col_columnar;
-- Add constraints
-- Add a CHECK constraint
CREATE TABLE products (
product_no integer,
name text,
price int CONSTRAINT price_constraint CHECK (price > 0)
) USING columnar;
-- first insert should fail
INSERT INTO products VALUES (1, 'bread', 0);
INSERT INTO products VALUES (1, 'bread', 10);
ALTER TABLE products ADD CONSTRAINT dummy_constraint CHECK (price > product_no);
-- first insert should fail
INSERT INTO products VALUES (2, 'shampoo', 1);
INSERT INTO products VALUES (2, 'shampoo', 20);
ALTER TABLE products DROP CONSTRAINT dummy_constraint;
INSERT INTO products VALUES (3, 'pen', 2);
SELECT * FROM products ORDER BY 1;
-- Add a UNIQUE constraint (should fail)
CREATE TABLE products_fail (
product_no integer UNIQUE,
name text,
price numeric
) USING columnar;
ALTER TABLE products ADD COLUMN store_id text UNIQUE;
-- Add a PRIMARY KEY constraint (should fail)
CREATE TABLE products_fail (
product_no integer PRIMARY KEY,
name text,
price numeric
) USING columnar;
ALTER TABLE products ADD COLUMN store_id text PRIMARY KEY;
-- Add an EXCLUSION constraint (should fail)
CREATE TABLE circles (
c circle,
EXCLUDE USING gist (c WITH &&)
) USING columnar;
-- Row level security
CREATE TABLE public.row_level_security_col (id int, pgUser CHARACTER VARYING) USING columnar;
CREATE USER user1;
CREATE USER user2;
INSERT INTO public.row_level_security_col VALUES (1, 'user1'), (2, 'user2');
GRANT SELECT, UPDATE, INSERT, DELETE ON public.row_level_security_col TO user1;
GRANT SELECT, UPDATE, INSERT, DELETE ON public.row_level_security_col TO user2;
CREATE POLICY policy_col ON public.row_level_security_col FOR ALL TO PUBLIC USING (pgUser = current_user);
ALTER TABLE public.row_level_security_col ENABLE ROW LEVEL SECURITY;
SELECT * FROM public.row_level_security_col ORDER BY 1;
SET ROLE user1;
SELECT * FROM public.row_level_security_col;
SET ROLE user2;
SELECT * FROM public.row_level_security_col;
RESET ROLE;
DROP TABLE public.row_level_security_col;
DROP USER user1;
DROP USER user2;
SET client_min_messages TO WARNING; SET client_min_messages TO WARNING;
DROP SCHEMA columnar_alter CASCADE; DROP SCHEMA columnar_alter CASCADE;

View File

@ -98,10 +98,46 @@ SELECT * FROM t ORDER BY a;
-- Prepared statements -- Prepared statements
-- --
PREPARE p1(int) AS INSERT INTO t VALUES (8, $1), (9, $1+2); -- INSERT INTO with 0 params
PREPARE p0 AS INSERT INTO t VALUES (8, 8), (9, 9);
EXPLAIN (COSTS OFF) EXECUTE p0;
EXECUTE p0;
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p0;
SELECT * FROM t ORDER BY a;
-- INSERT INTO with 1 param
PREPARE p1(int) AS INSERT INTO t VALUES (10, $1), (11, $1+2);
EXPLAIN (COSTS OFF) EXECUTE p1(16); EXPLAIN (COSTS OFF) EXECUTE p1(16);
EXECUTE p1(16); EXECUTE p1(16);
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p1(20); EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p1(20);
SELECT * FROM t ORDER BY a; SELECT * FROM t ORDER BY a;
-- INSERT INTO with >1 params
PREPARE p2(int, int) AS INSERT INTO t VALUES (12, $1), (13, $1+2), (14, $2), ($1+1, $2+1);
EXPLAIN (COSTS OFF) EXECUTE p2(30, 40);
EXECUTE p2(30, 40);
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p2(50, 60);
SELECT * FROM t ORDER BY a;
-- SELECT with 0 params
PREPARE p3 AS SELECT * FROM t WHERE a = 8;
EXPLAIN (COSTS OFF) EXECUTE p3;
EXECUTE p3;
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p3;
SELECT * FROM t ORDER BY a;
-- SELECT with 1 param
PREPARE p5(int) AS SELECT * FROM t WHERE a = $1;
EXPLAIN (COSTS OFF) EXECUTE p5(16);
EXECUTE p5(16);
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p5(9);
SELECT * FROM t ORDER BY a;
-- SELECT with >1 params
PREPARE p6(int, int) AS SELECT * FROM t WHERE a = $1+1 AND b = $2+1;
EXPLAIN (COSTS OFF) EXECUTE p6(30, 40);
EXECUTE p6(30, 40);
EXPLAIN (ANALYZE true, COSTS off, TIMING off, SUMMARY off) EXECUTE p6(50, 60);
SELECT * FROM t ORDER BY a;
DROP TABLE t; DROP TABLE t;

View File

@ -79,5 +79,9 @@ DELETE FROM parent WHERE n = 303;
SELECT * FROM parent; SELECT * FROM parent;
-- detach partition
ALTER TABLE parent DETACH PARTITION p0;
DROP TABLE p0;
DROP TABLE parent; DROP TABLE parent;

View File

@ -0,0 +1,62 @@
--
-- Testing cursors on columnar tables.
--
CREATE TABLE test_cursor (a int, b int) USING columnar;
INSERT INTO test_cursor SELECT i, j FROM generate_series(0, 100)i, generate_series(100, 200)j;
-- A case where the WHERE clause might filter out some chunks
EXPLAIN (analyze on, costs off, timing off, summary off) SELECT * FROM test_cursor WHERE a = 25;
BEGIN;
DECLARE a_25 SCROLL CURSOR
FOR SELECT * FROM test_cursor WHERE a = 25 ORDER BY 2;
FETCH 3 FROM a_25;
FETCH PRIOR FROM a_25;
FETCH NEXT FROM a_25;
FETCH NEXT FROM a_25;
FETCH RELATIVE -2 FROM a_25;
FETCH LAST FROM a_25;
FETCH RELATIVE -25 FROM a_25;
MOVE a_25;
FETCH a_25;
MOVE LAST FROM a_25;
FETCH a_25;
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
MOVE FORWARD 2 FROM a_25;
FETCH a_25;
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
UPDATE test_cursor SET a = 8000 WHERE CURRENT OF a_25;
COMMIT;
-- A case where the WHERE clause doesn't filter out any chunks
EXPLAIN (analyze on, costs off, timing off, summary off) SELECT * FROM test_cursor WHERE a > 25;
BEGIN;
DECLARE a_25 SCROLL CURSOR
FOR SELECT * FROM test_cursor WHERE a > 25 ORDER BY 1, 2;
FETCH 3 FROM a_25;
FETCH PRIOR FROM a_25;
FETCH NEXT FROM a_25;
FETCH NEXT FROM a_25;
FETCH RELATIVE -2 FROM a_25;
FETCH LAST FROM a_25;
FETCH RELATIVE -25 FROM a_25;
MOVE a_25;
FETCH a_25;
MOVE LAST FROM a_25;
FETCH a_25;
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
MOVE FORWARD 2 FROM a_25;
FETCH a_25;
MOVE RELATIVE -3 FROM a_25;
FETCH a_25;
UPDATE test_cursor SET a = 8000 WHERE CURRENT OF a_25;
COMMIT;
DROP TABLE test_cursor CASCADE;

View File

@ -123,5 +123,9 @@ SELECT * FROM ij_col_col;
SET columnar.enable_custom_scan TO DEFAULT; SET columnar.enable_custom_scan TO DEFAULT;
-- remove the child table from the inheritance hierarchy table
ALTER TABLE ij_row_row NO INHERIT i_row;
DROP TABLE ij_row_row;
DROP TABLE i_row CASCADE; DROP TABLE i_row CASCADE;
DROP TABLE i_col CASCADE; DROP TABLE i_col CASCADE;

View File

@ -0,0 +1,87 @@
--
-- Testing data types without comparison operators
-- If a data type doesn't have comparison operators, we should store NULL for min/max values
-- Verify that (1) min/max entries in columnar.chunk is NULL as expected
-- (2) we can run queries which has equality conditions in WHERE clause for that column with correct results
--
-- varchar
CREATE TABLE test_varchar (a varchar) USING columnar;
INSERT INTO test_varchar VALUES ('Hello');
SELECT minimum_value, maximum_value FROM columnar.chunk;
SELECT * FROM test_varchar WHERE a = 'Hello';
DROP TABLE test_varchar;
-- cidr
CREATE TABLE test_cidr (a cidr) USING columnar;
INSERT INTO test_cidr VALUES ('192.168.100.128/25');
SELECT minimum_value, maximum_value FROM columnar.chunk;
SELECT * FROM test_cidr WHERE a = '192.168.100.128/25';
DROP TABLE test_cidr;
-- json
CREATE TABLE test_json (a json) USING columnar;
INSERT INTO test_json VALUES ('5'::json);
SELECT minimum_value, maximum_value FROM columnar.chunk;
SELECT * FROM test_json WHERE a::text = '5'::json::text;
DROP TABLE test_json;
-- line
CREATE TABLE test_line (a line) USING columnar;
INSERT INTO test_line VALUES ('{1, 2, 3}');
SELECT minimum_value, maximum_value FROM columnar.chunk;
SELECT * FROM test_line WHERE a = '{1, 2, 3}';
DROP TABLE test_line;
-- lseg
CREATE TABLE test_lseg (a lseg) USING columnar;
INSERT INTO test_lseg VALUES ('( 1 , 2 ) , ( 3 , 4 )');
SELECT minimum_value, maximum_value FROM columnar.chunk;
SELECT * FROM test_lseg WHERE a = '( 1 , 2 ) , ( 3 , 4 )';
DROP TABLE test_lseg;
-- path
CREATE TABLE test_path (a path) USING columnar;
INSERT INTO test_path VALUES ('( 1 , 2 ) , ( 3 , 4 ) , ( 5 , 6 )');
SELECT minimum_value, maximum_value FROM columnar.chunk;
SELECT * FROM test_path WHERE a = '( 1 , 2 ) , ( 3 , 4 ) , ( 5 , 6 )';
DROP TABLE test_path;
-- txid_snapshot
CREATE TABLE test_txid_snapshot (a txid_snapshot) USING columnar;
INSERT INTO test_txid_snapshot VALUES ('10:20:10,14,15');
SELECT minimum_value, maximum_value FROM columnar.chunk;
SELECT * FROM test_txid_snapshot WHERE a::text = '10:20:10,14,15'::txid_snapshot::text;
DROP TABLE test_txid_snapshot;
-- xml
CREATE TABLE test_xml (a xml) USING columnar;
INSERT INTO test_xml VALUES ('<foo>bar</foo>'::xml);
SELECT minimum_value, maximum_value FROM columnar.chunk;
SELECT * FROM test_xml WHERE a::text = '<foo>bar</foo>'::xml::text;
DROP TABLE test_xml;
-- user defined
CREATE TYPE user_defined_color AS ENUM ('red', 'orange', 'yellow',
'green', 'blue', 'purple');
CREATE TABLE test_user_defined_color (a user_defined_color) USING columnar;
INSERT INTO test_user_defined_color VALUES ('red');
SELECT minimum_value, maximum_value FROM columnar.chunk;
SELECT * FROM test_user_defined_color WHERE a = 'red';
DROP TABLE test_user_defined_color;
DROP TYPE user_defined_color;
SHOW server_version \gset
SELECT substring(:'server_version', '\d+')::int > 12 AS server_version_above_twelve
\gset
\if :server_version_above_twelve
\else
\q
\endif
-- pg_snapshot
CREATE TABLE test_pg_snapshot (a pg_snapshot) USING columnar;
INSERT INTO test_pg_snapshot VALUES ('10:20:10,14,15');
SELECT minimum_value, maximum_value FROM columnar.chunk;
SELECT * FROM test_pg_snapshot WHERE a::text = '10:20:10,14,15'::pg_snapshot::text;
DROP TABLE test_pg_snapshot;