Type Conversion
data type
conversion
SQL statements can, intentionally or not, require
the mixing of different data types in the same expression.
PostgreSQL has extensive facilities for
evaluating mixed-type expressions.
In many cases a user does not need
to understand the details of the type conversion mechanism.
However, implicit conversions done by PostgreSQL
can affect the results of a query. When necessary, these results
can be tailored by using explicit type conversion.
This chapter introduces the PostgreSQL
type conversion mechanisms and conventions.
Refer to the relevant sections in and
for more information on specific data types and allowed functions and
operators.
Overview
SQL is a strongly typed language. That is, every data item
has an associated data type which determines its behavior and allowed usage.
PostgreSQL has an extensible type system that is
more general and flexible than other SQL implementations.
Hence, most type conversion behavior in PostgreSQL
is governed by general rules rather than by ad hoc>
heuristics. This allows the use of mixed-type expressions even with
user-defined types.
The PostgreSQL scanner/parser divides lexical
elements into five fundamental categories: integers, non-integer numbers,
strings, identifiers, and key words. Constants of most non-numeric types are
first classified as strings. The SQL language definition
allows specifying type names with strings, and this mechanism can be used in
PostgreSQL to start the parser down the correct
path. For example, the query:
SELECT text 'Origin' AS "label", point '(0,0)' AS "value";
label | value
--------+-------
Origin | (0,0)
(1 row)
has two literal constants, of type text and point.
If a type is not specified for a string literal, then the placeholder type
unknown is assigned initially, to be resolved in later
stages as described below.
There are four fundamental SQL constructs requiring
distinct type conversion rules in the PostgreSQL
parser:
Function calls
Much of the PostgreSQL type system is built around a
rich set of functions. Functions can have one or more arguments.
Since PostgreSQL permits function
overloading, the function name alone does not uniquely identify the function
to be called; the parser must select the right function based on the data
types of the supplied arguments.
Operators
PostgreSQL allows expressions with
prefix and postfix unary (one-argument) operators,
as well as binary (two-argument) operators. Like functions, operators can
be overloaded, so the same problem of selecting the right operator
exists.
Value Storage
SQL INSERT and UPDATE statements place the results of
expressions into a table. The expressions in the statement must be matched up
with, and perhaps converted to, the types of the target columns.
UNION, CASE, and related constructs
Since all query results from a unionized SELECT statement
must appear in a single set of columns, the types of the results of each
SELECT> clause must be matched up and converted to a uniform set.
Similarly, the result expressions of a CASE> construct must be
converted to a common type so that the CASE> expression as a whole
has a known output type. The same holds for ARRAY> constructs,
and for the GREATEST> and LEAST> functions.
The system catalogs store information about which conversions, or
casts, exist between which data types, and how to
perform those conversions. Additional casts can be added by the user
with the
command. (This is usually
done in conjunction with defining new data types. The set of casts
between built-in types has been carefully crafted and is best not
altered.)
data type
category
An additional heuristic provided by the parser allows improved determination
of the proper casting behavior among groups of types that have implicit casts.
Data types are divided into several basic type
categories, including boolean, numeric,
string, bitstring, datetime,
timespan, geometric, network, and
user-defined. (For a list see ;
but note it is also possible to create custom type categories.) Within each
category there can be one or more preferred types, which
are preferred when there is a choice of possible types. With careful selection
of preferred types and available implicit casts, it is possible to ensure that
ambiguous expressions (those with multiple candidate parsing solutions) can be
resolved in a useful way.
All type conversion rules are designed with several principles in mind:
Implicit conversions should never have surprising or unpredictable outcomes.
There should be no extra overhead in the parser or executor
if a query does not need implicit type conversion.
That is, if a query is well-formed and the types already match, then the query should execute
without spending extra time in the parser and without introducing unnecessary implicit conversion
calls in the query.
Additionally, if a query usually requires an implicit conversion for a function, and
if then the user defines a new function with the correct argument types, the parser
should use this new function and no longer do implicit conversion to use the old function.
Operators
operator
type resolution in an invocation
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 involved operators, since that will determine
which sub-expressions are taken to be the inputs of which operators.
See 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 ).
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.
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.
Run through all candidates and keep those with the most exact matches
on input types. (Domains are considered the same as their base type
for this purpose.) 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.
If only one candidate remains, use it. If no candidate or more than one
candidate remains,
then fail.
Some examples follow.
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";
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 on 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 literals as.
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)
Functions
function
type resolution in an invocation
The specific function that is referenced by a function call
is determined using the following procedure.
Function Type Resolution
Select the functions to be considered from the
pg_proc system catalog. If a non-schema-qualified
function name was used, the functions
considered are those with the matching name and argument count that are
visible in the current search path (see ).
If a qualified function name was given, only functions in the specified
schema are considered.
If the search path finds multiple functions of identical argument types,
only the one appearing earliest in the path is considered. Functions of
different argument types are considered on an equal footing regardless of
search path position.
If a function is declared with a VARIADIC> array parameter, and
the call does not use the VARIADIC> keyword, then the function
is treated as if the array parameter were replaced by one or more occurrences
of its element type, as needed to match the call. After such expansion the
function might have effective argument types identical to some non-variadic
function. In that case the function appearing earlier in the search path is
used, or if the two functions are in the same schema, the non-variadic one is
preferred.
Functions that have default values for parameters are considered to match any
call that omits zero or more of the defaultable parameter positions. If more
than one such function matches a call, the one appearing earliest in the
search path is used. If there are two or more such functions in the same
schema with identical parameter types in the non-defaulted positions (which is
possible if they have different sets of defaultable parameters), the system
will not be able to determine which to prefer, and so an ambiguous
function call> error will result if no better match to the call can be
found.
Check for a function accepting exactly the input argument types.
If one exists (there can be only one exact match in the set of
functions considered), use it.
(Cases involving unknown will never find a match at
this step.)
If no exact match is found, see if the function call appears
to be a special type conversion request. This happens if the function call
has just one argument and the function name is the same as the (internal)
name of some data type. Furthermore, the function argument must be either
an unknown-type literal, or a type that is binary-coercible to the named
data type, or a type that could be converted to the named data type by
applying that type's I/O functions (that is, the conversion is either to or
from one of the standard string types). When these conditions are met,
the function call is treated as a form of CAST> specification.
The reason for this step is to support function-style cast specifications
in cases where there is not an actual cast function. If there is a cast
function, it is conventionally named after its output type, and so there
is no need to have a special case. See
for additional commentary.
Look for the best match.
Discard candidate functions 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.
Run through all candidates and keep those with the most exact matches
on input types. (Domains are considered the same as their base type
for this purpose.) 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.
If only one candidate remains, use it. If no candidate or more than one
candidate remains,
then fail.
Note that the best match> rules are identical for operator and
function type resolution.
Some examples follow.
Rounding Function Argument Type Resolution
There is only one round function that takes two
arguments; it takes a first argument of type numeric and
a second argument of type integer.
So the following query automatically converts
the first argument of type integer to
numeric:
SELECT round(4, 4);
round
--------
4.0000
(1 row)
That query is actually transformed by the parser to:
SELECT round(CAST (4 AS numeric), 4);
Since numeric constants with decimal points are initially assigned the
type numeric, the following query will require no type
conversion and therefore might be slightly more efficient:
SELECT round(4.0, 4);
Substring Function Type Resolution
There are several substr functions, one of which
takes types text and integer. If called
with a string constant of unspecified type, the system chooses the
candidate function that accepts an argument of the preferred category
string (namely of type text).
SELECT substr('1234', 3);
substr
--------
34
(1 row)
If the string is declared to be of type varchar, as might be the case
if it comes from a table, then the parser will try to convert it to become text:
SELECT substr(varchar '1234', 3);
substr
--------
34
(1 row)
This is transformed by the parser to effectively become:
SELECT substr(CAST (varchar '1234' AS text), 3);
The parser learns from the pg_cast> catalog that
text and varchar
are binary-compatible, meaning that one can be passed to a function that
accepts the other without doing any physical conversion. Therefore, no
type conversion call is really inserted in this case.
And, if the function is called with an argument of type integer,
the parser will try to convert that to text:
SELECT substr(1234, 3);
ERROR: function substr(integer, integer) does not exist
HINT: No function matches the given name and argument types. You might need
to add explicit type casts.
This does not work because integer> does not have an implicit cast
to text>. An explicit cast will work, however:
SELECT substr(CAST (1234 AS text), 3);
substr
--------
34
(1 row)
Value Storage
Values to be inserted into a table are converted to the destination
column's data type according to the
following steps.
Value Storage Type Conversion
Check for an exact match with the target.
Otherwise, try to convert the expression to the target type. This will succeed
if there is a registered cast between the two types.
If the expression is an unknown-type literal, the contents of
the literal string will be fed to the input conversion routine for the target
type.
Check to see if there is a sizing cast for the target type. A sizing
cast is a cast from that type to itself. If one is found in the
pg_cast> catalog, apply it to the expression before storing
into the destination column. The implementation function for such a cast
always takes an extra parameter of type integer, which receives
the destination column's declared length (actually, its
atttypmod> value; the interpretation of
atttypmod> varies for different data types). The cast function
is responsible for applying any length-dependent semantics such as size
checking or truncation.
character Storage Type Conversion
For a target column declared as character(20) the following statement
ensures that the stored value is sized correctly:
CREATE TABLE vv (v character(20));
INSERT INTO vv SELECT 'abc' || 'def';
SELECT v, length(v) FROM vv;
v | length
----------------------+--------
abcdef | 20
(1 row)
What has really happened here is that the two unknown literals are resolved
to text by default, allowing the || operator
to be resolved as text concatenation. Then the text
result of the operator is converted to bpchar (blank-padded
char>, the internal name of the character data type) to match the target
column type. (Since the conversion from text to
bpchar is binary-coercible, this conversion does
not insert any real function call.) Finally, the sizing function
bpchar(bpchar, integer) is found in the system catalog
and applied to the operator's result and the stored column length. This
type-specific function performs the required length check and addition of
padding spaces.
UNION, CASE, and Related Constructs
UNION
determination of result type
CASE
determination of result type
ARRAY
determination of result type
VALUES
determination of result type
GREATEST
determination of result type
LEAST
determination of result type
SQL UNION> constructs must match up possibly dissimilar
types to become a single result set. The resolution algorithm is
applied separately to each output column of a union query. The
INTERSECT> and EXCEPT> constructs resolve
dissimilar types in the same way as UNION>. The
CASE>, ARRAY>, VALUES>,
GREATEST> and LEAST> constructs use the identical
algorithm to match up their component expressions and select a result
data type.
Type Resolution for UNION, CASE,
and Related Constructs
If all inputs are of the same type, and it is not unknown,
resolve as that type. Otherwise, replace any domain types in the list with
their underlying base types.
If all inputs are of type unknown, resolve as type
text (the preferred type of the string category).
Otherwise, unknown inputs are ignored.
If the non-unknown inputs are not all of the same type category, fail.
Choose the first non-unknown input type which is a preferred type in
that category, if there is one.
Otherwise, choose the last non-unknown input type that allows all the
preceding non-unknown inputs to be implicitly converted to it. (There
always is such a type, since at least the first type in the list must
satisfy this condition.)
Convert all inputs to the selected type. Fail if there is not a
conversion from a given input to the selected type.
Some examples follow.
Type Resolution with Underspecified Types in a Union
SELECT text 'a' AS "text" UNION SELECT 'b';
text
------
a
b
(2 rows)
Here, the unknown-type literal 'b' will be resolved to type text.
Type Resolution in a Simple Union
SELECT 1.2 AS "numeric" UNION SELECT 1;
numeric
---------
1
1.2
(2 rows)
The literal 1.2> is of type numeric>,
and the integer value 1> can be cast implicitly to
numeric>, so that type is used.
Type Resolution in a Transposed Union
SELECT 1 AS "real" UNION SELECT CAST('2.2' AS REAL);
real
------
1
2.2
(2 rows)
Here, since type real> cannot be implicitly cast to integer>,
but integer> can be implicitly cast to real>, the union
result type is resolved as real>.