parent
795d92da8d
commit
a486eed2e3
4
NEWS.md
4
NEWS.md
@ -1,3 +1,7 @@
|
|||||||
|
0.19.0 (2017-04-XX)
|
||||||
|
|
||||||
|
* Add new function `CDB_EstimateRowCount` #295
|
||||||
|
|
||||||
0.18.5 (2016-11-30)
|
0.18.5 (2016-11-30)
|
||||||
|
|
||||||
* Add to new overview creation strategies #290
|
* Add to new overview creation strategies #290
|
||||||
|
25
doc/CDB_EstimateRowCount.md
Normal file
25
doc/CDB_EstimateRowCount.md
Normal file
@ -0,0 +1,25 @@
|
|||||||
|
Estimate the number of rows of a query.
|
||||||
|
|
||||||
|
|
||||||
|
#### Using the function
|
||||||
|
|
||||||
|
```sql
|
||||||
|
SELECT CDB_EstimateRowCount($$
|
||||||
|
UPDATE addresses SET the_geom = cdb_geocode_street_point(addr, city, state, 'US');
|
||||||
|
$$) AS row_count;
|
||||||
|
```
|
||||||
|
|
||||||
|
Result:
|
||||||
|
|
||||||
|
```
|
||||||
|
row_count
|
||||||
|
-----------
|
||||||
|
5
|
||||||
|
(1 row)
|
||||||
|
```
|
||||||
|
|
||||||
|
#### Arguments
|
||||||
|
|
||||||
|
CDB_EstimateRowCount(query)
|
||||||
|
|
||||||
|
* **query** text: the SQL query to estimate the row count for.
|
29
scripts-available/CDB_EstimateRowCount.sql
Normal file
29
scripts-available/CDB_EstimateRowCount.sql
Normal file
@ -0,0 +1,29 @@
|
|||||||
|
-- Internal function to generate stats for a table if they don't exist
|
||||||
|
CREATE OR REPLACE FUNCTION _CDB_GenerateStats(reloid REGCLASS)
|
||||||
|
RETURNS VOID
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
num_cols INTEGER;
|
||||||
|
BEGIN
|
||||||
|
SELECT COUNT(*) FROM pg_catalog.pg_statistic WHERE starelid = reloid INTO num_cols;
|
||||||
|
IF num_cols = 0 THEN
|
||||||
|
EXECUTE Format('ANALYZE %s;', reloid);
|
||||||
|
END IF;
|
||||||
|
END
|
||||||
|
$$ LANGUAGE 'plpgsql' VOLATILE STRICT SECURITY DEFINER;
|
||||||
|
|
||||||
|
-- Return a row count estimate of the result of a query using statistics
|
||||||
|
CREATE OR REPLACE FUNCTION CDB_EstimateRowCount(query text)
|
||||||
|
RETURNS Numeric
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
plan JSON;
|
||||||
|
BEGIN
|
||||||
|
-- Make sure statistics exist for all the tables of the query
|
||||||
|
PERFORM _CDB_GenerateStats(tabname) FROM unnest(CDB_QueryTablesText(query)) AS tabname;
|
||||||
|
|
||||||
|
-- Use the query planner to obtain an estimate of the number of result rows
|
||||||
|
EXECUTE 'EXPLAIN (FORMAT JSON) ' || query INTO STRICT plan;
|
||||||
|
RETURN plan->0->'Plan'->'Plan Rows';
|
||||||
|
END
|
||||||
|
$$ LANGUAGE 'plpgsql' VOLATILE STRICT;
|
1
scripts-enabled/280-CDB_EstimateRowCount.sql
Symbolic link
1
scripts-enabled/280-CDB_EstimateRowCount.sql
Symbolic link
@ -0,0 +1 @@
|
|||||||
|
../scripts-available/CDB_EstimateRowCount.sql
|
10
test/CDB_EstimateRowCountTest.sql
Normal file
10
test/CDB_EstimateRowCountTest.sql
Normal file
@ -0,0 +1,10 @@
|
|||||||
|
SET client_min_messages TO error;
|
||||||
|
\set VERBOSITY terse
|
||||||
|
CREATE TABLE tmptab1(id INT);
|
||||||
|
INSERT INTO tmptab1(id) VALUES (1), (2), (3);
|
||||||
|
CREATE TABLE tmptab2(id INT, value NUMERIC);
|
||||||
|
INSERT INTO tmptab2(id, value) VALUES (1, 10.0), (2, 20.0);
|
||||||
|
SELECT CDB_EstimateRowCount('SELECT SUM(value) FROM tmptab1 INNER JOIN tmptab2 ON (tmptab1.id = tmptab2.id);') AS row_count;
|
||||||
|
SELECT CDB_EstimateRowCount('UPDATE tmptab2 SET value = 30 WHERE id=2;') AS row_count;
|
||||||
|
DROP TABLE tmptab2;
|
||||||
|
DROP TABLE tmptab1;
|
9
test/CDB_EstimateRowCountTest_expect
Normal file
9
test/CDB_EstimateRowCountTest_expect
Normal file
@ -0,0 +1,9 @@
|
|||||||
|
SET
|
||||||
|
CREATE TABLE
|
||||||
|
INSERT 0 3
|
||||||
|
CREATE TABLE
|
||||||
|
INSERT 0 2
|
||||||
|
1
|
||||||
|
1
|
||||||
|
DROP TABLE
|
||||||
|
DROP TABLE
|
Loading…
Reference in New Issue
Block a user