diff options
author | Tom Lane <tgl@sss.pgh.pa.us> | 2021-11-12 11:50:40 -0500 |
---|---|---|
committer | Tom Lane <tgl@sss.pgh.pa.us> | 2021-11-12 11:50:47 -0500 |
commit | f8abb0f5e114d8c309239f0faa277b97f696d829 (patch) | |
tree | 59d8de186271a28400980decb704f37bb76cf1e2 /contrib/postgres_fdw/sql | |
parent | 1593998ae858902e805eb0f8bf3b019399044471 (diff) | |
download | postgresql-f8abb0f5e114d8c309239f0faa277b97f696d829.tar.gz postgresql-f8abb0f5e114d8c309239f0faa277b97f696d829.zip |
postgres_fdw: suppress casts on constants in limited cases.
When deparsing an expression of the form "remote_var OP constant",
we'd normally apply a cast to the constant to make sure that the
remote parser thinks it's of the same type we do. However, doing
so is often not necessary, and it causes problems if the user has
intentionally declared the local column as being of a different
type than the remote column. A plausible use-case for that is
using text to represent a type that's an enum on the remote side.
A comparison on such a column will get shipped as "var = 'foo'::text",
which blows up on the remote side because there's no enum = text
operator. But if we simply leave off the explicit cast, the
comparison will do exactly what the user wants.
It's possible to do this without major risk of semantic problems, by
relying on the longstanding parser heuristic that "if one operand of
an operator is of type unknown, while the other one has a known type,
assume that the unknown operand is also of that type". Hence, this
patch leaves off the cast only if (a) the operator inputs have the same
type locally; (b) the constant will print as a string literal or NULL,
both of which are initially taken as type unknown; and (c) the non-Const
input is a plain foreign Var. Rule (c) guarantees that the remote
parser will know the type of the non-Const input; moreover, it means
that if this cast-omission does cause any semantic surprises, that can
only happen in cases where the local column has a different type than
the remote column. That wasn't guaranteed to work anyway, and this
patch should represent a net usability gain for such cases.
One point that I (tgl) remain slightly uncomfortable with is that we
will ignore an implicit RelabelType when deciding if the non-Const input
is a plain Var. That makes it a little squishy to argue that the remote
should resolve the Const as being of the same type as its Var, because
then our Const is not the same type as our Var. However, if we don't do
that, then this hack won't work as desired if the user chooses to use
varchar rather than text to represent some remote column. That seems
useful, so do it like this for now. We might have to give up the
RelabelType-ignoring bit if any problems surface.
Dian Fay, with review and kibitzing by me
Discussion: https://postgr.es/m/C9LU294V7K4F.34LRRDU449O45@lamia
Diffstat (limited to 'contrib/postgres_fdw/sql')
-rw-r--r-- | contrib/postgres_fdw/sql/postgres_fdw.sql | 18 |
1 files changed, 18 insertions, 0 deletions
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql index 43c30d492da..e40112e41d3 100644 --- a/contrib/postgres_fdw/sql/postgres_fdw.sql +++ b/contrib/postgres_fdw/sql/postgres_fdw.sql @@ -1168,6 +1168,24 @@ ANALYZE ft1; -- ERROR ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum; -- =================================================================== +-- local type can be different from remote type in some cases, +-- in particular if similarly-named operators do equivalent things +-- =================================================================== +ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE text; +EXPLAIN (VERBOSE, COSTS OFF) +SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1; +SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1; +EXPLAIN (VERBOSE, COSTS OFF) +SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1; +SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1; +-- we declared c8 to be text locally, but it's still the same type on +-- the remote which will balk if we try to do anything incompatible +-- with that remote type +SELECT * FROM ft1 WHERE c8 LIKE 'foo' LIMIT 1; -- ERROR +SELECT * FROM ft1 WHERE c8::text LIKE 'foo' LIMIT 1; -- ERROR; cast not pushed down +ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum; + +-- =================================================================== -- subtransaction -- + local/remote error doesn't break cursor -- =================================================================== |