The specific operator that is referenced by an operator expression is determined using the following procedure. Note that this procedure is indirectly affected by the precedence of the operators involved, since that will determine which sub-expressions are taken to be the inputs of which operators. See Section 4.1.6 for more information.
Operator Type Resolution
Select the operators to be considered from the pg_operator
system catalog. If a
non-schema-qualified operator name was used (the usual case), the
operators considered are those with the matching name and argument
count that are visible in the current search path (see Section 5.8.3). If a
qualified operator name was given, only operators in the specified
schema are considered.
If the search path finds multiple operators with identical argument types, only the one appearing earliest in the path is considered. Operators with different argument types are considered on an equal footing regardless of search path position.
Check for an operator accepting exactly the input argument types. If one exists (there can be only one exact match in the set of operators considered), use it.
If one argument of a binary operator invocation is of the
unknown
type, then assume it is the same
type as the other argument for this check. Invocations involving
two unknown
inputs, or a unary operator
with an unknown
input, will never find a
match at this step.
If one argument of a binary operator invocation is of the
unknown
type and the other is of a domain
type, next check to see if there is an operator accepting exactly
the domain's base type on both sides; if so, use it.
Look for the best match.
Discard candidate operators for which the input types do not
match and cannot be converted (using an implicit conversion) to
match. unknown
literals are assumed to be
convertible to anything for this purpose. If only one candidate
remains, use it; else continue to the next step.
If any input argument is of a domain type, treat it as being of the domain's base type for all subsequent steps. This ensures that domains act like their base types for purposes of ambiguous-operator resolution.
Run through all candidates and keep those with the most exact matches on input types. Keep all candidates if none have exact matches. If only one candidate remains, use it; else continue to the next step.
Run through all candidates and keep those that accept preferred types (of the input data type's type category) at the most positions where type conversion will be required. Keep all candidates if none accept preferred types. If only one candidate remains, use it; else continue to the next step.
If any input arguments are unknown
,
check the type categories accepted at those argument positions by
the remaining candidates. At each position, select the string
category if any candidate accepts that
category. (This bias towards string is appropriate since an
unknown-type literal looks like a string.) Otherwise, if all the
remaining candidates accept the same type category, select that
category; otherwise fail because the correct choice cannot be
deduced without more clues. Now discard candidates that do not
accept the selected type category. Furthermore, if any candidate
accepts a preferred type in that category, discard candidates that
accept non-preferred types for that argument. Keep all candidates
if none survive these tests. If only one candidate remains, use it;
else continue to the next step.
If there are both unknown
and
known-type arguments, and all the known-type arguments have the
same type, assume that the unknown
arguments are also of that type, and check which candidates can
accept that type at the unknown
-argument
positions. If exactly one candidate passes this test, use it.
Otherwise, fail.
Some examples follow.
Example 10.1. Factorial Operator Type Resolution
There is only one factorial operator (postfix !
) defined in the standard catalog, and it takes
an argument of type bigint
. The scanner
assigns an initial type of integer
to the
argument in this query expression:
SELECT 40 ! AS "40 factorial"; 40 factorial -------------------------------------------------- 815915283247897734345611269596115894272000000000 (1 row)
So the parser does a type conversion on the operand and the query is equivalent to:
SELECT CAST(40 AS bigint) ! AS "40 factorial";
Example 10.2. String Concatenation Operator Type Resolution
A string-like syntax is used for working with string types and for working with complex extension types. Strings with unspecified type are matched with likely operator candidates.
An example with one unspecified argument:
SELECT text 'abc' || 'def' AS "text and unknown"; text and unknown ------------------ abcdef (1 row)
In this case the parser looks to see if there is an operator
taking text
for both arguments. Since
there is, it assumes that the second argument should be interpreted
as type text
.
Here is a concatenation of two values of unspecified types:
SELECT 'abc' || 'def' AS "unspecified"; unspecified ------------- abcdef (1 row)
In this case there is no initial hint for which type to use,
since no types are specified in the query. So, the parser looks for
all candidate operators and finds that there are candidates
accepting both string-category and bit-string-category inputs.
Since string category is preferred when available, that category is
selected, and then the preferred type for strings, text
, is used as the specific type to resolve the
unknown-type literals as.
Example 10.3. Absolute-Value and Negation Operator Type Resolution
The PostgreSQL operator catalog
has several entries for the prefix operator @
, all of which implement absolute-value
operations for various numeric data types. One of these entries is
for type float8
, which is the preferred
type in the numeric category. Therefore, PostgreSQL will use that entry when faced with
an unknown
input:
SELECT @ '-4.5' AS "abs"; abs ----- 4.5 (1 row)
Here the system has implicitly resolved the unknown-type literal
as type float8
before applying the chosen
operator. We can verify that float8
and
not some other type was used:
SELECT @ '-4.5e500' AS "abs"; ERROR: "-4.5e500" is out of range for type double precision
On the other hand, the prefix operator ~
(bitwise negation) is defined only for integer
data types, not for float8
. So, if we try
a similar case with ~
, we get:
SELECT ~ '20' AS "negation"; ERROR: operator is not unique: ~ "unknown" HINT: Could not choose a best candidate operator. You might need to add explicit type casts.
This happens because the system cannot decide which of the
several possible ~
operators should be
preferred. We can help it out with an explicit cast:
SELECT ~ CAST('20' AS int8) AS "negation"; negation ---------- -21 (1 row)
Example 10.4. Array Inclusion Operator Type Resolution
Here is another example of resolving an operator with one known and one unknown input:
SELECT array[1,2] <@ '{1,2,3}' as "is subset"; is subset ----------- t (1 row)
The PostgreSQL operator catalog
has several entries for the infix operator <@
, but the only two that could possibly accept
an integer array on the left-hand side are array inclusion
(anyarray
<@
anyarray
) and
range inclusion (anyelement
<@
anyrange
). Since
none of these polymorphic pseudo-types (see Section 8.20) are considered
preferred, the parser cannot resolve the ambiguity on that basis.
However, Step
3.f tells it to assume that the unknown-type literal is of the
same type as the other input, that is, integer array. Now only one
of the two operators can match, so array inclusion is selected.
(Had range inclusion been selected, we would have gotten an error,
because the string does not have the right format to be a range
literal.)
Example 10.5. Custom Operator on a Domain Type
Users sometimes try to declare operators applying just to a domain type. This is possible but is not nearly as useful as it might seem, because the operator resolution rules are designed to select operators applying to the domain's base type. As an example consider
CREATE DOMAIN mytext AS text CHECK(...); CREATE FUNCTION mytext_eq_text (mytext, text) RETURNS boolean AS ...; CREATE OPERATOR = (procedure=mytext_eq_text, leftarg=mytext, rightarg=text); CREATE TABLE mytable (val mytext); SELECT * FROM mytable WHERE val = 'foo';
This query will not use the custom operator. The parser will
first see if there is a mytext
=
mytext
operator (Step
2.a), which there is not; then it will consider the domain's
base type text
, and see if there is a
text
=
text
operator (Step
2.b), which there is; so it resolves the unknown
-type literal as text
and uses the text
=
text
operator. The only way to get the custom operator to be used is to
explicitly cast the literal:
SELECT * FROM mytable WHERE val = text 'foo';
so that the mytext
=
text
operator is found
immediately according to the exact-match rule. If the best-match
rules are reached, they actively discriminate against operators on
domain types. If they did not, such an operator would create too
many ambiguous-operator failures, because the casting rules always
consider a domain as castable to or from its base type, and so the
domain operator would be considered usable in all the same cases as
a similarly-named operator on the base type.
If you see anything in the documentation that is not correct, does not match your experience with the particular feature or requires further clarification, please use this form to report a documentation issue.