postgresql/contrib/tsm_system_rows/sql/tsm_system_rows.sql
Tom Lane dd7a8f66ed Redesign tablesample method API, and do extensive code review.
The original implementation of TABLESAMPLE modeled the tablesample method
API on index access methods, which wasn't a good choice because, without
specialized DDL commands, there's no way to build an extension that can
implement a TSM.  (Raw inserts into system catalogs are not an acceptable
thing to do, because we can't undo them during DROP EXTENSION, nor will
pg_upgrade behave sanely.)  Instead adopt an API more like procedural
language handlers or foreign data wrappers, wherein the only SQL-level
support object needed is a single handler function identified by having
a special return type.  This lets us get rid of the supporting catalog
altogether, so that no custom DDL support is needed for the feature.

Adjust the API so that it can support non-constant tablesample arguments
(the original coding assumed we could evaluate the argument expressions at
ExecInitSampleScan time, which is undesirable even if it weren't outright
unsafe), and discourage sampling methods from looking at invisible tuples.
Make sure that the BERNOULLI and SYSTEM methods are genuinely repeatable
within and across queries, as required by the SQL standard, and deal more
honestly with methods that can't support that requirement.

Make a full code-review pass over the tablesample additions, and fix
assorted bugs, omissions, infelicities, and cosmetic issues (such as
failure to put the added code stanzas in a consistent ordering).
Improve EXPLAIN's output of tablesample plans, too.

Back-patch to 9.5 so that we don't have to support the original API
in production.
2015-07-25 14:39:00 -04:00

40 lines
1.3 KiB
SQL

CREATE EXTENSION tsm_system_rows;
CREATE TABLE test_tablesample (id int, name text);
INSERT INTO test_tablesample SELECT i, repeat(i::text, 1000)
FROM generate_series(0, 30) s(i);
ANALYZE test_tablesample;
SELECT count(*) FROM test_tablesample TABLESAMPLE system_rows (0);
SELECT count(*) FROM test_tablesample TABLESAMPLE system_rows (1);
SELECT count(*) FROM test_tablesample TABLESAMPLE system_rows (10);
SELECT count(*) FROM test_tablesample TABLESAMPLE system_rows (100);
-- bad parameters should get through planning, but not execution:
EXPLAIN (COSTS OFF)
SELECT id FROM test_tablesample TABLESAMPLE system_rows (-1);
SELECT id FROM test_tablesample TABLESAMPLE system_rows (-1);
-- fail, this method is not repeatable:
SELECT * FROM test_tablesample TABLESAMPLE system_rows (10) REPEATABLE (0);
-- but a join should be allowed:
EXPLAIN (COSTS OFF)
SELECT * FROM
(VALUES (0),(10),(100)) v(nrows),
LATERAL (SELECT count(*) FROM test_tablesample
TABLESAMPLE system_rows (nrows)) ss;
SELECT * FROM
(VALUES (0),(10),(100)) v(nrows),
LATERAL (SELECT count(*) FROM test_tablesample
TABLESAMPLE system_rows (nrows)) ss;
CREATE VIEW vv AS
SELECT count(*) FROM test_tablesample TABLESAMPLE system_rows (20);
SELECT * FROM vv;
DROP EXTENSION tsm_system_rows; -- fail, view depends on extension