Type Conversion SQL queries can, intentionally or not, require mixing of different data types in the same expression. Postgres 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 Postgres 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 Postgres 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. 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. Postgres has an extensible type system that is much more general and flexible than other RDBMS implementations. Hence, most type conversion behavior in Postgres 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 Postgres 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 SQL language definition allows specifying type names with strings, and this mechanism can be used in Postgres 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 strings, of type text and point. If a type is not specified for a string, 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 Postgres parser: Operators Postgres allows expressions with left- and right-unary (one argument) operators, as well as binary (two argument) operators. Function calls Much of the Postgres 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 Postgres 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 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. Many of the general type conversion rules use simple conventions built on the Postgres function and operator system tables. There are some heuristics included in the conversion rules to better support conventions for the SQL92 standard native types such as smallint, integer, and float. The Postgres 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. Guidelines 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, Postgres 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 Operator Type Resolution Check for an exact match in the pg_operator system catalog. 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. Make a list of all operators of the same name for which the input types match or can be coerced to match. (unknown literals are assumed to be coercible to anything for this purpose.) If there is only one, 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 "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. If only one candidate remains, use it. If no candidate or more than one candidate remains, then fail. Examples Exponentiation Operator There is only one exponentiation operator defined in the catalog, and it takes float8 arguments. The scanner assigns an initial type of int4 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 float8(2) ^ float8(3) 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 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. 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 bitstring-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. Factorial This example illustrates an interesting result. Traditionally, the factorial operator is defined for integers only. The Postgres operator catalog has only one entry for factorial, taking an integer operand. If given a non-integer numeric argument, Postgres will try to convert that argument to an integer for evaluation of the factorial. tgl=> select (4.3 !); ?column? ---------- 24 (1 row) 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, Postgres will try to oblige. Functions Function Call Type Resolution Check for an exact match in the pg_proc system catalog. (Cases involving unknown will never find a match at this step.) Look for the best match. 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. (unknown literals are assumed to be coercible to anything for this purpose.) If there is only one, 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 "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. If only one candidate remains, use it. If no candidate or more than one candidate remains, then fail. 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. Examples Factorial Function There is only one factorial 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 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) 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 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. Examples <type>varchar</type> Storage For a target column declared as varchar(4) the following query ensures that the target is sized correctly: 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) What's 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 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 varchar(varchar,int4) 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. UNION and CASE Constructs 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. UNION and 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. If one or more non-unknown inputs are of a preferred type in that category, resolve as that type. Otherwise, resolve as the type of the first non-unknown input. Coerce all inputs to the selected type. Examples Underspecified Types 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. Simple UNION tgl=> SELECT 1.2 AS "Float8" UNION SELECT 1; Float8 -------- 1 1.2 (2 rows) Transposed UNION Here the output type of the union is forced to match the type of the first/top clause in the union: tgl=> SELECT 1 AS "All integers" tgl-> UNION SELECT '2.2'::float4; All integers -------------- 1 2 (2 rows) Since float4 is not a preferred type, the parser sees no reason to select it over int4, 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 Postgres may support a more general notion of type preferences.