1 <!-- doc/src/sgml/typeconv.sgml -->
3 <chapter id=
"typeconv">
4 <title>Type Conversion
</title>
6 <indexterm zone=
"typeconv">
7 <primary>data type
</primary>
8 <secondary>conversion
</secondary>
12 <acronym>SQL
</acronym> statements can, intentionally or not, require
13 the mixing of different data types in the same expression.
14 <productname>PostgreSQL
</productname> has extensive facilities for
15 evaluating mixed-type expressions.
19 In many cases a user does not need
20 to understand the details of the type conversion mechanism.
21 However, implicit conversions done by
<productname>PostgreSQL
</productname>
22 can affect the results of a query. When necessary, these results
23 can be tailored by using
<emphasis>explicit
</emphasis> type conversion.
27 This chapter introduces the
<productname>PostgreSQL
</productname>
28 type conversion mechanisms and conventions.
29 Refer to the relevant sections in
<xref linkend=
"datatype"/> and
<xref linkend=
"functions"/>
30 for more information on specific data types and allowed functions and
34 <sect1 id=
"typeconv-overview">
35 <title>Overview
</title>
38 <acronym>SQL
</acronym> is a strongly typed language. That is, every data item
39 has an associated data type which determines its behavior and allowed usage.
40 <productname>PostgreSQL
</productname> has an extensible type system that is
41 more general and flexible than other
<acronym>SQL
</acronym> implementations.
42 Hence, most type conversion behavior in
<productname>PostgreSQL
</productname>
43 is governed by general rules rather than by ad hoc
44 heuristics. This allows the use of mixed-type expressions even with
49 The
<productname>PostgreSQL
</productname> scanner/parser divides lexical
50 elements into five fundamental categories: integers, non-integer numbers,
51 strings, identifiers, and key words. Constants of most non-numeric types are
52 first classified as strings. The
<acronym>SQL
</acronym> language definition
53 allows specifying type names with strings, and this mechanism can be used in
54 <productname>PostgreSQL
</productname> to start the parser down the correct
55 path. For example, the query:
58 SELECT text 'Origin' AS
"label", point '(
0,
0)' AS
"value";
66 has two literal constants, of type
<type>text
</type> and
<type>point
</type>.
67 If a type is not specified for a string literal, then the placeholder type
68 <type>unknown
</type> is assigned initially, to be resolved in later
69 stages as described below.
73 There are four fundamental
<acronym>SQL
</acronym> constructs requiring
74 distinct type conversion rules in the
<productname>PostgreSQL
</productname>
84 Much of the
<productname>PostgreSQL
</productname> type system is built around a
85 rich set of functions. Functions can have one or more arguments.
86 Since
<productname>PostgreSQL
</productname> permits function
87 overloading, the function name alone does not uniquely identify the function
88 to be called; the parser must select the right function based on the data
89 types of the supplied arguments.
99 <productname>PostgreSQL
</productname> allows expressions with
100 prefix (one-argument) operators,
101 as well as infix (two-argument) operators. Like functions, operators can
102 be overloaded, so the same problem of selecting the right operator
113 <acronym>SQL
</acronym> <command>INSERT
</command> and
<command>UPDATE
</command> statements place the results of
114 expressions into a table. The expressions in the statement must be matched up
115 with, and perhaps converted to, the types of the target columns.
121 <literal>UNION
</literal>,
<literal>CASE
</literal>, and related constructs
125 Since all query results from a unionized
<command>SELECT
</command> statement
126 must appear in a single set of columns, the types of the results of each
127 <command>SELECT
</command> clause must be matched up and converted to a uniform set.
128 Similarly, the result expressions of a
<literal>CASE
</literal> construct must be
129 converted to a common type so that the
<literal>CASE
</literal> expression as a whole
130 has a known output type. Some other constructs, such
131 as
<literal>ARRAY[]
</literal> and the
<function>GREATEST
</function>
132 and
<function>LEAST
</function> functions, likewise require determination of a
133 common type for several subexpressions.
141 The system catalogs store information about which conversions, or
142 <firstterm>casts
</firstterm>, exist between which data types, and how to
143 perform those conversions. Additional casts can be added by the user
144 with the
<xref linkend=
"sql-createcast"/>
145 command. (This is usually
146 done in conjunction with defining new data types. The set of casts
147 between built-in types has been carefully crafted and is best not
152 <primary>data type
</primary>
153 <secondary>category
</secondary>
157 An additional heuristic provided by the parser allows improved determination
158 of the proper casting behavior among groups of types that have implicit casts.
159 Data types are divided into several basic
<firstterm>type
160 categories
</firstterm>, including
<type>boolean
</type>,
<type>numeric
</type>,
161 <type>string
</type>,
<type>bitstring
</type>,
<type>datetime
</type>,
162 <type>timespan
</type>,
<type>geometric
</type>,
<type>network
</type>, and
163 user-defined. (For a list see
<xref linkend=
"catalog-typcategory-table"/>;
164 but note it is also possible to create custom type categories.) Within each
165 category there can be one or more
<firstterm>preferred types
</firstterm>, which
166 are preferred when there is a choice of possible types. With careful selection
167 of preferred types and available implicit casts, it is possible to ensure that
168 ambiguous expressions (those with multiple candidate parsing solutions) can be
169 resolved in a useful way.
173 All type conversion rules are designed with several principles in mind:
178 Implicit conversions should never have surprising or unpredictable outcomes.
184 There should be no extra overhead in the parser or executor
185 if a query does not need implicit type conversion.
186 That is, if a query is well-formed and the types already match, then the query should execute
187 without spending extra time in the parser and without introducing unnecessary implicit conversion
194 Additionally, if a query usually requires an implicit conversion for a function, and
195 if then the user defines a new function with the correct argument types, the parser
196 should use this new function and no longer do implicit conversion to use the old function.
204 <sect1 id=
"typeconv-oper">
205 <title>Operators
</title>
207 <indexterm zone=
"typeconv-oper">
208 <primary>operator
</primary>
209 <secondary>type resolution in an invocation
</secondary>
213 The specific operator that is referenced by an operator expression
214 is determined using the following procedure.
215 Note that this procedure is indirectly affected
216 by the precedence of the operators involved, since that will determine
217 which sub-expressions are taken to be the inputs of which operators.
218 See
<xref linkend=
"sql-precedence"/> for more information.
222 <title>Operator Type Resolution
</title>
224 <step id=
"op-resol-select" performance=
"required">
226 Select the operators to be considered from the
227 <classname>pg_operator
</classname> system catalog. If a non-schema-qualified
228 operator name was used (the usual case), the operators
229 considered are those with the matching name and argument count that are
230 visible in the current search path (see
<xref linkend=
"ddl-schemas-path"/>).
231 If a qualified operator name was given, only operators in the specified
232 schema are considered.
236 <step performance=
"optional">
238 If the search path finds multiple operators with identical argument types,
239 only the one appearing earliest in the path is considered. Operators with
240 different argument types are considered on an equal footing regardless of
241 search path position.
247 <step id=
"op-resol-exact-match" performance=
"required">
249 Check for an operator accepting exactly the input argument types.
250 If one exists (there can be only one exact match in the set of
251 operators considered), use it. Lack of an exact match creates a security
252 hazard when calling, via qualified name
253 <footnote id=
"op-qualified-security">
254 <!-- If you edit this, consider editing func-qualified-security. -->
256 The hazard does not arise with a non-schema-qualified name, because a
257 search path containing schemas that permit untrusted users to create
258 objects is not a
<link linkend=
"ddl-schemas-patterns">secure schema usage
262 (not typical), any operator found in a schema that permits untrusted users to
263 create objects. In such situations, cast arguments to force an exact match.
267 <step id=
"op-resol-exact-unknown" performance=
"optional">
269 If one argument of a binary operator invocation is of the
<type>unknown
</type> type,
270 then assume it is the same type as the other argument for this check.
271 Invocations involving two
<type>unknown
</type> inputs, or a prefix operator
272 with an
<type>unknown
</type> input, will never find a match at this step.
275 <step id=
"op-resol-exact-domain" performance=
"optional">
277 If one argument of a binary operator invocation is of the
<type>unknown
</type>
278 type and the other is of a domain type, next check to see if there is an
279 operator accepting exactly the domain's base type on both sides; if so, use it.
285 <step id=
"op-resol-best-match" performance=
"required">
287 Look for the best match.
290 <step performance=
"required">
292 Discard candidate operators for which the input types do not match
293 and cannot be converted (using an implicit conversion) to match.
294 <type>unknown
</type> literals are
295 assumed to be convertible to anything for this purpose. If only one
296 candidate remains, use it; else continue to the next step.
299 <step performance=
"required">
301 If any input argument is of a domain type, treat it as being of the
302 domain's base type for all subsequent steps. This ensures that domains
303 act like their base types for purposes of ambiguous-operator resolution.
306 <step performance=
"required">
308 Run through all candidates and keep those with the most exact matches
309 on input types. Keep all candidates if none have exact matches.
310 If only one candidate remains, use it; else continue to the next step.
313 <step performance=
"required">
315 Run through all candidates and keep those that accept preferred types (of the
316 input data type's type category) at the most positions where type conversion
318 Keep all candidates if none accept preferred types.
319 If only one candidate remains, use it; else continue to the next step.
322 <step performance=
"required">
324 If any input arguments are
<type>unknown
</type>, check the type
325 categories accepted at those argument positions by the remaining
326 candidates. At each position, select the
<type>string
</type> category
328 candidate accepts that category. (This bias towards string is appropriate
329 since an unknown-type literal looks like a string.) Otherwise, if
330 all the remaining candidates accept the same type category, select that
331 category; otherwise fail because the correct choice cannot be deduced
332 without more clues. Now discard
333 candidates that do not accept the selected type category. Furthermore,
334 if any candidate accepts a preferred type in that category,
335 discard candidates that accept non-preferred types for that argument.
336 Keep all candidates if none survive these tests.
337 If only one candidate remains, use it; else continue to the next step.
340 <step id=
"op-resol-last-unknown" performance=
"required">
342 If there are both
<type>unknown
</type> and known-type arguments, and all
343 the known-type arguments have the same type, assume that the
344 <type>unknown
</type> arguments are also of that type, and check which
345 candidates can accept that type at the
<type>unknown
</type>-argument
346 positions. If exactly one candidate passes this test, use it.
355 Some examples follow.
359 <title>Square Root Operator Type Resolution
</title>
362 There is only one square root operator (prefix
<literal>|/
</literal>)
363 defined in the standard catalog, and it takes an argument of type
364 <type>double precision
</type>.
365 The scanner assigns an initial type of
<type>integer
</type> to the argument
366 in this query expression:
368 SELECT |/
40 AS
"square root of 40";
375 So the parser does a type conversion on the operand and the query
379 SELECT |/ CAST(
40 AS double precision) AS
"square root of 40";
385 <title>String Concatenation Operator Type Resolution
</title>
388 A string-like syntax is used for working with string types and for
389 working with complex extension types.
390 Strings with unspecified type are matched with likely operator candidates.
394 An example with one unspecified argument:
396 SELECT text 'abc' || 'def' AS
"text and unknown";
406 In this case the parser looks to see if there is an operator taking
<type>text
</type>
407 for both arguments. Since there is, it assumes that the second argument should
408 be interpreted as type
<type>text
</type>.
412 Here is a concatenation of two values of unspecified types:
414 SELECT 'abc' || 'def' AS
"unspecified";
424 In this case there is no initial hint for which type to use, since no types
425 are specified in the query. So, the parser looks for all candidate operators
426 and finds that there are candidates accepting both string-category and
427 bit-string-category inputs. Since string category is preferred when available,
428 that category is selected, and then the
429 preferred type for strings,
<type>text
</type>, is used as the specific
430 type to resolve the unknown-type literals as.
435 <title>Absolute-Value and Negation Operator Type Resolution
</title>
438 The
<productname>PostgreSQL
</productname> operator catalog has several
439 entries for the prefix operator
<literal>@
</literal>, all of which implement
440 absolute-value operations for various numeric data types. One of these
441 entries is for type
<type>float8
</type>, which is the preferred type in
442 the numeric category. Therefore,
<productname>PostgreSQL
</productname>
443 will use that entry when faced with an
<type>unknown
</type> input:
445 SELECT @ '-
4.5' AS
"abs";
451 Here the system has implicitly resolved the unknown-type literal as type
452 <type>float8
</type> before applying the chosen operator. We can verify that
453 <type>float8
</type> and not some other type was used:
455 SELECT @ '-
4.5e500' AS
"abs";
457 ERROR:
"-4.5e500" is out of range for type double precision
462 On the other hand, the prefix operator
<literal>~
</literal> (bitwise negation)
463 is defined only for integer data types, not for
<type>float8
</type>. So, if we
464 try a similar case with
<literal>~
</literal>, we get:
466 SELECT ~ '
20' AS
"negation";
468 ERROR: operator is not unique: ~
"unknown"
469 HINT: Could not choose a best candidate operator. You might need to add
472 This happens because the system cannot decide which of the several
473 possible
<literal>~
</literal> operators should be preferred. We can help
474 it out with an explicit cast:
476 SELECT ~ CAST('
20' AS int8) AS
"negation";
487 <title>Array Inclusion Operator Type Resolution
</title>
490 Here is another example of resolving an operator with one known and one
493 SELECT array[
1,
2]
<@ '{
1,
2,
3}' as
"is subset";
500 The
<productname>PostgreSQL
</productname> operator catalog has several
501 entries for the infix operator
<literal><@
</literal>, but the only two that
502 could possibly accept an integer array on the left-hand side are
503 array inclusion (
<type>anyarray
</type> <literal><@
</literal> <type>anyarray
</type>)
504 and range inclusion (
<type>anyelement
</type> <literal><@
</literal> <type>anyrange
</type>).
505 Since none of these polymorphic pseudo-types (see
<xref
506 linkend=
"datatype-pseudo"/>) are considered preferred, the parser cannot
507 resolve the ambiguity on that basis.
508 However,
<xref linkend=
"op-resol-last-unknown"/> tells
509 it to assume that the unknown-type literal is of the same type as the other
510 input, that is, integer array. Now only one of the two operators can match,
511 so array inclusion is selected. (Had range inclusion been selected, we would
512 have gotten an error, because the string does not have the right format to be
518 <title>Custom Operator on a Domain Type
</title>
521 Users sometimes try to declare operators applying just to a domain type.
522 This is possible but is not nearly as useful as it might seem, because the
523 operator resolution rules are designed to select operators applying to the
524 domain's base type. As an example consider
526 CREATE DOMAIN mytext AS text CHECK(...);
527 CREATE FUNCTION mytext_eq_text (mytext, text) RETURNS boolean AS ...;
528 CREATE OPERATOR = (procedure=mytext_eq_text, leftarg=mytext, rightarg=text);
529 CREATE TABLE mytable (val mytext);
531 SELECT * FROM mytable WHERE val = 'foo';
533 This query will not use the custom operator. The parser will first see if
534 there is a
<type>mytext
</type> <literal>=
</literal> <type>mytext
</type> operator
535 (
<xref linkend=
"op-resol-exact-unknown"/>), which there is not;
536 then it will consider the domain's base type
<type>text
</type>, and see if
537 there is a
<type>text
</type> <literal>=
</literal> <type>text
</type> operator
538 (
<xref linkend=
"op-resol-exact-domain"/>), which there is;
539 so it resolves the
<type>unknown
</type>-type literal as
<type>text
</type> and
540 uses the
<type>text
</type> <literal>=
</literal> <type>text
</type> operator.
541 The only way to get the custom operator to be used is to explicitly cast
544 SELECT * FROM mytable WHERE val = text 'foo';
546 so that the
<type>mytext
</type> <literal>=
</literal> <type>text
</type> operator is found
547 immediately according to the exact-match rule. If the best-match rules
548 are reached, they actively discriminate against operators on domain types.
549 If they did not, such an operator would create too many ambiguous-operator
550 failures, because the casting rules always consider a domain as castable
551 to or from its base type, and so the domain operator would be considered
552 usable in all the same cases as a similarly-named operator on the base type.
558 <sect1 id=
"typeconv-func">
559 <title>Functions
</title>
561 <indexterm zone=
"typeconv-func">
562 <primary>function
</primary>
563 <secondary>type resolution in an invocation
</secondary>
567 The specific function that is referenced by a function call
568 is determined using the following procedure.
572 <title>Function Type Resolution
</title>
574 <step performance=
"required">
576 Select the functions to be considered from the
577 <classname>pg_proc
</classname> system catalog. If a non-schema-qualified
578 function name was used, the functions
579 considered are those with the matching name and argument count that are
580 visible in the current search path (see
<xref linkend=
"ddl-schemas-path"/>).
581 If a qualified function name was given, only functions in the specified
582 schema are considered.
586 <step performance=
"optional">
588 If the search path finds multiple functions of identical argument types,
589 only the one appearing earliest in the path is considered. Functions of
590 different argument types are considered on an equal footing regardless of
591 search path position.
594 <step performance=
"optional">
596 If a function is declared with a
<literal>VARIADIC
</literal> array parameter, and
597 the call does not use the
<literal>VARIADIC
</literal> keyword, then the function
598 is treated as if the array parameter were replaced by one or more occurrences
599 of its element type, as needed to match the call. After such expansion the
600 function might have effective argument types identical to some non-variadic
601 function. In that case the function appearing earlier in the search path is
602 used, or if the two functions are in the same schema, the non-variadic one is
606 This creates a security hazard when calling, via qualified name
607 <footnote id=
"func-qualified-security">
608 <!-- If you edit this, consider editing op-qualified-security. -->
610 The hazard does not arise with a non-schema-qualified name, because a
611 search path containing schemas that permit untrusted users to create
612 objects is not a
<link linkend=
"ddl-schemas-patterns">secure schema usage
616 a variadic function found in a schema that permits untrusted users to create
617 objects. A malicious user can take control and execute arbitrary SQL
618 functions as though you executed them. Substitute a call bearing
619 the
<literal>VARIADIC
</literal> keyword, which bypasses this hazard. Calls
620 populating
<literal>VARIADIC
"any"</literal> parameters often have no
621 equivalent formulation containing the
<literal>VARIADIC
</literal> keyword. To
622 issue those calls safely, the function's schema must permit only trusted users
626 <step performance=
"optional">
628 Functions that have default values for parameters are considered to match any
629 call that omits zero or more of the defaultable parameter positions. If more
630 than one such function matches a call, the one appearing earliest in the
631 search path is used. If there are two or more such functions in the same
632 schema with identical parameter types in the non-defaulted positions (which is
633 possible if they have different sets of defaultable parameters), the system
634 will not be able to determine which to prefer, and so an
<quote>ambiguous
635 function call
</quote> error will result if no better match to the call can be
639 This creates an availability hazard when calling, via qualified
640 name
<footnoteref linkend=
"func-qualified-security"/>, any function found in a
641 schema that permits untrusted users to create objects. A malicious user can
642 create a function with the name of an existing function, replicating that
643 function's parameters and appending novel parameters having default values.
644 This precludes new calls to the original function. To forestall this hazard,
645 place functions in schemas that permit only trusted users to create objects.
651 <step performance=
"required">
653 Check for a function accepting exactly the input argument types.
654 If one exists (there can be only one exact match in the set of
655 functions considered), use it. Lack of an exact match creates a security
656 hazard when calling, via qualified
657 name
<footnoteref linkend=
"func-qualified-security"/>, a function found in a
658 schema that permits untrusted users to create objects. In such situations,
659 cast arguments to force an exact match. (Cases involving
<type>unknown
</type>
660 will never find a match at this step.)
664 <step performance=
"required">
666 If no exact match is found, see if the function call appears
667 to be a special type conversion request. This happens if the function call
668 has just one argument and the function name is the same as the (internal)
669 name of some data type. Furthermore, the function argument must be either
670 an unknown-type literal, or a type that is binary-coercible to the named
671 data type, or a type that could be converted to the named data type by
672 applying that type's I/O functions (that is, the conversion is either to or
673 from one of the standard string types). When these conditions are met,
674 the function call is treated as a form of
<literal>CAST
</literal> specification.
677 The reason for this step is to support function-style cast specifications
678 in cases where there is not an actual cast function. If there is a cast
679 function, it is conventionally named after its output type, and so there
680 is no need to have a special case. See
681 <xref linkend=
"sql-createcast"/>
682 for additional commentary.
687 <step performance=
"required">
689 Look for the best match.
692 <step performance=
"required">
694 Discard candidate functions for which the input types do not match
695 and cannot be converted (using an implicit conversion) to match.
696 <type>unknown
</type> literals are
697 assumed to be convertible to anything for this purpose. If only one
698 candidate remains, use it; else continue to the next step.
701 <step performance=
"required">
703 If any input argument is of a domain type, treat it as being of the
704 domain's base type for all subsequent steps. This ensures that domains
705 act like their base types for purposes of ambiguous-function resolution.
708 <step performance=
"required">
710 Run through all candidates and keep those with the most exact matches
711 on input types. Keep all candidates if none have exact matches.
712 If only one candidate remains, use it; else continue to the next step.
715 <step performance=
"required">
717 Run through all candidates and keep those that accept preferred types (of the
718 input data type's type category) at the most positions where type conversion
720 Keep all candidates if none accept preferred types.
721 If only one candidate remains, use it; else continue to the next step.
724 <step performance=
"required">
726 If any input arguments are
<type>unknown
</type>, check the type categories
728 at those argument positions by the remaining candidates. At each position,
729 select the
<type>string
</type> category if any candidate accepts that category.
730 (This bias towards string
731 is appropriate since an unknown-type literal looks like a string.)
732 Otherwise, if all the remaining candidates accept the same type category,
733 select that category; otherwise fail because
734 the correct choice cannot be deduced without more clues.
735 Now discard candidates that do not accept the selected type category.
736 Furthermore, if any candidate accepts a preferred type in that category,
737 discard candidates that accept non-preferred types for that argument.
738 Keep all candidates if none survive these tests.
739 If only one candidate remains, use it; else continue to the next step.
742 <step performance=
"required">
744 If there are both
<type>unknown
</type> and known-type arguments, and all
745 the known-type arguments have the same type, assume that the
746 <type>unknown
</type> arguments are also of that type, and check which
747 candidates can accept that type at the
<type>unknown
</type>-argument
748 positions. If exactly one candidate passes this test, use it.
757 Note that the
<quote>best match
</quote> rules are identical for operator and
758 function type resolution.
759 Some examples follow.
763 <title>Rounding Function Argument Type Resolution
</title>
766 There is only one
<function>round
</function> function that takes two
767 arguments; it takes a first argument of type
<type>numeric
</type> and
768 a second argument of type
<type>integer
</type>.
769 So the following query automatically converts
770 the first argument of type
<type>integer
</type> to
771 <type>numeric
</type>:
782 That query is actually transformed by the parser to:
784 SELECT round(CAST (
4 AS numeric),
4);
789 Since numeric constants with decimal points are initially assigned the
790 type
<type>numeric
</type>, the following query will require no type
791 conversion and therefore might be slightly more efficient:
793 SELECT round(
4.0,
4);
799 <title>Variadic Function Resolution
</title>
803 CREATE FUNCTION public.variadic_example(VARIADIC numeric[]) RETURNS int
804 LANGUAGE sql AS 'SELECT
1';
808 This function accepts, but does not require, the VARIADIC keyword. It
809 tolerates both integer and numeric arguments:
812 SELECT public.variadic_example(
0),
813 public.variadic_example(
0.0),
814 public.variadic_example(VARIADIC array[
0.0]);
815 variadic_example | variadic_example | variadic_example
816 ------------------+------------------+------------------
821 However, the first and second calls will prefer more-specific functions, if
825 CREATE FUNCTION public.variadic_example(numeric) RETURNS int
826 LANGUAGE sql AS 'SELECT
2';
829 CREATE FUNCTION public.variadic_example(int) RETURNS int
830 LANGUAGE sql AS 'SELECT
3';
833 SELECT public.variadic_example(
0),
834 public.variadic_example(
0.0),
835 public.variadic_example(VARIADIC array[
0.0]);
836 variadic_example | variadic_example | variadic_example
837 ------------------+------------------+------------------
842 Given the default configuration and only the first function existing, the
843 first and second calls are insecure. Any user could intercept them by
844 creating the second or third function. By matching the argument type exactly
845 and using the
<literal>VARIADIC
</literal> keyword, the third call is secure.
850 <title>Substring Function Type Resolution
</title>
853 There are several
<function>substr
</function> functions, one of which
854 takes types
<type>text
</type> and
<type>integer
</type>. If called
855 with a string constant of unspecified type, the system chooses the
856 candidate function that accepts an argument of the preferred category
857 <literal>string
</literal> (namely of type
<type>text
</type>).
860 SELECT substr('
1234',
3);
870 If the string is declared to be of type
<type>varchar
</type>, as might be the case
871 if it comes from a table, then the parser will try to convert it to become
<type>text
</type>:
873 SELECT substr(varchar '
1234',
3);
881 This is transformed by the parser to effectively become:
883 SELECT substr(CAST (varchar '
1234' AS text),
3);
889 The parser learns from the
<structname>pg_cast
</structname> catalog that
890 <type>text
</type> and
<type>varchar
</type>
891 are binary-compatible, meaning that one can be passed to a function that
892 accepts the other without doing any physical conversion. Therefore, no
893 type conversion call is really inserted in this case.
899 And, if the function is called with an argument of type
<type>integer
</type>,
900 the parser will try to convert that to
<type>text
</type>:
902 SELECT substr(
1234,
3);
903 ERROR: function substr(integer, integer) does not exist
904 HINT: No function matches the given name and argument types. You might need
905 to add explicit type casts.
908 This does not work because
<type>integer
</type> does not have an implicit cast
909 to
<type>text
</type>. An explicit cast will work, however:
911 SELECT substr(CAST (
1234 AS text),
3);
923 <sect1 id=
"typeconv-query">
924 <title>Value Storage
</title>
927 Values to be inserted into a table are converted to the destination
928 column's data type according to the
933 <title>Value Storage Type Conversion
</title>
935 <step performance=
"required">
937 Check for an exact match with the target.
941 <step performance=
"required">
943 Otherwise, try to convert the expression to the target type. This is possible
944 if an
<firstterm>assignment cast
</firstterm> between the two types is registered in the
945 <structname>pg_cast
</structname> catalog (see
<xref linkend=
"sql-createcast"/>).
946 Alternatively, if the expression is an unknown-type literal, the contents of
947 the literal string will be fed to the input conversion routine for the target
952 <step performance=
"required">
954 Check to see if there is a sizing cast for the target type. A sizing
955 cast is a cast from that type to itself. If one is found in the
956 <structname>pg_cast
</structname> catalog, apply it to the expression before storing
957 into the destination column. The implementation function for such a cast
958 always takes an extra parameter of type
<type>integer
</type>, which receives
959 the destination column's
<structfield>atttypmod
</structfield> value (typically its
960 declared length, although the interpretation of
<structfield>atttypmod
</structfield>
961 varies for different data types), and it may take a third
<type>boolean
</type>
962 parameter that says whether the cast is explicit or implicit. The cast
964 is responsible for applying any length-dependent semantics such as size
965 checking or truncation.
972 <title><type>character
</type> Storage Type Conversion
</title>
975 For a target column declared as
<type>character(
20)
</type> the following
976 statement shows that the stored value is sized correctly:
979 CREATE TABLE vv (v character(
20));
980 INSERT INTO vv SELECT 'abc' || 'def';
981 SELECT v, octet_length(v) FROM vv;
984 ----------------------+--------------
991 What has really happened here is that the two unknown literals are resolved
992 to
<type>text
</type> by default, allowing the
<literal>||
</literal> operator
993 to be resolved as
<type>text
</type> concatenation. Then the
<type>text
</type>
994 result of the operator is converted to
<type>bpchar
</type> (
<quote>blank-padded
995 char
</quote>, the internal name of the
<type>character
</type> data type) to match the target
996 column type. (Since the conversion from
<type>text
</type> to
997 <type>bpchar
</type> is binary-coercible, this conversion does
998 not insert any real function call.) Finally, the sizing function
999 <literal>bpchar(bpchar, integer, boolean)
</literal> is found in the system catalog
1000 and applied to the operator's result and the stored column length. This
1001 type-specific function performs the required length check and addition of
1007 <sect1 id=
"typeconv-union-case">
1008 <title><literal>UNION
</literal>,
<literal>CASE
</literal>, and Related Constructs
</title>
1010 <indexterm zone=
"typeconv-union-case">
1011 <primary>UNION
</primary>
1012 <secondary>determination of result type
</secondary>
1015 <indexterm zone=
"typeconv-union-case">
1016 <primary>CASE
</primary>
1017 <secondary>determination of result type
</secondary>
1020 <indexterm zone=
"typeconv-union-case">
1021 <primary>ARRAY
</primary>
1022 <secondary>determination of result type
</secondary>
1025 <indexterm zone=
"typeconv-union-case">
1026 <primary>VALUES
</primary>
1027 <secondary>determination of result type
</secondary>
1030 <indexterm zone=
"typeconv-union-case">
1031 <primary>GREATEST
</primary>
1032 <secondary>determination of result type
</secondary>
1035 <indexterm zone=
"typeconv-union-case">
1036 <primary>LEAST
</primary>
1037 <secondary>determination of result type
</secondary>
1041 SQL
<literal>UNION
</literal> constructs must match up possibly dissimilar
1042 types to become a single result set. The resolution algorithm is
1043 applied separately to each output column of a union query. The
1044 <literal>INTERSECT
</literal> and
<literal>EXCEPT
</literal> constructs resolve
1045 dissimilar types in the same way as
<literal>UNION
</literal>.
1046 Some other constructs, including
1047 <literal>CASE
</literal>,
<literal>ARRAY
</literal>,
<literal>VALUES
</literal>,
1048 and the
<function>GREATEST
</function> and
<function>LEAST
</function>
1049 functions, use the identical
1050 algorithm to match up their component expressions and select a result
1055 <title>Type Resolution for
<literal>UNION
</literal>,
<literal>CASE
</literal>,
1056 and Related Constructs
</title>
1058 <step performance=
"required">
1060 If all inputs are of the same type, and it is not
<type>unknown
</type>,
1061 resolve as that type.
1065 <step performance=
"required">
1067 If any input is of a domain type, treat it as being of the
1068 domain's base type for all subsequent steps.
1071 Somewhat like the treatment of domain inputs for operators and
1072 functions, this behavior allows a domain type to be preserved through
1073 a
<literal>UNION
</literal> or similar construct, so long as the user is
1074 careful to ensure that all inputs are implicitly or explicitly of that
1075 exact type. Otherwise the domain's base type will be used.
1081 <step performance=
"required">
1083 If all inputs are of type
<type>unknown
</type>, resolve as type
1084 <type>text
</type> (the preferred type of the string category).
1085 Otherwise,
<type>unknown
</type> inputs are ignored for the purposes
1086 of the remaining rules.
1090 <step performance=
"required">
1092 If the non-unknown inputs are not all of the same type category, fail.
1096 <step performance=
"required">
1098 Select the first non-unknown input type as the candidate type,
1099 then consider each other non-unknown input type, left to right.
1102 For historical reasons,
<literal>CASE
</literal> treats
1103 its
<literal>ELSE
</literal> clause (if any) as the
<quote>first
</quote>
1104 input, with the
<literal>THEN
</literal> clauses(s) considered after
1105 that. In all other cases,
<quote>left to right
</quote> means the order
1106 in which the expressions appear in the query text.
1109 If the candidate type can be implicitly converted to the other type,
1110 but not vice-versa, select the other type as the new candidate type.
1111 Then continue considering the remaining inputs. If, at any stage of this
1112 process, a preferred type is selected, stop considering additional
1117 <step performance=
"required">
1119 Convert all inputs to the final candidate type. Fail if there is not an
1120 implicit conversion from a given input type to the candidate type.
1126 Some examples follow.
1130 <title>Type Resolution with Underspecified Types in a Union
</title>
1134 SELECT text 'a' AS
"text" UNION SELECT 'b';
1142 Here, the unknown-type literal
<literal>'b'
</literal> will be resolved to type
<type>text
</type>.
1147 <title>Type Resolution in a Simple Union
</title>
1151 SELECT
1.2 AS
"numeric" UNION SELECT
1;
1159 The literal
<literal>1.2</literal> is of type
<type>numeric
</type>,
1160 and the
<type>integer
</type> value
<literal>1</literal> can be cast implicitly to
1161 <type>numeric
</type>, so that type is used.
1166 <title>Type Resolution in a Transposed Union
</title>
1170 SELECT
1 AS
"real" UNION SELECT CAST('
2.2' AS REAL);
1178 Here, since type
<type>real
</type> cannot be implicitly cast to
<type>integer
</type>,
1179 but
<type>integer
</type> can be implicitly cast to
<type>real
</type>, the union
1180 result type is resolved as
<type>real
</type>.
1185 <title>Type Resolution in a Nested Union
</title>
1189 SELECT NULL UNION SELECT NULL UNION SELECT
1;
1191 ERROR: UNION types text and integer cannot be matched
1193 This failure occurs because
<productname>PostgreSQL
</productname> treats
1194 multiple
<literal>UNION
</literal>s as a nest of pairwise operations;
1195 that is, this input is the same as
1197 (SELECT NULL UNION SELECT NULL) UNION SELECT
1;
1199 The inner
<literal>UNION
</literal> is resolved as emitting
1200 type
<type>text
</type>, according to the rules given above. Then the
1201 outer
<literal>UNION
</literal> has inputs of types
<type>text
</type>
1202 and
<type>integer
</type>, leading to the observed error. The problem
1203 can be fixed by ensuring that the leftmost
<literal>UNION
</literal>
1204 has at least one input of the desired result type.
1208 <literal>INTERSECT
</literal> and
<literal>EXCEPT
</literal> operations are
1209 likewise resolved pairwise. However, the other constructs described in this
1210 section consider all of their inputs in one resolution step.
1215 <sect1 id=
"typeconv-select">
1216 <title><literal>SELECT
</literal> Output Columns
</title>
1218 <indexterm zone=
"typeconv-select">
1219 <primary>SELECT
</primary>
1220 <secondary>determination of result type
</secondary>
1224 The rules given in the preceding sections will result in assignment
1225 of non-
<type>unknown
</type> data types to all expressions in an SQL query,
1226 except for unspecified-type literals that appear as simple output
1227 columns of a
<command>SELECT
</command> command. For example, in
1230 SELECT 'Hello World';
1233 there is nothing to identify what type the string literal should be
1234 taken as. In this situation
<productname>PostgreSQL
</productname> will fall back
1235 to resolving the literal's type as
<type>text
</type>.
1239 When the
<command>SELECT
</command> is one arm of a
<literal>UNION
</literal>
1240 (or
<literal>INTERSECT
</literal> or
<literal>EXCEPT
</literal>) construct, or when it
1241 appears within
<command>INSERT ... SELECT
</command>, this rule is not applied
1242 since rules given in preceding sections take precedence. The type of an
1243 unspecified-type literal can be taken from the other
<literal>UNION
</literal> arm
1244 in the first case, or from the destination column in the second case.
1248 <literal>RETURNING
</literal> lists are treated the same as
<command>SELECT
</command>
1249 output lists for this purpose.
1254 Prior to
<productname>PostgreSQL
</productname> 10, this rule did not exist, and
1255 unspecified-type literals in a
<command>SELECT
</command> output list were
1256 left as type
<type>unknown
</type>. That had assorted bad consequences,
1257 so it's been changed.