BUG #4170: Rows estimation which are cast from TEXT is inaccurate. - Mailing list pgsql-bugs

From Tashuhito Kasahara
Subject BUG #4170: Rows estimation which are cast from TEXT is inaccurate.
Date
Msg-id 200805151132.m4FBWaYo028791@wwwmaster.postgresql.org
Whole thread Raw
Responses Re: BUG #4170: Rows estimation which are cast from TEXT is inaccurate.
List pgsql-bugs
The following bug has been logged online:

Bug reference:      4170
Logged by:          Tashuhito Kasahara
Email address:      kasahara.tatsuhito@oss.ntt.co.jp
PostgreSQL version: 8.3.1
Operating system:   Linux
Description:        Rows estimation which are cast from TEXT  is inaccurate.
Details:

I noticed that rows estimation is not accurate when we cast some datetype to
TEXT.
See the following example. (TEXT -> TIMESTAMP)

============================================================================
====
test=# SELECT count(*) FROM test WHERE t < '2008-05-14 23:55:00';
 count
-------
 86099
(1 row)

test=# EXPLAIN SELECT * FROM test WHERE t < '2008-05-14 23:55:00';
                             QUERY PLAN
--------------------------------------------------------------------
 Seq Scan on test  (cost=0.00..1727.00 rows=85721 width=12)
   Filter: (t < '2008-05-14 23:55:00'::timestamp without time zone)
(2 rows)


test=# EXPLAIN SELECT * FROM test WHERE t < '2008-05-14
23:55:00'::text::timestamp;
                                 QUERY PLAN
----------------------------------------------------------------------------

 Seq Scan on test  (cost=0.00..2209.00 rows=32133 width=12)  <- too little
number of the estimates
   Filter: (t < ('2008-05-14 23:55:00'::text)::timestamp without time zone)
(2 rows)

test=# SELECT count(*) FROM test WHERE t < '2008-05-14 23:55:00';
 count
-------
 86099
(1 row)
============================================================================
====

We can avoid this problem by setting appropriate cast-function.

============================================================================
====
CREATE FUNCTION text2timestamp(text) RETURNS timestamp AS
$$
    SELECT timestamp_in(textout($1), 0, 0);
$$
LANGUAGE sql STRICT STABLE;

CREATE CAST (text AS timestamp) WITH FUNCTION text2timestamp(text) AS
ASSIGNMENT;

test=# EXPLAIN SELECT * FROM test WHERE t < '2008-05-14
23:55:00'::text::timestamp;
                               QUERY PLAN
-------------------------------------------------------------------------
 Seq Scan on test  (cost=0.00..1968.00 rows=85721 width=12)
   Filter: (t < timestamp_in('2008-05-14 23:55:00'::cstring, 0::oid, 0))
(2 rows)
============================================================================
====

I think it's a bug and will be troubled at plan optimization.

Best regards.

pgsql-bugs by date:

Previous
From: "shohorab hossain"
Date:
Subject: BUG #4169: Problem in installing
Next
From: shohorab hossain
Date:
Subject: problem in installing pgsql-8.3.1