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