diff options
Diffstat (limited to 'src/test')
| -rw-r--r-- | src/test/regress/expected/rowsecurity.out | 24 | ||||
| -rw-r--r-- | src/test/regress/expected/rules.out | 4 | ||||
| -rw-r--r-- | src/test/regress/expected/sanity_check.out | 1 | ||||
| -rw-r--r-- | src/test/regress/expected/tablesample.out | 284 | ||||
| -rw-r--r-- | src/test/regress/output/misc.source | 5 | ||||
| -rw-r--r-- | src/test/regress/serial_schedule | 2 | ||||
| -rw-r--r-- | src/test/regress/sql/rowsecurity.sql | 8 | ||||
| -rw-r--r-- | src/test/regress/sql/tablesample.sql | 90 |
8 files changed, 271 insertions, 147 deletions
diff --git a/src/test/regress/expected/rowsecurity.out b/src/test/regress/expected/rowsecurity.out index 414299a6941..e7c242cd22d 100644 --- a/src/test/regress/expected/rowsecurity.out +++ b/src/test/regress/expected/rowsecurity.out @@ -101,15 +101,17 @@ NOTICE: f_leak => great manga 44 | 8 | 1 | rls_regress_user2 | great manga | manga (4 rows) -SELECT * FROM document TABLESAMPLE BERNOULLI (50) REPEATABLE(1) WHERE f_leak(dtitle) ORDER BY did; -NOTICE: f_leak => my first novel +-- try a sampled version +SELECT * FROM document TABLESAMPLE BERNOULLI(50) REPEATABLE(0) + WHERE f_leak(dtitle) ORDER BY did; NOTICE: f_leak => my first manga NOTICE: f_leak => great science fiction +NOTICE: f_leak => great manga did | cid | dlevel | dauthor | dtitle -----+-----+--------+-------------------+----------------------- - 1 | 11 | 1 | rls_regress_user1 | my first novel 4 | 44 | 1 | rls_regress_user1 | my first manga 6 | 22 | 1 | rls_regress_user2 | great science fiction + 8 | 44 | 1 | rls_regress_user2 | great manga (3 rows) -- viewpoint from rls_regress_user2 @@ -156,20 +158,20 @@ NOTICE: f_leak => great manga 44 | 8 | 1 | rls_regress_user2 | great manga | manga (8 rows) -SELECT * FROM document TABLESAMPLE BERNOULLI (50) REPEATABLE(1) WHERE f_leak(dtitle) ORDER BY did; -NOTICE: f_leak => my first novel -NOTICE: f_leak => my second novel +-- try a sampled version +SELECT * FROM document TABLESAMPLE BERNOULLI(50) REPEATABLE(0) + WHERE f_leak(dtitle) ORDER BY did; NOTICE: f_leak => my first manga +NOTICE: f_leak => my second manga NOTICE: f_leak => great science fiction -NOTICE: f_leak => great technology book +NOTICE: f_leak => great manga did | cid | dlevel | dauthor | dtitle -----+-----+--------+-------------------+----------------------- - 1 | 11 | 1 | rls_regress_user1 | my first novel - 2 | 11 | 2 | rls_regress_user1 | my second novel 4 | 44 | 1 | rls_regress_user1 | my first manga + 5 | 44 | 2 | rls_regress_user1 | my second manga 6 | 22 | 1 | rls_regress_user2 | great science fiction - 7 | 33 | 2 | rls_regress_user2 | great technology book -(5 rows) + 8 | 44 | 1 | rls_regress_user2 | great manga +(4 rows) EXPLAIN (COSTS OFF) SELECT * FROM document WHERE f_leak(dtitle); QUERY PLAN diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out index cd5337531d4..1e5b0b9a2c4 100644 --- a/src/test/regress/expected/rules.out +++ b/src/test/regress/expected/rules.out @@ -2202,6 +2202,10 @@ street| SELECT r.name, FROM ONLY road r, real_city c WHERE (c.outline ## r.thepath); +test_tablesample_v1| SELECT test_tablesample.id + FROM test_tablesample TABLESAMPLE system ((10 * 2)) REPEATABLE (2); +test_tablesample_v2| SELECT test_tablesample.id + FROM test_tablesample TABLESAMPLE system (99); toyemp| SELECT emp.name, emp.age, emp.location, diff --git a/src/test/regress/expected/sanity_check.out b/src/test/regress/expected/sanity_check.out index 14acd16da3b..eb0bc88ef1f 100644 --- a/src/test/regress/expected/sanity_check.out +++ b/src/test/regress/expected/sanity_check.out @@ -128,7 +128,6 @@ pg_shdepend|t pg_shdescription|t pg_shseclabel|t pg_statistic|t -pg_tablesample_method|t pg_tablespace|t pg_transform|t pg_trigger|t diff --git a/src/test/regress/expected/tablesample.out b/src/test/regress/expected/tablesample.out index 04e5eb8b807..727a8354397 100644 --- a/src/test/regress/expected/tablesample.out +++ b/src/test/regress/expected/tablesample.out @@ -1,107 +1,123 @@ -CREATE TABLE test_tablesample (id int, name text) WITH (fillfactor=10); -- force smaller pages so we don't have to load too much data to get multiple pages -INSERT INTO test_tablesample SELECT i, repeat(i::text, 200) FROM generate_series(0, 9) s(i) ORDER BY i; -SELECT t.id FROM test_tablesample AS t TABLESAMPLE SYSTEM (50) REPEATABLE (10); +CREATE TABLE test_tablesample (id int, name text) WITH (fillfactor=10); +-- use fillfactor so we don't have to load too much data to get multiple pages +INSERT INTO test_tablesample + SELECT i, repeat(i::text, 200) FROM generate_series(0, 9) s(i); +SELECT t.id FROM test_tablesample AS t TABLESAMPLE SYSTEM (50) REPEATABLE (0); id ---- - 0 - 1 - 2 3 4 5 - 9 -(7 rows) - -SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (100.0/11) REPEATABLE (9999); - id ----- 6 7 8 -(3 rows) +(6 rows) -SELECT count(*) FROM test_tablesample TABLESAMPLE SYSTEM (100); - count -------- - 10 -(1 row) +SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (100.0/11) REPEATABLE (0); + id +---- +(0 rows) -SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (100); +SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (0); id ---- - 0 - 1 - 2 + 3 + 4 + 5 6 7 8 - 9 -(7 rows) +(6 rows) -SELECT id FROM test_tablesample TABLESAMPLE BERNOULLI (50) REPEATABLE (100); +SELECT id FROM test_tablesample TABLESAMPLE BERNOULLI (50) REPEATABLE (0); id ---- - 0 - 1 - 3 4 5 + 6 + 7 + 8 (5 rows) -SELECT id FROM test_tablesample TABLESAMPLE BERNOULLI (5.5) REPEATABLE (1); +SELECT id FROM test_tablesample TABLESAMPLE BERNOULLI (5.5) REPEATABLE (0); id ---- - 0 - 5 -(2 rows) + 7 +(1 row) -CREATE VIEW test_tablesample_v1 AS SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (10*2) REPEATABLE (2); -CREATE VIEW test_tablesample_v2 AS SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (99); -SELECT pg_get_viewdef('test_tablesample_v1'::regclass); - pg_get_viewdef --------------------------------------------------------------------------------- - SELECT test_tablesample.id + - FROM test_tablesample TABLESAMPLE system (((10 * 2))::real) REPEATABLE (2); +-- 100% should give repeatable count results (ie, all rows) in any case +SELECT count(*) FROM test_tablesample TABLESAMPLE SYSTEM (100); + count +------- + 10 (1 row) -SELECT pg_get_viewdef('test_tablesample_v2'::regclass); - pg_get_viewdef ------------------------------------------------------------ - SELECT test_tablesample.id + - FROM test_tablesample TABLESAMPLE system ((99)::real); +SELECT count(*) FROM test_tablesample TABLESAMPLE SYSTEM (100) REPEATABLE (1+2); + count +------- + 10 +(1 row) + +SELECT count(*) FROM test_tablesample TABLESAMPLE SYSTEM (100) REPEATABLE (0.4); + count +------- + 10 (1 row) +CREATE VIEW test_tablesample_v1 AS + SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (10*2) REPEATABLE (2); +CREATE VIEW test_tablesample_v2 AS + SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (99); +\d+ test_tablesample_v1 + View "public.test_tablesample_v1" + Column | Type | Modifiers | Storage | Description +--------+---------+-----------+---------+------------- + id | integer | | plain | +View definition: + SELECT test_tablesample.id + FROM test_tablesample TABLESAMPLE system ((10 * 2)) REPEATABLE (2); + +\d+ test_tablesample_v2 + View "public.test_tablesample_v2" + Column | Type | Modifiers | Storage | Description +--------+---------+-----------+---------+------------- + id | integer | | plain | +View definition: + SELECT test_tablesample.id + FROM test_tablesample TABLESAMPLE system (99); + +-- check a sampled query doesn't affect cursor in progress BEGIN; -DECLARE tablesample_cur CURSOR FOR SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (100); +DECLARE tablesample_cur CURSOR FOR + SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (0); FETCH FIRST FROM tablesample_cur; id ---- - 0 + 3 (1 row) FETCH NEXT FROM tablesample_cur; id ---- - 1 + 4 (1 row) FETCH NEXT FROM tablesample_cur; id ---- - 2 + 5 (1 row) -SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (10); +SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (0); id ---- - 0 - 1 - 2 3 4 5 - 9 -(7 rows) + 6 + 7 + 8 +(6 rows) FETCH NEXT FROM tablesample_cur; id @@ -124,19 +140,19 @@ FETCH NEXT FROM tablesample_cur; FETCH FIRST FROM tablesample_cur; id ---- - 0 + 3 (1 row) FETCH NEXT FROM tablesample_cur; id ---- - 1 + 4 (1 row) FETCH NEXT FROM tablesample_cur; id ---- - 2 + 5 (1 row) FETCH NEXT FROM tablesample_cur; @@ -159,41 +175,129 @@ FETCH NEXT FROM tablesample_cur; CLOSE tablesample_cur; END; -EXPLAIN SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (10); - QUERY PLAN -------------------------------------------------------------------------------- - Sample Scan (system) on test_tablesample (cost=0.00..26.35 rows=635 width=4) +EXPLAIN (COSTS OFF) + SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (2); + QUERY PLAN +-------------------------------------------------------------------- + Sample Scan on test_tablesample + Sampling: system ('50'::real) REPEATABLE ('2'::double precision) +(2 rows) + +EXPLAIN (COSTS OFF) + SELECT * FROM test_tablesample_v1; + QUERY PLAN +-------------------------------------------------------------------- + Sample Scan on test_tablesample + Sampling: system ('20'::real) REPEATABLE ('2'::double precision) +(2 rows) + +-- check inheritance behavior +explain (costs off) + select count(*) from person tablesample bernoulli (100); + QUERY PLAN +------------------------------------------------- + Aggregate + -> Append + -> Sample Scan on person + Sampling: bernoulli ('100'::real) + -> Sample Scan on emp + Sampling: bernoulli ('100'::real) + -> Sample Scan on student + Sampling: bernoulli ('100'::real) + -> Sample Scan on stud_emp + Sampling: bernoulli ('100'::real) +(10 rows) + +select count(*) from person tablesample bernoulli (100); + count +------- + 58 (1 row) -EXPLAIN SELECT * FROM test_tablesample_v1; - QUERY PLAN -------------------------------------------------------------------------------- - Sample Scan (system) on test_tablesample (cost=0.00..10.54 rows=254 width=4) +select count(*) from person; + count +------- + 58 +(1 row) + +-- check that collations get assigned within the tablesample arguments +SELECT count(*) FROM test_tablesample TABLESAMPLE bernoulli (('1'::text < '0'::text)::int); + count +------- + 0 +(1 row) + +-- check behavior during rescans, as well as correct handling of min/max pct +select * from + (values (0),(100)) v(pct), + lateral (select count(*) from tenk1 tablesample bernoulli (pct)) ss; + pct | count +-----+------- + 0 | 0 + 100 | 10000 +(2 rows) + +select * from + (values (0),(100)) v(pct), + lateral (select count(*) from tenk1 tablesample system (pct)) ss; + pct | count +-----+------- + 0 | 0 + 100 | 10000 +(2 rows) + +explain (costs off) +select pct, count(unique1) from + (values (0),(100)) v(pct), + lateral (select * from tenk1 tablesample bernoulli (pct)) ss + group by pct; + QUERY PLAN +-------------------------------------------------------- + HashAggregate + Group Key: "*VALUES*".column1 + -> Nested Loop + -> Values Scan on "*VALUES*" + -> Sample Scan on tenk1 + Sampling: bernoulli ("*VALUES*".column1) +(6 rows) + +select pct, count(unique1) from + (values (0),(100)) v(pct), + lateral (select * from tenk1 tablesample bernoulli (pct)) ss + group by pct; + pct | count +-----+------- + 100 | 10000 +(1 row) + +select pct, count(unique1) from + (values (0),(100)) v(pct), + lateral (select * from tenk1 tablesample system (pct)) ss + group by pct; + pct | count +-----+------- + 100 | 10000 (1 row) -- errors SELECT id FROM test_tablesample TABLESAMPLE FOOBAR (1); -ERROR: tablesample method "foobar" does not exist +ERROR: tablesample method foobar does not exist LINE 1: SELECT id FROM test_tablesample TABLESAMPLE FOOBAR (1); - ^ + ^ +SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (NULL); +ERROR: TABLESAMPLE parameter cannot be null SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (NULL); -ERROR: REPEATABLE clause must be NOT NULL numeric value -LINE 1: ... test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (NULL); - ^ +ERROR: TABLESAMPLE REPEATABLE parameter cannot be null SELECT id FROM test_tablesample TABLESAMPLE BERNOULLI (-1); -ERROR: invalid sample size -HINT: Sample size must be numeric value between 0 and 100 (inclusive). +ERROR: sample percentage must be between 0 and 100 SELECT id FROM test_tablesample TABLESAMPLE BERNOULLI (200); -ERROR: invalid sample size -HINT: Sample size must be numeric value between 0 and 100 (inclusive). +ERROR: sample percentage must be between 0 and 100 SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (-1); -ERROR: invalid sample size -HINT: Sample size must be numeric value between 0 and 100 (inclusive). +ERROR: sample percentage must be between 0 and 100 SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (200); -ERROR: invalid sample size -HINT: Sample size must be numeric value between 0 and 100 (inclusive). +ERROR: sample percentage must be between 0 and 100 SELECT id FROM test_tablesample_v1 TABLESAMPLE BERNOULLI (1); -ERROR: TABLESAMPLE clause can only be used on tables and materialized views +ERROR: TABLESAMPLE clause can only be applied to tables and materialized views LINE 1: SELECT id FROM test_tablesample_v1 TABLESAMPLE BERNOULLI (1)... ^ INSERT INTO test_tablesample_v1 VALUES(1); @@ -202,30 +306,10 @@ DETAIL: Views containing TABLESAMPLE are not automatically updatable. HINT: To enable inserting into the view, provide an INSTEAD OF INSERT trigger or an unconditional ON INSERT DO INSTEAD rule. WITH query_select AS (SELECT * FROM test_tablesample) SELECT * FROM query_select TABLESAMPLE BERNOULLI (5.5) REPEATABLE (1); -ERROR: TABLESAMPLE clause can only be used on tables and materialized views +ERROR: TABLESAMPLE clause can only be applied to tables and materialized views LINE 2: SELECT * FROM query_select TABLESAMPLE BERNOULLI (5.5) REPEA... ^ SELECT q.* FROM (SELECT * FROM test_tablesample) as q TABLESAMPLE BERNOULLI (5); ERROR: syntax error at or near "TABLESAMPLE" LINE 1: ...CT q.* FROM (SELECT * FROM test_tablesample) as q TABLESAMPL... ^ --- catalog sanity -SELECT * -FROM pg_tablesample_method -WHERE tsminit IS NULL - OR tsmseqscan IS NULL - OR tsmpagemode IS NULL - OR tsmnextblock IS NULL - OR tsmnexttuple IS NULL - OR tsmend IS NULL - OR tsmreset IS NULL - OR tsmcost IS NULL; - tsmname | tsmseqscan | tsmpagemode | tsminit | tsmnextblock | tsmnexttuple | tsmexaminetuple | tsmend | tsmreset | tsmcost ----------+------------+-------------+---------+--------------+--------------+-----------------+--------+----------+--------- -(0 rows) - --- done -DROP TABLE test_tablesample CASCADE; -NOTICE: drop cascades to 2 other objects -DETAIL: drop cascades to view test_tablesample_v1 -drop cascades to view test_tablesample_v2 diff --git a/src/test/regress/output/misc.source b/src/test/regress/output/misc.source index 70c9cc356a6..9eedb363d06 100644 --- a/src/test/regress/output/misc.source +++ b/src/test/regress/output/misc.source @@ -686,6 +686,9 @@ SELECT user_relns() AS user_relns test_range_excl test_range_gist test_range_spgist + test_tablesample + test_tablesample_v1 + test_tablesample_v2 test_tsvector testjsonb text_tbl @@ -705,7 +708,7 @@ SELECT user_relns() AS user_relns tvvmv varchar_tbl xacttest -(127 rows) +(130 rows) SELECT name(equipment(hobby_construct(text 'skywalking', text 'mer'))); name diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule index 3a607cff46c..15d74d4e6eb 100644 --- a/src/test/regress/serial_schedule +++ b/src/test/regress/serial_schedule @@ -110,6 +110,7 @@ test: lock test: replica_identity test: rowsecurity test: object_address +test: tablesample test: alter_generic test: alter_operator test: misc @@ -156,4 +157,3 @@ test: with test: xml test: event_trigger test: stats -test: tablesample diff --git a/src/test/regress/sql/rowsecurity.sql b/src/test/regress/sql/rowsecurity.sql index 039070b85b7..e86f8143142 100644 --- a/src/test/regress/sql/rowsecurity.sql +++ b/src/test/regress/sql/rowsecurity.sql @@ -94,14 +94,18 @@ SET row_security TO ON; SELECT * FROM document WHERE f_leak(dtitle) ORDER BY did; SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle) ORDER BY did; -SELECT * FROM document TABLESAMPLE BERNOULLI (50) REPEATABLE(1) WHERE f_leak(dtitle) ORDER BY did; +-- try a sampled version +SELECT * FROM document TABLESAMPLE BERNOULLI(50) REPEATABLE(0) + WHERE f_leak(dtitle) ORDER BY did; -- viewpoint from rls_regress_user2 SET SESSION AUTHORIZATION rls_regress_user2; SELECT * FROM document WHERE f_leak(dtitle) ORDER BY did; SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle) ORDER BY did; -SELECT * FROM document TABLESAMPLE BERNOULLI (50) REPEATABLE(1) WHERE f_leak(dtitle) ORDER BY did; +-- try a sampled version +SELECT * FROM document TABLESAMPLE BERNOULLI(50) REPEATABLE(0) + WHERE f_leak(dtitle) ORDER BY did; EXPLAIN (COSTS OFF) SELECT * FROM document WHERE f_leak(dtitle); EXPLAIN (COSTS OFF) SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle); diff --git a/src/test/regress/sql/tablesample.sql b/src/test/regress/sql/tablesample.sql index 7b3eb9bedf7..eec97934966 100644 --- a/src/test/regress/sql/tablesample.sql +++ b/src/test/regress/sql/tablesample.sql @@ -1,26 +1,37 @@ -CREATE TABLE test_tablesample (id int, name text) WITH (fillfactor=10); -- force smaller pages so we don't have to load too much data to get multiple pages +CREATE TABLE test_tablesample (id int, name text) WITH (fillfactor=10); +-- use fillfactor so we don't have to load too much data to get multiple pages -INSERT INTO test_tablesample SELECT i, repeat(i::text, 200) FROM generate_series(0, 9) s(i) ORDER BY i; +INSERT INTO test_tablesample + SELECT i, repeat(i::text, 200) FROM generate_series(0, 9) s(i); -SELECT t.id FROM test_tablesample AS t TABLESAMPLE SYSTEM (50) REPEATABLE (10); -SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (100.0/11) REPEATABLE (9999); +SELECT t.id FROM test_tablesample AS t TABLESAMPLE SYSTEM (50) REPEATABLE (0); +SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (100.0/11) REPEATABLE (0); +SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (0); +SELECT id FROM test_tablesample TABLESAMPLE BERNOULLI (50) REPEATABLE (0); +SELECT id FROM test_tablesample TABLESAMPLE BERNOULLI (5.5) REPEATABLE (0); + +-- 100% should give repeatable count results (ie, all rows) in any case SELECT count(*) FROM test_tablesample TABLESAMPLE SYSTEM (100); -SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (100); -SELECT id FROM test_tablesample TABLESAMPLE BERNOULLI (50) REPEATABLE (100); -SELECT id FROM test_tablesample TABLESAMPLE BERNOULLI (5.5) REPEATABLE (1); +SELECT count(*) FROM test_tablesample TABLESAMPLE SYSTEM (100) REPEATABLE (1+2); +SELECT count(*) FROM test_tablesample TABLESAMPLE SYSTEM (100) REPEATABLE (0.4); -CREATE VIEW test_tablesample_v1 AS SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (10*2) REPEATABLE (2); -CREATE VIEW test_tablesample_v2 AS SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (99); -SELECT pg_get_viewdef('test_tablesample_v1'::regclass); -SELECT pg_get_viewdef('test_tablesample_v2'::regclass); +CREATE VIEW test_tablesample_v1 AS + SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (10*2) REPEATABLE (2); +CREATE VIEW test_tablesample_v2 AS + SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (99); +\d+ test_tablesample_v1 +\d+ test_tablesample_v2 +-- check a sampled query doesn't affect cursor in progress BEGIN; -DECLARE tablesample_cur CURSOR FOR SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (100); +DECLARE tablesample_cur CURSOR FOR + SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (0); + FETCH FIRST FROM tablesample_cur; FETCH NEXT FROM tablesample_cur; FETCH NEXT FROM tablesample_cur; -SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (10); +SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (0); FETCH NEXT FROM tablesample_cur; FETCH NEXT FROM tablesample_cur; @@ -36,12 +47,45 @@ FETCH NEXT FROM tablesample_cur; CLOSE tablesample_cur; END; -EXPLAIN SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (10); -EXPLAIN SELECT * FROM test_tablesample_v1; +EXPLAIN (COSTS OFF) + SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (2); +EXPLAIN (COSTS OFF) + SELECT * FROM test_tablesample_v1; + +-- check inheritance behavior +explain (costs off) + select count(*) from person tablesample bernoulli (100); +select count(*) from person tablesample bernoulli (100); +select count(*) from person; + +-- check that collations get assigned within the tablesample arguments +SELECT count(*) FROM test_tablesample TABLESAMPLE bernoulli (('1'::text < '0'::text)::int); + +-- check behavior during rescans, as well as correct handling of min/max pct +select * from + (values (0),(100)) v(pct), + lateral (select count(*) from tenk1 tablesample bernoulli (pct)) ss; +select * from + (values (0),(100)) v(pct), + lateral (select count(*) from tenk1 tablesample system (pct)) ss; +explain (costs off) +select pct, count(unique1) from + (values (0),(100)) v(pct), + lateral (select * from tenk1 tablesample bernoulli (pct)) ss + group by pct; +select pct, count(unique1) from + (values (0),(100)) v(pct), + lateral (select * from tenk1 tablesample bernoulli (pct)) ss + group by pct; +select pct, count(unique1) from + (values (0),(100)) v(pct), + lateral (select * from tenk1 tablesample system (pct)) ss + group by pct; -- errors SELECT id FROM test_tablesample TABLESAMPLE FOOBAR (1); +SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (NULL); SELECT id FROM test_tablesample TABLESAMPLE SYSTEM (50) REPEATABLE (NULL); SELECT id FROM test_tablesample TABLESAMPLE BERNOULLI (-1); @@ -56,19 +100,3 @@ WITH query_select AS (SELECT * FROM test_tablesample) SELECT * FROM query_select TABLESAMPLE BERNOULLI (5.5) REPEATABLE (1); SELECT q.* FROM (SELECT * FROM test_tablesample) as q TABLESAMPLE BERNOULLI (5); - --- catalog sanity - -SELECT * -FROM pg_tablesample_method -WHERE tsminit IS NULL - OR tsmseqscan IS NULL - OR tsmpagemode IS NULL - OR tsmnextblock IS NULL - OR tsmnexttuple IS NULL - OR tsmend IS NULL - OR tsmreset IS NULL - OR tsmcost IS NULL; - --- done -DROP TABLE test_tablesample CASCADE; |
