postgresql/doc/src/sgml/typeconv.sgml

815 lines
24 KiB
Plaintext
Raw Normal View History

<chapter Id="typeconv">
<title>Type Conversion</title>
<para>
<acronym>SQL</acronym> queries can, intentionally or not, require
mixing of different data types in the same expression.
<productname>Postgres</productname> has extensive facilities for
evaluating mixed-type expressions.
</para>
<para>
In many cases a user will not need
to understand the details of the type conversion mechanism.
However, the implicit conversions done by <productname>Postgres</productname>
can affect the results of a query. When necessary, these results
can be tailored by a user or programmer
using <emphasis>explicit</emphasis> type coercion.
</para>
<para>
This chapter introduces the <productname>Postgres</productname>
type conversion mechanisms and conventions.
Refer to the relevant sections in the User's Guide and Programmer's Guide
for more information on specific data types and allowed functions and
operators.
</para>
<para>
The Programmer's Guide has more details on the exact algorithms used for
implicit type conversion and coercion.
</para>
<sect1 id="typeconv-overview">
<title>Overview</title>
<para>
<acronym>SQL</acronym> is a strongly typed language. That is, every data item
has an associated data type which determines its behavior and allowed usage.
<productname>Postgres</productname> has an extensible type system that is
much more general and flexible than other <acronym>RDBMS</acronym> implementations.
Hence, most type conversion behavior in <productname>Postgres</productname>
should be governed by general rules rather than by ad-hoc heuristics to allow
mixed-type expressions to be meaningful, even with user-defined types.
</para>
<para>
The <productname>Postgres</productname> scanner/parser decodes lexical
elements into only five fundamental categories: integers, floats, strings,
names, and keywords. Most extended types are first tokenized into
strings. The <acronym>SQL</acronym> language definition allows specifying type
names with strings, and this mechanism can be used in
<productname>Postgres</productname> to start the parser down the correct
path. For example, the query
<programlisting>
tgl=> SELECT text 'Origin' AS "Label", point '(0,0)' AS "Value";
Label | Value
--------+-------
Origin | (0,0)
(1 row)
</programlisting>
has two strings, of type <type>text</type> and <type>point</type>.
If a type is not specified for a string, then the placeholder type
<firstterm>unknown</firstterm> is assigned initially, to be resolved in later
stages as described below.
</para>
<para>
There are four fundamental <acronym>SQL</acronym> constructs requiring
distinct type conversion rules in the <productname>Postgres</productname>
parser:
</para>
<variablelist>
<varlistentry>
<term>
Operators
</term>
<listitem>
<para>
<productname>Postgres</productname> allows expressions with
left- and right-unary (one argument) operators,
as well as binary (two argument) operators.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
Function calls
</term>
<listitem>
<para>
Much of the <productname>Postgres</productname> type system is built around a
rich set of functions. Function calls have one or more arguments which, for
any specific query, must be matched to the functions available in the system
catalog. Since <productname>Postgres</productname> 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.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
Query targets
</term>
<listitem>
<para>
<acronym>SQL</acronym> INSERT and UPDATE statements place the results of
expressions into a table. The expressions in the query must be matched up
with, and perhaps converted to, the types of the target columns.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
UNION and CASE constructs
</term>
<listitem>
<para>
Since all select results from a UNION 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 coerced to
a common type so that the CASE expression as a whole has a known output type.
</para>
</listitem>
</varlistentry>
</variablelist>
<para>
Many of the general type conversion rules use simple conventions built on
the <productname>Postgres</productname> function and operator system tables.
There are some heuristics included in the conversion rules to better support
conventions for the <acronym>SQL92</acronym> standard native types such as
<type>smallint</type>, <type>integer</type>, and <type>float</type>.
</para>
<para>
The <productname>Postgres</productname> parser uses the convention that all
type conversion functions take a single argument of the source type and are
named with the same name as the target type. Any function meeting these
criteria is considered to be a valid conversion function, and may be used
by the parser as such. This simple assumption gives the parser the power
to explore type conversion possibilities without hardcoding, allowing
extended user-defined types to use these same features transparently.
</para>
<para>
An additional heuristic is provided in the parser to allow better guesses
at proper behavior for <acronym>SQL</acronym> standard types. There are
several basic <firstterm>type categories</firstterm> defined: <type>boolean</type>,
<type>numeric</type>, <type>string</type>, <type>bitstring</type>, <type>datetime</type>, <type>timespan</type>, <type>geometric</type>, <type>network</type>,
and user-defined. Each category, with the exception of user-defined, has
a <firstterm>preferred type</firstterm> which is preferentially selected
when there is ambiguity.
In the user-defined category, each type is its own preferred type.
Ambiguous expressions (those with multiple candidate parsing solutions)
can often be resolved when there are multiple possible built-in types, but
they will raise an error when there are multiple choices for user-defined
types.
</para>
<sect2>
<title>Guidelines</title>
<para>
All type conversion rules are designed with several principles in mind:
<itemizedlist mark="bullet" spacing="compact">
<listitem>
<para>
Implicit conversions should never have surprising or unpredictable outcomes.
</para>
</listitem>
<listitem>
<para>
User-defined types, of which the parser has no a-priori knowledge, should be
<quote>higher</quote> in the type hierarchy. In mixed-type expressions, native types shall always
be converted to a user-defined type (of course, only if conversion is necessary).
</para>
</listitem>
<listitem>
<para>
User-defined types are not related. Currently, <productname>Postgres</productname>
does not have information available to it on relationships between types, other than
hardcoded heuristics for built-in types and implicit relationships based on available functions
in the catalog.
</para>
</listitem>
<listitem>
<para>
There should be no extra overhead from the parser or executor
if a query does not need implicit type conversion.
That is, if a query is well formulated and the types already match up, then the query should proceed
without spending extra time in the parser and without introducing unnecessary implicit conversion
functions into the query.
</para>
<para>
Additionally, if a query usually requires an implicit conversion for a function, and
if then the user defines an explicit function with the correct argument types, the parser
should use this new function and will no longer do the implicit conversion using the old function.
</para>
</listitem>
</itemizedlist>
</para>
</sect2>
</sect1>
<sect1 id="typeconv-oper">
<title>Operators</title>
<procedure>
<title>Operator Type Resolution</title>
<step performance="required">
<para>
Check for an exact match in the pg_operator system catalog.
</para>
<substeps>
<step performance="optional">
<para>
If one argument of a binary operator is <type>unknown</type> type,
then assume it is the same type as the other argument for this check.
Other cases involving <type>unknown</type> will never find a match at
this step.
</para>
</step>
</substeps>
</step>
<step performance="required">
<para>
Look for the best match.
</para>
<substeps>
<step performance="required">
<para>
Make a list of all operators of the same name for which the input types
match or can be coerced to match. (<type>unknown</type> literals are
assumed to be coercible to anything for this purpose.) If there is only
one, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
Run through all candidates and keep those with the most exact matches
on input types. Keep all candidates if none have any exact matches.
If only one candidate remains, use it; else continue to the next step.
</para>
2000-12-17 18:50:46 +01:00
</step>
<step performance="required">
<para>
Run through all candidates and keep those with the most exact or
binary-compatible matches on input types. Keep all candidates if none have
any exact or binary-compatible matches.
If only one candidate remains, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
Run through all candidates and keep those that accept preferred types at
the most positions where type coercion will be required.
Keep all candidates if none accept preferred types.
If only one candidate remains, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
If any input arguments are <quote>unknown</quote>, check the type categories accepted
at those argument positions by the remaining candidates. At each position,
select "string"
category if any candidate accepts that category (this bias towards string
is appropriate since an unknown-type literal does look 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. Also note whether
any of the candidates accept a preferred data type within the selected category.
Now discard operator candidates that do not accept the selected type category;
furthermore, if any candidate accepts a preferred type at a given argument
position, discard candidates that accept non-preferred types for that
argument.
</para>
</step>
<step performance="required">
<para>
If only one candidate remains, use it. If no candidate or more than one
candidate remains,
then fail.
</para>
</step>
</substeps>
</step>
</procedure>
<sect2>
<title>Examples</title>
<sect3>
<title>Exponentiation Operator</title>
<para>
There is only one exponentiation
operator defined in the catalog, and it takes arguments of type
<type>double precision</type>.
The scanner assigns an initial type of <type>int4</type> to both arguments
of this query expression:
<programlisting>
tgl=> select 2 ^ 3 AS "Exp";
Exp
-----
8
(1 row)
</programlisting>
So the parser does a type conversion on both operands and the query
is equivalent to
<programlisting>
tgl=> select CAST(2 AS double precision) ^ CAST(3 AS double precision) AS "Exp";
Exp
-----
8
(1 row)
</programlisting>
or
<programlisting>
tgl=> select 2.0 ^ 3.0 AS "Exp";
Exp
-----
8
(1 row)
</programlisting>
<note>
<para>
This last form has the least overhead, since no functions are called to do
implicit type conversion. This is not an issue for small queries, but may
have an impact on the performance of queries involving large tables.
</para>
</note>
</para>
</sect3>
<sect3>
<title>String Concatenation</title>
<para>
A string-like syntax is used for working with string types as well as for
working with complex extended types.
Strings with unspecified type are matched with likely operator candidates.
</para>
<para>
One unspecified argument:
<programlisting>
tgl=> SELECT text 'abc' || 'def' AS "Text and Unknown";
Text and Unknown
------------------
abcdef
(1 row)
</programlisting>
</para>
<para>
In this case the parser looks to see if there is an operator taking <type>text</type>
for both arguments. Since there is, it assumes that the second argument should
be interpreted as of type <type>text</type>.
</para>
<para>
Concatenation on unspecified types:
<programlisting>
tgl=> SELECT 'abc' || 'def' AS "Unspecified";
Unspecified
-------------
abcdef
(1 row)
</programlisting>
</para>
<para>
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
<quote>preferred type</quote> for strings, <type>text</type>, is used as the specific
type to resolve the unknown literals to.
</para>
</sect3>
<sect3>
<title>Factorial</title>
<para>
This example illustrates an interesting result. Traditionally, the
factorial operator is defined for integers only. The <productname>Postgres</productname>
operator catalog has only one entry for factorial, taking an integer operand.
If given a non-integer numeric argument, <productname>Postgres</productname>
will try to convert that argument to an integer for evaluation of the
factorial.
<programlisting>
tgl=> select (4.3 !);
?column?
----------
24
(1 row)
</programlisting>
<note>
<para>
Of course, this leads to a mathematically suspect result,
since in principle the factorial of a non-integer is not defined.
However, the role of a database is not to teach mathematics, but
to be a tool for data manipulation. If a user chooses to take the
factorial of a floating point number, <productname>Postgres</productname>
will try to oblige.
</para>
</note>
</para>
</sect3>
</sect2>
</sect1>
<sect1 id="typeconv-func">
<title>Functions</title>
<procedure>
<title>Function Call Type Resolution</title>
<step performance="required">
<para>
Check for an exact match in the <classname>pg_proc</classname> system catalog.
(Cases involving <type>unknown</type> will never find a match at
this step.)
</para></step>
<step performance="required">
<para>
Look for the best match.
</para>
<substeps>
<step performance="required">
<para>
Make a list of all functions of the same name with the same number of
arguments for which the input types
match or can be coerced to match. (<type>unknown</type> literals are
assumed to be coercible to anything for this purpose.) If there is only
one, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
Run through all candidates and keep those with the most exact matches
on input types. Keep all candidates if none have any exact matches.
If only one candidate remains, use it; else continue to the next step.
</para>
2000-12-17 18:50:46 +01:00
</step>
<step performance="required">
<para>
Run through all candidates and keep those with the most exact or
binary-compatible matches on input types. Keep all candidates if none have
any exact or binary-compatible matches.
If only one candidate remains, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
Run through all candidates and keep those that accept preferred types at
the most positions where type coercion will be required.
Keep all candidates if none accept preferred types.
If only one candidate remains, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
If any input arguments are <type>unknown</type>, check the type categories accepted
at those argument positions by the remaining candidates. At each position,
select <type>string</type>
category if any candidate accepts that category (this bias towards string
is appropriate since an unknown-type literal does look 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. Also note whether
any of the candidates accept a preferred data type within the selected category.
Now discard operator candidates that do not accept the selected type category;
furthermore, if any candidate accepts a preferred type at a given argument
position, discard candidates that accept non-preferred types for that
argument.
</para>
</step>
<step performance="required">
<para>
If only one candidate remains, use it. If no candidate or more than one
candidate remains,
then fail.
</para>
</step>
</substeps>
</step>
<step performance="required">
<para>
If no best match could be identified, see whether the function call appears
to be a trivial type coercion 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-compatible with the named
data type. When these conditions are met, the function argument is coerced
to the named data type.
</para>
</step>
</procedure>
<sect2>
<title>Examples</title>
<sect3>
<title>Factorial Function</title>
<para>
There is only one factorial function defined in the <classname>pg_proc</classname> catalog.
So the following query automatically converts the <type>int2</type> argument
to <type>int4</type>:
<programlisting>
tgl=> select int4fac(int2 '4');
int4fac
---------
24
(1 row)
</programlisting>
and is actually transformed by the parser to
<programlisting>
tgl=> select int4fac(int4(int2 '4'));
int4fac
---------
24
(1 row)
</programlisting>
</para>
</sect3>
<sect3>
<title>Substring Function</title>
<para>
There are two <function>substr</function> functions declared in <classname>pg_proc</classname>. However,
only one takes two arguments, of types <type>text</type> and <type>int4</type>.
</para>
<para>
If called with a string constant of unspecified type, the type is matched up
directly with the only candidate function type:
<programlisting>
tgl=> select substr('1234', 3);
substr
--------
34
(1 row)
</programlisting>
</para>
<para>
If the string is declared to be of type <type>varchar</type>, as might be the case
if it comes from a table, then the parser will try to coerce it to become <type>text</type>:
<programlisting>
tgl=> select substr(varchar '1234', 3);
substr
--------
34
(1 row)
</programlisting>
which is transformed by the parser to become
<programlisting>
tgl=> select substr(text(varchar '1234'), 3);
substr
--------
34
(1 row)
</programlisting>
</para>
<note>
<para>
Actually, the parser is aware that <type>text</type> and <type>varchar</type>
are <firstterm>binary compatible</>, meaning that one can be passed to a function that
accepts the other without doing any physical conversion. Therefore, no
explicit type conversion call is really inserted in this case.
</para>
</note>
<para>
And, if the function is called with an <type>int4</type>, the parser will
try to convert that to <type>text</type>:
<programlisting>
tgl=> select substr(1234, 3);
substr
--------
34
(1 row)
</programlisting>
actually executes as
<programlisting>
tgl=> select substr(text(1234), 3);
substr
--------
34
(1 row)
</programlisting>
This succeeds because there is a conversion function text(int4) in the
system catalog.
</para>
</sect3>
</sect2>
</sect1>
<sect1 id="typeconv-query">
<title>Query Targets</title>
<procedure>
<title>Query Target Type Resolution</title>
<step performance="required">
<para>
Check for an exact match with the target.
</para></step>
<step performance="required">
<para>
Otherwise, try to coerce the expression to the target type. This will succeed
if the two types are known binary-compatible, or if there is a conversion
function. 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.
</para></step>
<step performance="required">
<para>
If the target is a fixed-length type (e.g. <type>char</type> or <type>varchar</type>
declared with a length) then try to find a sizing function for the target
type. A sizing function is a function of the same name as the type,
taking two arguments of which the first is that type and the second is an
integer, and returning the same type. If one is found, it is applied,
passing the column's declared length as the second parameter.
</para></step>
</procedure>
<sect2>
<title>Examples</title>
<sect3>
<title><type>varchar</type> Storage</title>
<para>
For a target column declared as <type>varchar(4)</type> the following query
ensures that the target is sized correctly:
<programlisting>
tgl=> CREATE TABLE vv (v varchar(4));
CREATE
tgl=> INSERT INTO vv SELECT 'abc' || 'def';
INSERT 392905 1
tgl=> SELECT * FROM vv;
v
------
abcd
(1 row)
</programlisting>
What's really happened here is that the two unknown literals are resolved
to text by default, allowing the <literal>||</literal> operator to be
resolved as text concatenation. Then the text result of the operator
is coerced to <type>varchar</type> to match the target column type. (But, since the
parser knows that text and <type>varchar</type> are binary-compatible, this coercion
is implicit and does not insert any real function call.) Finally, the
sizing function <literal>varchar(varchar,int4)</literal> is found in the system
catalogs and applied to the operator's result and the stored column length.
This type-specific function performs the desired truncation.
</para>
</sect3>
</sect2>
</sect1>
<sect1 id="typeconv-union-case">
<title>UNION and CASE Constructs</title>
<para>
The UNION and CASE 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. CASE uses the identical algorithm to match
up its result expressions.
</para>
<procedure>
<title>UNION and CASE Type Resolution</title>
<step performance="required">
<para>
If all inputs are of type <type>unknown</type>, resolve as type
<type>text</type> (the preferred type for string category).
Otherwise, ignore the <type>unknown</type> inputs while choosing the type.
</para></step>
<step performance="required">
<para>
If the non-unknown inputs are not all of the same type category, fail.
</para></step>
<step performance="required">
<para>
If one or more non-unknown inputs are of a preferred type in that category,
resolve as that type.
</para></step>
<step performance="required">
<para>
Otherwise, resolve as the type of the first non-unknown input.
</para></step>
<step performance="required">
<para>
Coerce all inputs to the selected type.
</para></step>
</procedure>
<sect2>
<title>Examples</title>
<sect3>
<title>Underspecified Types</title>
<para>
<programlisting>
tgl=> SELECT text 'a' AS "Text" UNION SELECT 'b';
Text
------
a
b
(2 rows)
</programlisting>
Here, the unknown-type literal <literal>'b'</literal> will be resolved as type text.
</para>
</sect3>
<sect3>
<title>Simple UNION</title>
<para>
<programlisting>
tgl=> SELECT 1.2 AS "Double" UNION SELECT 1;
Double
--------
1
1.2
(2 rows)
</programlisting>
</para>
</sect3>
<sect3>
<title>Transposed UNION</title>
<para>
Here the output type of the union is forced to match the type of
the first/top clause in the union:
<programlisting>
tgl=> SELECT 1 AS "All integers"
tgl-> UNION SELECT CAST('2.2' AS REAL);
All integers
--------------
1
2
(2 rows)
</programlisting>
</para>
<para>
Since <type>REAL</type> is not a preferred type, the parser sees no reason
to select it over <type>INTEGER</type> (which is what the 1 is), and instead
falls back on the use-the-first-alternative rule.
This example demonstrates that the preferred-type mechanism doesn't encode
as much information as we'd like. Future versions of
<productname>Postgres</productname> may support a more general notion of
type preferences.
</para>
</sect3>
</sect2>
</sect1>
</chapter>
<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:t
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/lib/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->