Type Conversion Introduction SQL queries can, intentionally or not, require mixing of different data types in the same expression. PostgreSQL has extensive facilities for evaluating mixed-type expressions. In many cases a user will not need to understand the details of the type conversion mechanism. However, the implicit conversions done by PostgreSQL can affect the results of a query. When necessary, these results can be tailored by a user or programmer using explicit type coercion. This chapter introduces the PostgreSQL type conversion mechanisms and conventions. Refer to the relevant sections in and for more information on specific data types and allowed functions and operators. The Programmer's Guide has more details on the exact algorithms used for implicit type conversion and coercion. Overview SQL is a strongly typed language. That is, every data item has an associated data type which determines its behavior and allowed usage. PostgreSQL has an extensible type system that is much more general and flexible than other RDBMS implementations. Hence, most type conversion behavior in PostgreSQL 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. The PostgreSQL scanner/parser decodes lexical elements into only five fundamental categories: integers, floating-point numbers, strings, names, and key words. Most extended types are first tokenized into strings. The SQL language definition allows specifying type names with strings, and this mechanism can be used in PostgreSQL to start the parser down the correct path. For example, the query tgl=> SELECT text 'Origin' AS "Label", point '(0,0)' AS "Value"; Label | Value --------+------- Origin | (0,0) (1 row) has two literal constants, of type text and point. If a type is not specified for a string literal, then the placeholder type unknown is assigned initially, to be resolved in later stages as described below. There are four fundamental SQL constructs requiring distinct type conversion rules in the PostgreSQL parser: Operators PostgreSQL allows expressions with prefix and postfix unary (one-argument) operators, as well as binary (two-argument) operators. Function calls Much of the PostgreSQL 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 PostgreSQL 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. Query targets SQL 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. UNION and CASE constructs Since all select results from a unionized 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. Many of the general type conversion rules use simple conventions built on the PostgreSQL function and operator system tables. There are some heuristics included in the conversion rules to better support conventions for the SQL standard native types such as smallint, integer, and real. The PostgreSQL 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. An additional heuristic is provided in the parser to allow better guesses at proper behavior for SQL standard types. There are several basic type categories defined: boolean, numeric, string, bitstring, datetime, timespan, geometric, network, and user-defined. Each category, with the exception of user-defined, has a preferred type 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. All type conversion rules are designed with several principles in mind: Implicit conversions should never have surprising or unpredictable outcomes. 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). User-defined types are not related. Currently, PostgreSQL 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. 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. 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. Operators The operand types of an operator invocation are resolved following the procedure below. Note that this procedure is indirectly affected by the precedence of the involved operators. See for more information. Operand Type Resolution Select the operators to be considered from the pg_operator system catalog. If an unqualified operator name is used (the usual case), the operators considered are those of the right name and argument count that are visible in the current search path (see ). If a qualified operator name was given, only operators in the specified schema are considered. If the search path finds multiple operators of identical argument types, only the one appearing earliest in the path is considered. But operators of different argument types are considered on an equal footing regardless of search path position. 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. If one argument of a binary operator is unknown type, then assume it is the same type as the other argument for this check. Other cases involving unknown will never find a match at this step. Look for the best match. Discard candidate operators for which the input types do not match and cannot be coerced (using an implicit coercion function) to match. unknown literals are assumed to be coercible to anything for this purpose. If only one candidate remains, use it; else continue to the next step. 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. 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. 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. If any input arguments are unknown, check the type categories accepted at those argument positions by the remaining candidates. At each position, select the "string" category if any candidate accepts that category (this bias towards string is appropriate since an unknown-type literal does look like a string). Otherwise, if all the remaining candidates accept the same type category, select that category; otherwise fail because the correct choice cannot be deduced without more clues. Also note whether any of the candidates accept a preferred data type within the selected category. Now discard operator candidates that do not accept the selected type category; furthermore, if any candidate accepts a preferred type at a given argument position, discard candidates that accept non-preferred types for that argument. If only one candidate remains, use it. If no candidate or more than one candidate remains, then fail. Examples Exponentiation Operator Type Resolution There is only one exponentiation operator defined in the catalog, and it takes arguments of type double precision. The scanner assigns an initial type of integer to both arguments of this query expression: tgl=> SELECT 2 ^ 3 AS "Exp"; Exp ----- 8 (1 row) So the parser does a type conversion on both operands and the query is equivalent to tgl=> SELECT CAST(2 AS double precision) ^ CAST(3 AS double precision) AS "Exp"; Exp ----- 8 (1 row) or tgl=> SELECT 2.0 ^ 3.0 AS "Exp"; Exp ----- 8 (1 row) 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. String Concatenation Operator Type Resolution 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. An example with one unspecified argument: tgl=> SELECT text 'abc' || 'def' AS "Text and Unknown"; Text and Unknown ------------------ abcdef (1 row) In this case the parser looks to see if there is an operator taking text for both arguments. Since there is, it assumes that the second argument should be interpreted as of type text. Concatenation on unspecified types: tgl=> SELECT 'abc' || 'def' AS "Unspecified"; Unspecified ------------- abcdef (1 row) 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, text, is used as the specific type to resolve the unknown literals to. Absolute-Value and Factorial Operator Type Resolution The PostgreSQL operator catalog has several entries for the prefix operator @, all of which implement absolute-value operations for various numeric data types. One of these entries is for type float8, which is the preferred type in the numeric category. Therefore, PostgreSQL will use that entry when faced with a non-numeric input: tgl=> select @ text '-4.5' as "abs"; abs ----- 4.5 (1 row) Here the system has performed an implicit text-to-float8 conversion before applying the chosen operator. We can verify that float8 and not some other type was used: tgl=> select @ text '-4.5e500' as "abs"; ERROR: Input '-4.5e500' is out of range for float8 On the other hand, the postfix operator ! (factorial) is defined only for integer data types, not for float8. So, if we try a similar case with !, we get: tgl=> select text '20' ! as "factorial"; ERROR: Unable to identify a postfix operator '!' for type 'text' You may need to add parentheses or an explicit cast This happens because the system can't decide which of the several possible ! operators should be preferred. We can help it out with an explicit cast: tgl=> select cast(text '20' as int8) ! as "factorial"; factorial --------------------- 2432902008176640000 (1 row) Functions The argument types of function calls are resolved according to the following steps. Function Argument Type Resolution Select the functions to be considered from the pg_proc system catalog. If an unqualified function name is used, the functions considered are those of the right name and argument count that are visible in the current search path (see ). If a qualified function name was given, only functions in the specified schema are considered. If the search path finds multiple functions of identical argument types, only the one appearing earliest in the path is considered. But functions of different argument types are considered on an equal footing regardless of search path position. 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 unknown will never find a match at this step.) If no exact match is found, see whether the function call appears to be a trivial type coercion request. This happens if the function call has just one argument and the function name is the same as the (internal) name of some data type. Furthermore, the function argument must be either an unknown-type literal or a type that is binary-compatible with the named data type. When these conditions are met, the function argument is coerced to the named data type without any explicit function call. Look for the best match. Discard candidate functions for which the input types do not match and cannot be coerced (using an implicit coercion function) to match. unknown literals are assumed to be coercible to anything for this purpose. If only one candidate remains, use it; else continue to the next step. 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. 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. 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. If any input arguments are unknown, check the type categories accepted at those argument positions by the remaining candidates. At each position, select the string category if any candidate accepts that category (this bias towards string is appropriate since an unknown-type literal does look like a string). Otherwise, if all the remaining candidates accept the same type category, select that category; otherwise fail because the correct choice cannot be deduced without more clues. Also note whether any of the candidates accept a preferred data type within the selected category. Now discard 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. If only one candidate remains, use it. If no candidate or more than one candidate remains, then fail. Examples Factorial Function Argument Type Resolution There is only one int4fac function defined in the pg_proc catalog. So the following query automatically converts the int2 argument to int4: tgl=> SELECT int4fac(int2 '4'); int4fac --------- 24 (1 row) and is actually transformed by the parser to tgl=> SELECT int4fac(int4(int2 '4')); int4fac --------- 24 (1 row) Substring Function Type Resolution There are two substr functions declared in pg_proc. However, only one takes two arguments, of types text and int4. If called with a string constant of unspecified type, the type is matched up directly with the only candidate function type: tgl=> SELECT substr('1234', 3); substr -------- 34 (1 row) If the string is declared to be of type varchar, as might be the case if it comes from a table, then the parser will try to coerce it to become text: tgl=> SELECT substr(varchar '1234', 3); substr -------- 34 (1 row) which is transformed by the parser to become tgl=> SELECT substr(text(varchar '1234'), 3); substr -------- 34 (1 row) Actually, the parser is aware that text and varchar 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. And, if the function is called with an int4, the parser will try to convert that to text: tgl=> SELECT substr(1234, 3); substr -------- 34 (1 row) which actually executes as tgl=> SELECT substr(text(1234), 3); substr -------- 34 (1 row) This succeeds because there is a conversion function text(int4) in the system catalog. Query Targets Values to be inserted into a table are coerced to the destination column's data type according to the following steps. Query Target Type Resolution Check for an exact match with the target. 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. If the target is a fixed-length type (e.g. char or varchar 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. <type>character</type> Storage Type Conversion For a target column declared as character(20) the following query ensures that the target is sized correctly: tgl=> CREATE TABLE vv (v character(20)); CREATE tgl=> INSERT INTO vv SELECT 'abc' || 'def'; INSERT 392905 1 tgl=> SELECT v, length(v) FROM vv; v | length ----------------------+-------- abcdef | 20 (1 row) What has really happened here is that the two unknown literals are resolved to text by default, allowing the || operator to be resolved as text concatenation. Then the text result of the operator is coerced to bpchar (blank-padded char, the internal name of the character data type) to match the target column type. (Since the parser knows that text and bpchar are binary-compatible, this coercion is implicit and does not insert any real function call.) Finally, the sizing function bpchar(bpchar, integer) is found in the system catalogs 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. <literal>UNION</> and <literal>CASE</> Constructs SQL 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 INTERSECT and EXCEPT constructs resolve dissimilar types in the same way as UNION. A CASE construct also uses the identical algorithm to match up its component expressions and select a result data type. <literal>UNION</> and <literal>CASE</> Type Resolution If all inputs are of type unknown, resolve as type text (the preferred type for string category). Otherwise, ignore the unknown inputs while choosing the type. If the non-unknown inputs are not all of the same type category, fail. Choose the first non-unknown input type which is a preferred type in that category or allows all the non-unknown inputs to be implicitly coerced to it. Coerce all inputs to the selected type. Examples Underspecified Types in a Union tgl=> SELECT text 'a' AS "Text" UNION SELECT 'b'; Text ------ a b (2 rows) Here, the unknown-type literal 'b' will be resolved as type text. Type Conversion in a Simple Union tgl=> SELECT 1.2 AS "Numeric" UNION SELECT 1; Numeric --------- 1 1.2 (2 rows) The literal 1.2 is of type numeric, and the integer value 1 can be cast implicitly to numeric, so that type is used. Type Conversion in a Transposed Union tgl=> SELECT 1 AS "Real" tgl-> UNION SELECT CAST('2.2' AS REAL); Real ------ 1 2.2 (2 rows) Here, since type real cannot be implicitly cast to integer, but integer can be implicitly cast to real, the union result type is resolved as real.