aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/typeconv.sgml
blob: 0bf7fe8967d8e31049eb2b29c298622ecbda6c77 (plain)
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
<chapter Id="typeconv">
<title>Type Conversion</title>

<para>
<acronym>SQL</acronym> queries can, intentionally or not, require
mixing of different data types in the same expression. 
<productname>Postgres</productname> has extensive facilities for
evaluating mixed-type expressions.
</para>

<para>
In many cases a user will not need
to understand the details of the type conversion mechanism.
However, the implicit conversions done by <productname>Postgres</productname>
can affect the results of a query.  When necessary, these results
can be tailored by a user or programmer
using <emphasis>explicit</emphasis> type coercion.
</para>

<para>
This chapter introduces the <productname>Postgres</productname>
type conversion mechanisms and conventions.
Refer to the relevant sections in the User's Guide and Programmer's Guide
for more information on specific data types and allowed functions and
operators.
</para>

<para>
The Programmer's Guide has more details on the exact algorithms used for
implicit type conversion and coercion.
</para>

<sect1 id="typeconv-overview">
<title>Overview</title>

<para>
<acronym>SQL</acronym> is a strongly typed language. That is, every data item
has an associated data type which determines its behavior and allowed usage.
<productname>Postgres</productname> has an extensible type system that is
much more general and flexible than other <acronym>RDBMS</acronym> implementations.
Hence, most type conversion behavior in <productname>Postgres</productname>
should be governed by general rules rather than by ad-hoc heuristics to allow
mixed-type expressions to be meaningful, even with user-defined types.
</para>

<para>
The <productname>Postgres</productname> scanner/parser decodes lexical
elements into only five fundamental categories: integers, floats, strings,
names, and keywords.  Most extended types are first tokenized into
strings. The <acronym>SQL</acronym> language definition allows specifying type
names with strings, and this mechanism can be used in
<productname>Postgres</productname> to start the parser down the correct
path. For example, the query

<programlisting>
tgl=> SELECT text 'Origin' AS "Label", point '(0,0)' AS "Value";
 Label  | Value
--------+-------
 Origin | (0,0)
(1 row)
</programlisting>

has two strings, of type <type>text</type> and <type>point</type>.
If a type is not specified for a string, then the placeholder type
<firstterm>unknown</firstterm> is assigned initially, to be resolved in later
stages as described below.
</para>

<para>
There are four fundamental <acronym>SQL</acronym> constructs requiring
distinct type conversion rules in the <productname>Postgres</productname>
parser:
</para>

<variablelist>
<varlistentry>
<term>
Operators
</term>
<listitem>
<para>
<productname>Postgres</productname> allows expressions with
left- and right-unary (one argument) operators,
as well as binary (two argument) operators.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
Function calls
</term>
<listitem>
<para>
Much of the <productname>Postgres</productname> type system is built around a
rich set of functions. Function calls have one or more arguments which, for
any specific query, must be matched to the functions available in the system
catalog.  Since <productname>Postgres</productname> permits function
overloading, the function name alone does not uniquely identify the function
to be called --- the parser must select the right function based on the data
types of the supplied arguments.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
Query targets
</term>
<listitem>
<para>
<acronym>SQL</acronym> INSERT and UPDATE statements place the results of
expressions into a table. The expressions in the query must be matched up
with, and perhaps converted to, the types of the target columns.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
UNION and CASE constructs
</term>
<listitem>
<para>
Since all select results from a UNION SELECT statement must appear in a single
set of columns, the types of the results
of each SELECT clause must be matched up and converted to a uniform set.
Similarly, the result expressions of a CASE construct must be coerced to
a common type so that the CASE expression as a whole has a known output type.
</para>
</listitem>
</varlistentry>
</variablelist>

<para>
Many of the general type conversion rules use simple conventions built on
the <productname>Postgres</productname> function and operator system tables.
There are some heuristics included in the conversion rules to better support
conventions for the <acronym>SQL92</acronym> standard native types such as
<type>smallint</type>, <type>integer</type>, and <type>float</type>.
</para>

<para>
The <productname>Postgres</productname> parser uses the convention that all
type conversion functions take a single argument of the source type and are
named with the same name as the target type. Any function meeting these
criteria is considered to be a valid conversion function, and may be used
by the parser as such. This simple assumption gives the parser the power
to explore type conversion possibilities without hardcoding, allowing
extended user-defined types to use these same features transparently.
</para>

<para>
An additional heuristic is provided in the parser to allow better guesses
at proper behavior for <acronym>SQL</acronym> standard types. There are
several basic <firstterm>type categories</firstterm> defined: boolean,
numeric, string, bitstring, datetime, timespan, geometric, network,
and user-defined. Each category, with the exception of user-defined, has
a <firstterm>preferred type</firstterm> which is preferentially selected
when there is ambiguity.
In the user-defined category, each type is its own preferred type.
Ambiguous expressions (those with multiple candidate parsing solutions)
can often be resolved when there are multiple possible built-in types, but
they will raise an error when there are multiple choices for user-defined
types.
</para>

<sect2>
<title>Guidelines</title>

<para>
All type conversion rules are designed with several principles in mind:

<itemizedlist mark="bullet" spacing="compact">
<listitem>
<para>
Implicit conversions should never have surprising or unpredictable outcomes.
</para>
</listitem>

<listitem>
<para>
User-defined types, of which the parser has no a-priori knowledge, should be
"higher" in the type hierarchy. In mixed-type expressions, native types shall always
be converted to a user-defined type (of course, only if conversion is necessary).
</para>
</listitem>

<listitem>
<para>
User-defined types are not related. Currently, <productname>Postgres</productname>
does not have information available to it on relationships between types, other than
hardcoded heuristics for built-in types and implicit relationships based on available functions
in the catalog.
</para>
</listitem>

<listitem>
<para>
There should be no extra overhead from the parser or executor
if a query does not need implicit type conversion.
That is, if a query is well formulated and the types already match up, then the query should proceed
without spending extra time in the parser and without introducing unnecessary implicit conversion
functions into the query.
</para>

<para>
Additionally, if a query usually requires an implicit conversion for a function, and
if then the user defines an explicit function with the correct argument types, the parser
should use this new function and will no longer do the implicit conversion using the old function.
</para>
</listitem>
</itemizedlist>
</para>
</sect2>
</sect1>

<sect1 id="typeconv-oper">
<title>Operators</title>

<procedure>
<title>Operator Type Resolution</title>

<step performance="required">
<para>
Check for an exact match in the pg_operator system catalog.
</para>

<substeps>
<step performance="optional">
<para>
If one argument of a binary operator is <type>unknown</type> type,
then assume it is the same type as the other argument for this check.
Other cases involving <type>unknown</type> will never find a match at
this step.
</para>
</step>
</substeps>
</step>

<step performance="required">
<para>
Look for the best match.
</para>
<substeps>
<step performance="required">
<para>
Make a list of all operators of the same name for which the input types
match or can be coerced to match.  (<type>unknown</type> literals are
assumed to be coercible to anything for this purpose.)  If there is only
one, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
Run through all candidates and keep those with the most exact matches
on input types.  Keep all candidates if none have any exact matches.
If only one candidate remains, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
Run through all candidates and keep those with the most exact or
binary-compatible matches on input types.  Keep all candidates if none have
any exact or binary-compatible matches.
If only one candidate remains, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
Run through all candidates and keep those that accept preferred types at
the most positions where type coercion will be required.
Keep all candidates if none accept preferred types.
If only one candidate remains, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
If any input arguments are "unknown", check the type categories accepted
at those argument positions by the remaining candidates.  At each position,
select "string"
category if any candidate accepts that category (this bias towards string
is appropriate since an unknown-type literal does look like a string).
Otherwise, if all the remaining candidates accept the same type category,
select that category; otherwise fail because
the correct choice cannot be deduced without more clues.  Also note whether
any of the candidates accept a preferred datatype within the selected category.
Now discard operator candidates that do not accept the selected type category;
furthermore, if any candidate accepts a preferred type at a given argument
position, discard candidates that accept non-preferred types for that
argument.
</para>
</step>
<step performance="required">
<para>
If only one candidate remains, use it.  If no candidate or more than one
candidate remains,
then fail.
</para>
</step>
</substeps>
</step>
</procedure>

<sect2>
<title>Examples</title>

<sect3>
<title>Exponentiation Operator</title>

<para>
There is only one exponentiation
operator defined in the catalog, and it takes arguments of type 
<type>double precision</type>.
The scanner assigns an initial type of <type>int4</type> to both arguments
of this query expression:
<programlisting>
tgl=> select 2 ^ 3 AS "Exp";
 Exp
-----
   8
(1 row)
</programlisting>

So the parser does a type conversion on both operands and the query
is equivalent to

<programlisting>
tgl=> select CAST(2 AS double precision) ^ CAST(3 AS double precision) AS "Exp";
 Exp
-----
   8
(1 row)
</programlisting>

or

<programlisting>
tgl=> select 2.0 ^ 3.0 AS "Exp";
 Exp
-----
   8
(1 row)
</programlisting>

<note>
<para>
This last form has the least overhead, since no functions are called to do
implicit type conversion. This is not an issue for small queries, but may
have an impact on the performance of queries involving large tables.
</para>
</note>
</para>
</sect3>

<sect3>
<title>String Concatenation</title>

<para>
A string-like syntax is used for working with string types as well as for
working with complex extended types.
Strings with unspecified type are matched with likely operator candidates.
</para>

<para>
One unspecified argument:
<programlisting>
tgl=> SELECT text 'abc' || 'def' AS "Text and Unknown";
 Text and Unknown
------------------
 abcdef
(1 row)
</programlisting>
</para>

<para>
In this case the parser looks to see if there is an operator taking <type>text</type>
for both arguments. Since there is, it assumes that the second argument should
be interpreted as of type <type>text</type>.
</para>

<para>
Concatenation on unspecified types:
<programlisting>
tgl=> SELECT 'abc' || 'def' AS "Unspecified";
 Unspecified
-------------
 abcdef
(1 row)
</programlisting>
</para>

<para>
In this case there is no initial hint for which type to use, since no types
are specified in the query. So, the parser looks for all candidate operators
and finds that there are candidates accepting both string-category and
bitstring-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 to.
</para>
</sect3>

<sect3>
<title>Factorial</title>

<para>
This example illustrates an interesting result. Traditionally, the
factorial operator is defined for integers only. The <productname>Postgres</productname>
operator catalog has only one entry for factorial, taking an integer operand.
If given a non-integer numeric argument, <productname>Postgres</productname>
will try to convert that argument to an integer for evaluation of the
factorial.

<programlisting>
tgl=> select (4.3 !);
 ?column?
----------
       24
(1 row)
</programlisting>

<note>
<para>
Of course, this leads to a mathematically suspect result,
since in principle the factorial of a non-integer is not defined.
However, the role of a database is not to teach mathematics, but
to be a tool for data manipulation. If a user chooses to take the
factorial of a floating point number, <productname>Postgres</productname>
will try to oblige.
</para>
</note>
</para>
</sect3>
</sect2>
</sect1>

<sect1 id="typeconv-func">
<title>Functions</title>

<procedure>
<title>Function Call Type Resolution</title>

<step performance="required">
<para>
Check for an exact match in the pg_proc system catalog.
(Cases involving <type>unknown</type> will never find a match at
this step.)
</para></step>
<step performance="required">
<para>
Look for the best match.
</para>
<substeps>
<step performance="required">
<para>
Make a list of all functions of the same name with the same number of
arguments for which the input types
match or can be coerced to match.  (<type>unknown</type> literals are
assumed to be coercible to anything for this purpose.)  If there is only
one, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
Run through all candidates and keep those with the most exact matches
on input types.  Keep all candidates if none have any exact matches.
If only one candidate remains, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
Run through all candidates and keep those with the most exact or
binary-compatible matches on input types.  Keep all candidates if none have
any exact or binary-compatible matches.
If only one candidate remains, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
Run through all candidates and keep those that accept preferred types at
the most positions where type coercion will be required.
Keep all candidates if none accept preferred types.
If only one candidate remains, use it; else continue to the next step.
</para>
</step>
<step performance="required">
<para>
If any input arguments are "unknown", check the type categories accepted
at those argument positions by the remaining candidates.  At each position,
select "string"
category if any candidate accepts that category (this bias towards string
is appropriate since an unknown-type literal does look like a string).
Otherwise, if all the remaining candidates accept the same type category,
select that category; otherwise fail because
the correct choice cannot be deduced without more clues.  Also note whether
any of the candidates accept a preferred datatype within the selected category.
Now discard operator candidates that do not accept the selected type category;
furthermore, if any candidate accepts a preferred type at a given argument
position, discard candidates that accept non-preferred types for that
argument.
</para>
</step>
<step performance="required">
<para>
If only one candidate remains, use it.  If no candidate or more than one
candidate remains,
then fail.
</para>
</step>
</substeps>
</step>
<step performance="required">
<para>
If no best match could be identified, see whether the function call appears
to be a trivial type coercion request.  This happens if the function call
has just one argument and the function name is the same as the (internal)
name of some datatype.  Furthermore, the function argument must be either
an unknown-type literal or a type that is binary-compatible with the named
datatype.  When these conditions are met, the function argument is coerced
to the named datatype.
</para>
</step>
</procedure>

<sect2>
<title>Examples</title>

<sect3>
<title>Factorial Function</title>

<para>
There is only one factorial function defined in the pg_proc catalog.
So the following query automatically converts the <type>int2</type> argument
to <type>int4</type>:

<programlisting>
tgl=> select int4fac(int2 '4');
 int4fac
---------
      24
(1 row)
</programlisting>

and is actually transformed by the parser to
<programlisting>
tgl=> select int4fac(int4(int2 '4'));
 int4fac
---------
      24
(1 row)
</programlisting>
</para>
</sect3>

<sect3>
<title>Substring Function</title>

<para>
There are two <function>substr</function> functions declared in pg_proc. However,
only one takes two arguments, of types <type>text</type> and <type>int4</type>.
</para>

<para>
If called with a string constant of unspecified type, the type is matched up
directly with the only candidate function type:
<programlisting>
tgl=> select substr('1234', 3);
 substr
--------
     34
(1 row)
</programlisting>
</para>

<para>
If the string is declared to be of type <type>varchar</type>, as might be the case
if it comes from a table, then the parser will try to coerce it to become <type>text</type>:
<programlisting>
tgl=> select substr(varchar '1234', 3);
 substr
--------
     34
(1 row)
</programlisting>
which is transformed by the parser to become
<programlisting>
tgl=> select substr(text(varchar '1234'), 3);
 substr
--------
     34
(1 row)
</programlisting>
</para>
<note>
<para>
Actually, the parser is aware that <type>text</type> and <type>varchar</type>
are "binary compatible", meaning that one can be passed to a function that
accepts the other without doing any physical conversion.  Therefore, no
explicit type conversion call is really inserted in this case.
</para>
</note>

<para>
And, if the function is called with an <type>int4</type>, the parser will
try to convert that to <type>text</type>:
<programlisting>
tgl=> select substr(1234, 3);
 substr
--------
     34
(1 row)
</programlisting>
actually executes as
<programlisting>
tgl=> select substr(text(1234), 3);
 substr
--------
     34
(1 row)
</programlisting>
This succeeds because there is a conversion function text(int4) in the
system catalog.
</para>
</sect3>
</sect2>
</sect1>

<sect1 id="typeconv-query">
<title>Query Targets</title>

<procedure>
<title>Query Target Type Resolution</title>

<step performance="required">
<para>
Check for an exact match with the target.
</para></step>
<step performance="required">
<para>
Otherwise, try to coerce the expression to the target type.  This will succeed
if the two types are known binary-compatible, or if there is a conversion
function.  If the expression is an unknown-type literal, the contents of
the literal string will be fed to the input conversion routine for the target
type.
</para></step>

<step performance="required">
<para>
If the target is a fixed-length type (e.g. <type>char</type> or <type>varchar</type>
declared with a length) then try to find a sizing function for the target
type.  A sizing function is a function of the same name as the type,
taking two arguments of which the first is that type and the second is an
integer, and returning the same type.  If one is found, it is applied,
passing the column's declared length as the second parameter.
</para></step>

</procedure>

<sect2>
<title>Examples</title>

<sect3>
<title><type>varchar</type> Storage</title>

<para>
For a target column declared as <type>varchar(4)</type> the following query
ensures that the target is sized correctly:

<programlisting>
tgl=> CREATE TABLE vv (v varchar(4));
CREATE
tgl=> INSERT INTO vv SELECT 'abc' || 'def';
INSERT 392905 1
tgl=> SELECT * FROM vv;
  v
------
 abcd
(1 row)
</programlisting>

What's really happened here is that the two unknown literals are resolved
to text by default, allowing the <literal>||</literal> operator to be
resolved as text concatenation.  Then the text result of the operator
is coerced to varchar to match the target column type.  (But, since the
parser knows that text and varchar are binary-compatible, this coercion
is implicit and does not insert any real function call.)  Finally, the
sizing function <literal>varchar(varchar,int4)</literal> is found in the system
catalogs and applied to the operator's result and the stored column length.
This type-specific function performs the desired truncation.
</para>
</sect3>
</sect2>
</sect1>

<sect1 id="typeconv-union-case">
<title>UNION and CASE Constructs</title>

<para>
The UNION and CASE constructs must match up possibly dissimilar types to
become a single result set.  The resolution algorithm is applied separately to
each output column of a UNION.  CASE uses the identical algorithm to match
up its result expressions.
</para>
<procedure>
<title>UNION and CASE Type Resolution</title>

<step performance="required">
<para>
If all inputs are of type <type>unknown</type>, resolve as type
<type>text</type> (the preferred type for string category).
Otherwise, ignore the <type>unknown</type> inputs while choosing the type.
</para></step>

<step performance="required">
<para>
If the non-unknown inputs are not all of the same type category, fail.
</para></step>

<step performance="required">
<para>
If one or more non-unknown inputs are of a preferred type in that category,
resolve as that type.
</para></step>

<step performance="required">
<para>
Otherwise, resolve as the type of the first non-unknown input.
</para></step>

<step performance="required">
<para>
Coerce all inputs to the selected type.
</para></step>
</procedure>

<sect2>
<title>Examples</title>

<sect3>
<title>Underspecified Types</title>

<para>
<programlisting>
tgl=> SELECT text 'a' AS "Text" UNION SELECT 'b';
 Text
------
 a
 b
(2 rows)
</programlisting>
Here, the unknown-type literal 'b' will be resolved as type text.
</para>
</sect3>

<sect3>
<title>Simple UNION</title>

<para>
<programlisting>
tgl=> SELECT 1.2 AS "Double" UNION SELECT 1;
 Double
--------
      1
    1.2
(2 rows)
</programlisting>
</para>
</sect3>

<sect3>
<title>Transposed UNION</title>

<para>
Here the output type of the union is forced to match the type of
the first/top clause in the union:

<programlisting>
tgl=> SELECT 1 AS "All integers"
tgl-> UNION SELECT CAST('2.2' AS REAL);
 All integers
--------------
            1
            2
(2 rows)
</programlisting>
</para>
<para>
Since <type>REAL</type> is not a preferred type, the parser sees no reason
to select it over <type>INTEGER</type> (which is what the 1 is), and instead
falls back on the use-the-first-alternative rule.
This example demonstrates that the preferred-type mechanism doesn't encode
as much information as we'd like.  Future versions of
<productname>Postgres</productname> may support a more general notion of
type preferences.
</para>
</sect3>
</sect2>
</sect1>
</chapter>

<!-- Keep this comment at the end of the file
Local variables:
mode:sgml
sgml-omittag:t
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:("/usr/lib/sgml/catalog")
sgml-local-ecat-files:nil
End:
-->