The code to unlink dropped relations in FinishPreparedTransaction() was
[PostgreSQL.git] / doc / src / sgml / typeconv.sgml
blob70cc5eec3ca82f442956f37f72d49d8e20000425
1 <!-- $PostgreSQL$ -->
3 <chapter Id="typeconv">
4 <title>Type Conversion</title>
6 <indexterm zone="typeconv">
7 <primary>data type</primary>
8 <secondary>conversion</secondary>
9 </indexterm>
11 <para>
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.
16 </para>
18 <para>
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.
24 </para>
26 <para>
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
31 operators.
32 </para>
34 <sect1 id="typeconv-overview">
35 <title>Overview</title>
37 <para>
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 <foreignphrase>ad hoc</>
44 heuristics. This allows the use of mixed-type expressions even with
45 user-defined types.
46 </para>
48 <para>
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:
57 <screen>
58 SELECT text 'Origin' AS "label", point '(0,0)' AS "value";
60 label | value
61 --------+-------
62 Origin | (0,0)
63 (1 row)
64 </screen>
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.
70 </para>
72 <para>
73 There are four fundamental <acronym>SQL</acronym> constructs requiring
74 distinct type conversion rules in the <productname>PostgreSQL</productname>
75 parser:
77 <variablelist>
78 <varlistentry>
79 <term>
80 Function calls
81 </term>
82 <listitem>
83 <para>
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.
90 </para>
91 </listitem>
92 </varlistentry>
93 <varlistentry>
94 <term>
95 Operators
96 </term>
97 <listitem>
98 <para>
99 <productname>PostgreSQL</productname> allows expressions with
100 prefix and postfix unary (one-argument) operators,
101 as well as binary (two-argument) operators. Like functions, operators can
102 be overloaded, so the same problem of selecting the right operator
103 exists.
104 </para>
105 </listitem>
106 </varlistentry>
107 <varlistentry>
108 <term>
109 Value Storage
110 </term>
111 <listitem>
112 <para>
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.
116 </para>
117 </listitem>
118 </varlistentry>
119 <varlistentry>
120 <term>
121 <literal>UNION</literal>, <literal>CASE</literal>, and related constructs
122 </term>
123 <listitem>
124 <para>
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</> clause must be matched up and converted to a uniform set.
128 Similarly, the result expressions of a <literal>CASE</> construct must be
129 converted to a common type so that the <literal>CASE</> expression as a whole
130 has a known output type. The same holds for <literal>ARRAY</> constructs,
131 and for the <function>GREATEST</> and <function>LEAST</> functions.
132 </para>
133 </listitem>
134 </varlistentry>
135 </variablelist>
136 </para>
138 <para>
139 The system catalogs store information about which conversions, or
140 <firstterm>casts</firstterm>, exist between which data types, and how to
141 perform those conversions. Additional casts can be added by the user
142 with the <xref linkend="sql-createcast" endterm="sql-createcast-title">
143 command. (This is usually
144 done in conjunction with defining new data types. The set of casts
145 between built-in types has been carefully crafted and is best not
146 altered.)
147 </para>
149 <indexterm>
150 <primary>data type</primary>
151 <secondary>category</secondary>
152 </indexterm>
154 <para>
155 An additional heuristic provided by the parser allows improved determination
156 of the proper casting behavior among groups of types that have implicit casts.
157 Data types are divided into several basic <firstterm>type
158 categories</firstterm>, including <type>boolean</type>, <type>numeric</type>,
159 <type>string</type>, <type>bitstring</type>, <type>datetime</type>,
160 <type>timespan</type>, <type>geometric</type>, <type>network</type>, and
161 user-defined. (For a list see <xref linkend="catalog-typcategory-table">;
162 but note it is also possible to create custom type categories.) Within each
163 category there can be one or more <firstterm>preferred types</firstterm>, which
164 are preferred when there is a choice of possible types. With careful selection
165 of preferred types and available implicit casts, it is possible to ensure that
166 ambiguous expressions (those with multiple candidate parsing solutions) can be
167 resolved in a useful way.
168 </para>
170 <para>
171 All type conversion rules are designed with several principles in mind:
173 <itemizedlist>
174 <listitem>
175 <para>
176 Implicit conversions should never have surprising or unpredictable outcomes.
177 </para>
178 </listitem>
180 <listitem>
181 <para>
182 There should be no extra overhead in the parser or executor
183 if a query does not need implicit type conversion.
184 That is, if a query is well-formed and the types already match, then the query should execute
185 without spending extra time in the parser and without introducing unnecessary implicit conversion
186 calls in the query.
187 </para>
189 <para>
190 Additionally, if a query usually requires an implicit conversion for a function, and
191 if then the user defines a new function with the correct argument types, the parser
192 should use this new function and no longer do implicit conversion to use the old function.
193 </para>
194 </listitem>
195 </itemizedlist>
196 </para>
198 </sect1>
200 <sect1 id="typeconv-oper">
201 <title>Operators</title>
203 <indexterm zone="typeconv-oper">
204 <primary>operator</primary>
205 <secondary>type resolution in an invocation</secondary>
206 </indexterm>
208 <para>
209 The specific operator that is referenced by an operator expression
210 is determined using the following procedure.
211 Note that this procedure is indirectly affected
212 by the precedence of the involved operators, since that will determine
213 which sub-expressions are taken to be the inputs of which operators.
214 See <xref linkend="sql-precedence"> for more information.
215 </para>
217 <procedure>
218 <title>Operator Type Resolution</title>
220 <step performance="required">
221 <para>
222 Select the operators to be considered from the
223 <classname>pg_operator</classname> system catalog. If a non-schema-qualified
224 operator name was used (the usual case), the operators
225 considered are those with the matching name and argument count that are
226 visible in the current search path (see <xref linkend="ddl-schemas-path">).
227 If a qualified operator name was given, only operators in the specified
228 schema are considered.
229 </para>
231 <substeps>
232 <step performance="optional">
233 <para>
234 If the search path finds multiple operators with identical argument types,
235 only the one appearing earliest in the path is considered. Operators with
236 different argument types are considered on an equal footing regardless of
237 search path position.
238 </para>
239 </step>
240 </substeps>
241 </step>
243 <step performance="required">
244 <para>
245 Check for an operator accepting exactly the input argument types.
246 If one exists (there can be only one exact match in the set of
247 operators considered), use it.
248 </para>
250 <substeps>
251 <step performance="optional">
252 <para>
253 If one argument of a binary operator invocation is of the <type>unknown</type> type,
254 then assume it is the same type as the other argument for this check.
255 Invocations involving two <type>unknown</type> inputs, or a unary operator
256 with an <type>unknown</type> input, will never find a match at this step.
257 </para>
258 </step>
259 </substeps>
260 </step>
262 <step performance="required">
263 <para>
264 Look for the best match.
265 </para>
266 <substeps>
267 <step performance="required">
268 <para>
269 Discard candidate operators for which the input types do not match
270 and cannot be converted (using an implicit conversion) to match.
271 <type>unknown</type> literals are
272 assumed to be convertible to anything for this purpose. If only one
273 candidate remains, use it; else continue to the next step.
274 </para>
275 </step>
276 <step performance="required">
277 <para>
278 Run through all candidates and keep those with the most exact matches
279 on input types. (Domains are considered the same as their base type
280 for this purpose.) Keep all candidates if none have exact matches.
281 If only one candidate remains, use it; else continue to the next step.
282 </para>
283 </step>
284 <step performance="required">
285 <para>
286 Run through all candidates and keep those that accept preferred types (of the
287 input data type's type category) at the most positions where type conversion
288 will be required.
289 Keep all candidates if none accept preferred types.
290 If only one candidate remains, use it; else continue to the next step.
291 </para>
292 </step>
293 <step performance="required">
294 <para>
295 If any input arguments are <type>unknown</type>, check the type
296 categories accepted at those argument positions by the remaining
297 candidates. At each position, select the <type>string</type> category
298 if any
299 candidate accepts that category. (This bias towards string is appropriate
300 since an unknown-type literal looks like a string.) Otherwise, if
301 all the remaining candidates accept the same type category, select that
302 category; otherwise fail because the correct choice cannot be deduced
303 without more clues. Now discard
304 candidates that do not accept the selected type category. Furthermore,
305 if any candidate accepts a preferred type in that category,
306 discard candidates that accept non-preferred types for that argument.
307 </para>
308 </step>
309 <step performance="required">
310 <para>
311 If only one candidate remains, use it. If no candidate or more than one
312 candidate remains,
313 then fail.
314 </para>
315 </step>
316 </substeps>
317 </step>
318 </procedure>
320 <para>
321 Some examples follow.
322 </para>
324 <example>
325 <title>Factorial Operator Type Resolution</title>
327 <para>
328 There is only one factorial operator (postfix <literal>!</>)
329 defined in the standard catalog, and it takes an argument of type
330 <type>bigint</type>.
331 The scanner assigns an initial type of <type>integer</type> to the argument
332 in this query expression:
333 <screen>
334 SELECT 40 ! AS "40 factorial";
336 40 factorial
337 --------------------------------------------------
338 815915283247897734345611269596115894272000000000
339 (1 row)
340 </screen>
342 So the parser does a type conversion on the operand and the query
343 is equivalent to:
345 <screen>
346 SELECT CAST(40 AS bigint) ! AS "40 factorial";
347 </screen>
348 </para>
349 </example>
351 <example>
352 <title>String Concatenation Operator Type Resolution</title>
354 <para>
355 A string-like syntax is used for working with string types and for
356 working with complex extension types.
357 Strings with unspecified type are matched with likely operator candidates.
358 </para>
360 <para>
361 An example with one unspecified argument:
362 <screen>
363 SELECT text 'abc' || 'def' AS "text and unknown";
365 text and unknown
366 ------------------
367 abcdef
368 (1 row)
369 </screen>
370 </para>
372 <para>
373 In this case the parser looks to see if there is an operator taking <type>text</type>
374 for both arguments. Since there is, it assumes that the second argument should
375 be interpreted as type <type>text</type>.
376 </para>
378 <para>
379 Here is a concatenation on unspecified types:
380 <screen>
381 SELECT 'abc' || 'def' AS "unspecified";
383 unspecified
384 -------------
385 abcdef
386 (1 row)
387 </screen>
388 </para>
390 <para>
391 In this case there is no initial hint for which type to use, since no types
392 are specified in the query. So, the parser looks for all candidate operators
393 and finds that there are candidates accepting both string-category and
394 bit-string-category inputs. Since string category is preferred when available,
395 that category is selected, and then the
396 preferred type for strings, <type>text</type>, is used as the specific
397 type to resolve the unknown literals as.
398 </para>
399 </example>
401 <example>
402 <title>Absolute-Value and Negation Operator Type Resolution</title>
404 <para>
405 The <productname>PostgreSQL</productname> operator catalog has several
406 entries for the prefix operator <literal>@</>, all of which implement
407 absolute-value operations for various numeric data types. One of these
408 entries is for type <type>float8</type>, which is the preferred type in
409 the numeric category. Therefore, <productname>PostgreSQL</productname>
410 will use that entry when faced with an <type>unknown</> input:
411 <screen>
412 SELECT @ '-4.5' AS "abs";
414 -----
416 (1 row)
417 </screen>
418 Here the system has implicitly resolved the unknown-type literal as type
419 <type>float8</type> before applying the chosen operator. We can verify that
420 <type>float8</type> and not some other type was used:
421 <screen>
422 SELECT @ '-4.5e500' AS "abs";
424 ERROR: "-4.5e500" is out of range for type double precision
425 </screen>
426 </para>
428 <para>
429 On the other hand, the prefix operator <literal>~</> (bitwise negation)
430 is defined only for integer data types, not for <type>float8</type>. So, if we
431 try a similar case with <literal>~</>, we get:
432 <screen>
433 SELECT ~ '20' AS "negation";
435 ERROR: operator is not unique: ~ "unknown"
436 HINT: Could not choose a best candidate operator. You might need to add
437 explicit type casts.
438 </screen>
439 This happens because the system cannot decide which of the several
440 possible <literal>~</> operators should be preferred. We can help
441 it out with an explicit cast:
442 <screen>
443 SELECT ~ CAST('20' AS int8) AS "negation";
445 negation
446 ----------
448 (1 row)
449 </screen>
450 </para>
451 </example>
453 </sect1>
455 <sect1 id="typeconv-func">
456 <title>Functions</title>
458 <indexterm zone="typeconv-func">
459 <primary>function</primary>
460 <secondary>type resolution in an invocation</secondary>
461 </indexterm>
463 <para>
464 The specific function that is referenced by a function call
465 is determined using the following procedure.
466 </para>
468 <procedure>
469 <title>Function Type Resolution</title>
471 <step performance="required">
472 <para>
473 Select the functions to be considered from the
474 <classname>pg_proc</classname> system catalog. If a non-schema-qualified
475 function name was used, the functions
476 considered are those with the matching name and argument count that are
477 visible in the current search path (see <xref linkend="ddl-schemas-path">).
478 If a qualified function name was given, only functions in the specified
479 schema are considered.
480 </para>
482 <substeps>
483 <step performance="optional">
484 <para>
485 If the search path finds multiple functions of identical argument types,
486 only the one appearing earliest in the path is considered. Functions of
487 different argument types are considered on an equal footing regardless of
488 search path position.
489 </para>
490 </step>
491 <step performance="optional">
492 <para>
493 If a function is declared with a <literal>VARIADIC</> array parameter, and
494 the call does not use the <literal>VARIADIC</> keyword, then the function
495 is treated as if the array parameter were replaced by one or more occurrences
496 of its element type, as needed to match the call. After such expansion the
497 function might have effective argument types identical to some non-variadic
498 function. In that case the function appearing earlier in the search path is
499 used, or if the two functions are in the same schema, the non-variadic one is
500 preferred.
501 </para>
502 </step>
503 <step performance="optional">
504 <para>
505 Functions that have default values for parameters are considered to match any
506 call that omits zero or more of the defaultable parameter positions. If more
507 than one such function matches a call, the one appearing earliest in the
508 search path is used. If there are two or more such functions in the same
509 schema with identical parameter types in the non-defaulted positions (which is
510 possible if they have different sets of defaultable parameters), the system
511 will not be able to determine which to prefer, and so an <quote>ambiguous
512 function call</> error will result if no better match to the call can be
513 found.
514 </para>
515 </step>
516 </substeps>
517 </step>
519 <step performance="required">
520 <para>
521 Check for a function accepting exactly the input argument types.
522 If one exists (there can be only one exact match in the set of
523 functions considered), use it.
524 (Cases involving <type>unknown</type> will never find a match at
525 this step.)
526 </para>
527 </step>
529 <step performance="required">
530 <para>
531 If no exact match is found, see if the function call appears
532 to be a special type conversion request. This happens if the function call
533 has just one argument and the function name is the same as the (internal)
534 name of some data type. Furthermore, the function argument must be either
535 an unknown-type literal, or a type that is binary-coercible to the named
536 data type, or a type that could be converted to the named data type by
537 applying that type's I/O functions (that is, the conversion is either to or
538 from one of the standard string types). When these conditions are met,
539 the function call is treated as a form of <literal>CAST</> specification.
540 <footnote>
541 <para>
542 The reason for this step is to support function-style cast specifications
543 in cases where there is not an actual cast function. If there is a cast
544 function, it is conventionally named after its output type, and so there
545 is no need to have a special case. See
546 <xref linkend="sql-createcast" endterm="sql-createcast-title">
547 for additional commentary.
548 </para>
549 </footnote>
550 </para>
551 </step>
552 <step performance="required">
553 <para>
554 Look for the best match.
555 </para>
556 <substeps>
557 <step performance="required">
558 <para>
559 Discard candidate functions for which the input types do not match
560 and cannot be converted (using an implicit conversion) to match.
561 <type>unknown</type> literals are
562 assumed to be convertible to anything for this purpose. If only one
563 candidate remains, use it; else continue to the next step.
564 </para>
565 </step>
566 <step performance="required">
567 <para>
568 Run through all candidates and keep those with the most exact matches
569 on input types. (Domains are considered the same as their base type
570 for this purpose.) Keep all candidates if none have exact matches.
571 If only one candidate remains, use it; else continue to the next step.
572 </para>
573 </step>
574 <step performance="required">
575 <para>
576 Run through all candidates and keep those that accept preferred types (of the
577 input data type's type category) at the most positions where type conversion
578 will be required.
579 Keep all candidates if none accept preferred types.
580 If only one candidate remains, use it; else continue to the next step.
581 </para>
582 </step>
583 <step performance="required">
584 <para>
585 If any input arguments are <type>unknown</type>, check the type categories
586 accepted
587 at those argument positions by the remaining candidates. At each position,
588 select the <type>string</type> category if any candidate accepts that category.
589 (This bias towards string
590 is appropriate since an unknown-type literal looks like a string.)
591 Otherwise, if all the remaining candidates accept the same type category,
592 select that category; otherwise fail because
593 the correct choice cannot be deduced without more clues.
594 Now discard candidates that do not accept the selected type category.
595 Furthermore, if any candidate accepts a preferred type in that category,
596 discard candidates that accept non-preferred types for that argument.
597 </para>
598 </step>
599 <step performance="required">
600 <para>
601 If only one candidate remains, use it. If no candidate or more than one
602 candidate remains,
603 then fail.
604 </para>
605 </step>
606 </substeps>
607 </step>
608 </procedure>
610 <para>
611 Note that the <quote>best match</> rules are identical for operator and
612 function type resolution.
613 Some examples follow.
614 </para>
616 <example>
617 <title>Rounding Function Argument Type Resolution</title>
619 <para>
620 There is only one <function>round</function> function that takes two
621 arguments; it takes a first argument of type <type>numeric</type> and
622 a second argument of type <type>integer</type>.
623 So the following query automatically converts
624 the first argument of type <type>integer</type> to
625 <type>numeric</type>:
627 <screen>
628 SELECT round(4, 4);
630 round
631 --------
632 4.0000
633 (1 row)
634 </screen>
636 That query is actually transformed by the parser to:
637 <screen>
638 SELECT round(CAST (4 AS numeric), 4);
639 </screen>
640 </para>
642 <para>
643 Since numeric constants with decimal points are initially assigned the
644 type <type>numeric</type>, the following query will require no type
645 conversion and therefore might be slightly more efficient:
646 <screen>
647 SELECT round(4.0, 4);
648 </screen>
649 </para>
650 </example>
652 <example>
653 <title>Substring Function Type Resolution</title>
655 <para>
656 There are several <function>substr</function> functions, one of which
657 takes types <type>text</type> and <type>integer</type>. If called
658 with a string constant of unspecified type, the system chooses the
659 candidate function that accepts an argument of the preferred category
660 <literal>string</literal> (namely of type <type>text</type>).
662 <screen>
663 SELECT substr('1234', 3);
665 substr
666 --------
668 (1 row)
669 </screen>
670 </para>
672 <para>
673 If the string is declared to be of type <type>varchar</type>, as might be the case
674 if it comes from a table, then the parser will try to convert it to become <type>text</type>:
675 <screen>
676 SELECT substr(varchar '1234', 3);
678 substr
679 --------
681 (1 row)
682 </screen>
684 This is transformed by the parser to effectively become:
685 <screen>
686 SELECT substr(CAST (varchar '1234' AS text), 3);
687 </screen>
688 </para>
689 <para>
690 <note>
691 <para>
692 The parser learns from the <structname>pg_cast</> catalog that
693 <type>text</type> and <type>varchar</type>
694 are binary-compatible, meaning that one can be passed to a function that
695 accepts the other without doing any physical conversion. Therefore, no
696 type conversion call is really inserted in this case.
697 </para>
698 </note>
699 </para>
701 <para>
702 And, if the function is called with an argument of type <type>integer</type>,
703 the parser will try to convert that to <type>text</type>:
704 <screen>
705 SELECT substr(1234, 3);
706 ERROR: function substr(integer, integer) does not exist
707 HINT: No function matches the given name and argument types. You might need
708 to add explicit type casts.
709 </screen>
711 This does not work because <type>integer</> does not have an implicit cast
712 to <type>text</>. An explicit cast will work, however:
713 <screen>
714 SELECT substr(CAST (1234 AS text), 3);
716 substr
717 --------
719 (1 row)
720 </screen>
721 </para>
722 </example>
724 </sect1>
726 <sect1 id="typeconv-query">
727 <title>Value Storage</title>
729 <para>
730 Values to be inserted into a table are converted to the destination
731 column's data type according to the
732 following steps.
733 </para>
735 <procedure>
736 <title>Value Storage Type Conversion</title>
738 <step performance="required">
739 <para>
740 Check for an exact match with the target.
741 </para>
742 </step>
744 <step performance="required">
745 <para>
746 Otherwise, try to convert the expression to the target type. This will succeed
747 if there is a registered cast between the two types.
748 If the expression is an unknown-type literal, the contents of
749 the literal string will be fed to the input conversion routine for the target
750 type.
751 </para>
752 </step>
754 <step performance="required">
755 <para>
756 Check to see if there is a sizing cast for the target type. A sizing
757 cast is a cast from that type to itself. If one is found in the
758 <structname>pg_cast</> catalog, apply it to the expression before storing
759 into the destination column. The implementation function for such a cast
760 always takes an extra parameter of type <type>integer</type>, which receives
761 the destination column's declared length (actually, its
762 <structfield>atttypmod</> value; the interpretation of
763 <structfield>atttypmod</> varies for different data types). The cast function
764 is responsible for applying any length-dependent semantics such as size
765 checking or truncation.
766 </para>
767 </step>
769 </procedure>
771 <example>
772 <title><type>character</type> Storage Type Conversion</title>
774 <para>
775 For a target column declared as <type>character(20)</type> the following statement
776 ensures that the stored value is sized correctly:
778 <screen>
779 CREATE TABLE vv (v character(20));
780 INSERT INTO vv SELECT 'abc' || 'def';
781 SELECT v, length(v) FROM vv;
783 v | length
784 ----------------------+--------
785 abcdef | 20
786 (1 row)
787 </screen>
788 </para>
790 <para>
791 What has really happened here is that the two unknown literals are resolved
792 to <type>text</type> by default, allowing the <literal>||</literal> operator
793 to be resolved as <type>text</type> concatenation. Then the <type>text</type>
794 result of the operator is converted to <type>bpchar</type> (<quote>blank-padded
795 char</>, the internal name of the <type>character</type> data type) to match the target
796 column type. (Since the conversion from <type>text</type> to
797 <type>bpchar</type> is binary-coercible, this conversion does
798 not insert any real function call.) Finally, the sizing function
799 <literal>bpchar(bpchar, integer)</literal> is found in the system catalog
800 and applied to the operator's result and the stored column length. This
801 type-specific function performs the required length check and addition of
802 padding spaces.
803 </para>
804 </example>
805 </sect1>
807 <sect1 id="typeconv-union-case">
808 <title><literal>UNION</literal>, <literal>CASE</literal>, and Related Constructs</title>
810 <indexterm zone="typeconv-union-case">
811 <primary>UNION</primary>
812 <secondary>determination of result type</secondary>
813 </indexterm>
815 <indexterm zone="typeconv-union-case">
816 <primary>CASE</primary>
817 <secondary>determination of result type</secondary>
818 </indexterm>
820 <indexterm zone="typeconv-union-case">
821 <primary>ARRAY</primary>
822 <secondary>determination of result type</secondary>
823 </indexterm>
825 <indexterm zone="typeconv-union-case">
826 <primary>VALUES</primary>
827 <secondary>determination of result type</secondary>
828 </indexterm>
830 <indexterm zone="typeconv-union-case">
831 <primary>GREATEST</primary>
832 <secondary>determination of result type</secondary>
833 </indexterm>
835 <indexterm zone="typeconv-union-case">
836 <primary>LEAST</primary>
837 <secondary>determination of result type</secondary>
838 </indexterm>
840 <para>
841 SQL <literal>UNION</> constructs must match up possibly dissimilar
842 types to become a single result set. The resolution algorithm is
843 applied separately to each output column of a union query. The
844 <literal>INTERSECT</> and <literal>EXCEPT</> constructs resolve
845 dissimilar types in the same way as <literal>UNION</>. The
846 <literal>CASE</>, <literal>ARRAY</>, <literal>VALUES</>,
847 <function>GREATEST</> and <function>LEAST</> constructs use the identical
848 algorithm to match up their component expressions and select a result
849 data type.
850 </para>
852 <procedure>
853 <title>Type Resolution for <literal>UNION</literal>, <literal>CASE</literal>,
854 and Related Constructs</title>
856 <step performance="required">
857 <para>
858 If all inputs are of the same type, and it is not <type>unknown</type>,
859 resolve as that type. Otherwise, replace any domain types in the list with
860 their underlying base types.
861 </para>
862 </step>
864 <step performance="required">
865 <para>
866 If all inputs are of type <type>unknown</type>, resolve as type
867 <type>text</type> (the preferred type of the string category).
868 Otherwise, <type>unknown</type> inputs are ignored.
869 </para>
870 </step>
872 <step performance="required">
873 <para>
874 If the non-unknown inputs are not all of the same type category, fail.
875 </para>
876 </step>
878 <step performance="required">
879 <para>
880 Choose the first non-unknown input type which is a preferred type in
881 that category, if there is one.
882 </para>
883 </step>
885 <step performance="required">
886 <para>
887 Otherwise, choose the last non-unknown input type that allows all the
888 preceding non-unknown inputs to be implicitly converted to it. (There
889 always is such a type, since at least the first type in the list must
890 satisfy this condition.)
891 </para>
892 </step>
894 <step performance="required">
895 <para>
896 Convert all inputs to the selected type. Fail if there is not a
897 conversion from a given input to the selected type.
898 </para>
899 </step>
900 </procedure>
902 <para>
903 Some examples follow.
904 </para>
906 <example>
907 <title>Type Resolution with Underspecified Types in a Union</title>
909 <para>
910 <screen>
911 SELECT text 'a' AS "text" UNION SELECT 'b';
913 text
914 ------
917 (2 rows)
918 </screen>
919 Here, the unknown-type literal <literal>'b'</literal> will be resolved to type <type>text</type>.
920 </para>
921 </example>
923 <example>
924 <title>Type Resolution in a Simple Union</title>
926 <para>
927 <screen>
928 SELECT 1.2 AS "numeric" UNION SELECT 1;
930 numeric
931 ---------
934 (2 rows)
935 </screen>
936 The literal <literal>1.2</> is of type <type>numeric</>,
937 and the <type>integer</type> value <literal>1</> can be cast implicitly to
938 <type>numeric</>, so that type is used.
939 </para>
940 </example>
942 <example>
943 <title>Type Resolution in a Transposed Union</title>
945 <para>
946 <screen>
947 SELECT 1 AS "real" UNION SELECT CAST('2.2' AS REAL);
949 real
950 ------
953 (2 rows)
954 </screen>
955 Here, since type <type>real</> cannot be implicitly cast to <type>integer</>,
956 but <type>integer</> can be implicitly cast to <type>real</>, the union
957 result type is resolved as <type>real</>.
958 </para>
959 </example>
961 </sect1>
962 </chapter>