Thread: BUG #17052: Incorrect params inferred on PREPARE (part 2)

BUG #17052: Incorrect params inferred on PREPARE (part 2)

From
PG Bug reporting form
Date:
The following bug has been logged on the website:

Bug reference:      17052
Logged by:          Arthur McGibbon
Email address:      arthur.mcgibbon@gmail.com
PostgreSQL version: 13.3
Operating system:   Windows + wsl2 + docker
Description:

Using the table...

  CREATE TABLE testSchema.testTable (timestampCol timestamp);

...and preparing the query...

  PREPARE testQuery (unknown) AS
  UPDATE testSchema.testTable
  SET timestampCol = $1 + interval '1 minute';

...results in an error...

ERROR:  column "timestampcol" is of type timestamp without time zone but
expression is of type interval
LINE 4:   set timestampCol = $1 + interval '1 minute';
                             ^
HINT:  You will need to rewrite or cast the expression.
SQL state: 42804
Character: 82

Specifying the parameter as timestamp works without error...
  PREPARE testQuery (timestamp) AS
  UPDATE testSchema.testTable
  SET timestampCol = $1 + interval '1 minute';

as does casting...
  PREPARE testQuery (unknown) AS
  UPDATE testSchema.testTable
  SET timestampCol = cast($1 as timestamp) + interval '1 minute';


I'd hope that PostgreSQL would infer a "timestamp" type here instead of an
interval type

It seems in this case (and possibly in bug report 17051) Postgres uses only
a section of the expression to evaluate the parameter type i.e. "$1 +
interval '1 minute'" and assumes that only an interval type can be added to
an interval type but there are a number of types that can be added to an
interval type and ideally it would take into account the result of the
expression which has to be a timestamp (because of the definition of the
timestampCol column) and so work out that the only (or best) way to achieve
that is to have $1 be of type timestamp.


Re: BUG #17052: Incorrect params inferred on PREPARE (part 2)

From
"David G. Johnston"
Date:


On Tuesday, June 8, 2021, PG Bug reporting form <noreply@postgresql.org> wrote:

I'd hope that PostgreSQL would infer a "timestamp" type here instead of an
interval type

It seems in this case (and possibly in bug report 17051) Postgres uses only
a section of the expression to evaluate the parameter type i.e. "$1 +
interval '1 minute'" and assumes that only an interval type can be added to
an interval type but there are a number of types that can be added to an
interval type and ideally it would take into account the result of the
expression which has to be a timestamp (because of the definition of the
timestampCol column) and so work out that the only (or best) way to achieve
that is to have $1 be of type timestamp.


Maybe, but the failure to do so does not constitute a bug.

David J.

Re: BUG #17052: Incorrect params inferred on PREPARE (part 2)

From
Tom Lane
Date:
PG Bug reporting form <noreply@postgresql.org> writes:
>   SET timestampCol = $1 + interval '1 minute';
> ...results in an error...
> ERROR:  column "timestampcol" is of type timestamp without time zone but
> expression is of type interval
> LINE 4:   set timestampCol = $1 + interval '1 minute';
>                              ^

As in your other report, the context in which the parameter type is
guessed is just the immediate context of the plus-operator expression.
The relevant rule there is "guess that an unknown input is of the same
type as the other input", so we resolve the operator as interval + interval.

            regards, tom lane