On Tue, Aug 09, 2005 at 09:29:13PM -0600, Michael Fuhr wrote: > On Tue, Aug 09, 2005 at 10:49:14PM -0400, Tom Lane wrote: > > Current best practice is to run the explain and parse out the "rows" > > figure using a perl (or axe-of-choice) regexp, though we could be > > persuaded to supply a simpler API if there's enough demand for it. > > Somebody else requested a row-count-estimate function a couple of > weeks ago: > > http://archives.postgresql.org/pgsql-admin/2005-07/msg00256.php
Here's a simple example that parses EXPLAIN output. It should work in 8.0.2 and later: CREATE FUNCTION count_estimate(query text) RETURNS integer AS $$ DECLARE rec record; rows integer; BEGIN FOR rec IN EXECUTE 'EXPLAIN ' || query LOOP rows := substring(rec."QUERY PLAN" FROM ' rows=([[:digit:]]+)'); EXIT WHEN rows IS NOT NULL; END LOOP; RETURN rows; END; $$ LANGUAGE plpgsql VOLATILE STRICT; CREATE TABLE foo (r double precision); INSERT INTO foo SELECT random() FROM generate_series(1, 1000); ANALYZE foo; SELECT count_estimate('SELECT * FROM foo WHERE r < 0.1'); count_estimate ---------------- 97 (1 row) EXPLAIN SELECT * FROM foo WHERE r < 0.1; QUERY PLAN ----------------------------------------------------- Seq Scan on foo (cost=0.00..17.50 rows=97 width=8) Filter: (r < 0.1::double precision) (2 rows) -- Michael Fuhr ---------------------------(end of broadcast)--------------------------- TIP 9: In versions below 8.0, the planner will ignore your desire to choose an index scan if your joining column's datatypes do not match