Defines a new cast.
CREATE CAST (<sourcetype> AS <targettype>)
WITH FUNCTION <funcname> (<argtype> [, ...])
[AS ASSIGNMENT | AS IMPLICIT]
CREATE CAST (<sourcetype> AS <targettype>)
WITHOUT FUNCTION
[AS ASSIGNMENT | AS IMPLICIT]
CREATE CAST (<sourcetype> AS <targettype>)
WITH INOUT
[AS ASSIGNMENT | AS IMPLICIT]
CREATE CAST
defines a new cast. A cast specifies how to perform a conversion between two data types. For example,
SELECT CAST(42 AS float8);
converts the integer constant 42
to type float8
by invoking a previously specified function, in this case float8(int4)
. If no suitable cast has been defined, the conversion fails.
Two types may be binary coercible, which means that the types can be converted into one another without invoking any function. This requires that corresponding values use the same internal representation. For instance, the types text
and varchar
are binary coercible in both directions. Binary coercibility is not necessarily a symmetric relationship. For example, the cast from xml
to text
can be performed for free in the present implementation, but the reverse direction requires a function that performs at least a syntax check. (Two types that are binary coercible both ways are also referred to as binary compatible.)
You can define a cast as an I/O conversion cast by using the WITH INOUT
syntax. An I/O conversion cast is performed by invoking the output function of the source data type, and passing the resulting string to the input function of the target data type. In many common cases, this feature avoids the need to write a separate cast function for conversion. An I/O conversion cast acts the same as a regular function-based cast; only the implementation is different.
By default, a cast can be invoked only by an explicit cast request, that is an explicit CAST(x AS
typename)
or x:: typename
construct.
If the cast is marked AS ASSIGNMENT
then it can be invoked implicitly when assigning a value to a column of the target data type. For example, supposing that foo.f1
is a column of type text
, then:
INSERT INTO foo (f1) VALUES (42);
will be allowed if the cast from type integer
to type text
is marked AS ASSIGNMENT
, otherwise not. The term assignment cast is typically used to describe this kind of cast.
If the cast is marked AS IMPLICIT
then it can be invoked implicitly in any context, whether assignment or internally in an expression. The term implicit cast is typically used to describe this kind of cast. For example, consider this query:
SELECT 2 + 4.0;
The parser initially marks the constants as being of type integer
and numeric
, respectively. There is no integer + numeric
operator in the system catalogs, but there is a numeric + numeric
operator. This query succeeds if a cast from integer
to numeric
exists (it does) and is marked AS IMPLICIT
, which in fact it is. The parser applies only the implicit cast and resolves the query as if it had been written as the following:
SELECT CAST ( 2 AS numeric ) + 4.0;
The catalogs also provide a cast from numeric
to integer
. If that cast were marked AS IMPLICIT
, which it is not, then the parser would be faced with choosing between the above interpretation and the alternative of casting the numeric
constant to integer
and applying the integer + integer
operator. Lacking any knowledge of which choice to prefer, the parser would give up and declare the query ambiguous. The fact that only one of the two casts is implicit is the way in which we teach the parser to prefer resolution of a mixed numeric
-and-integer
expression as numeric
; the parser has no built-in knowledge about that.
It is wise to be conservative about marking casts as implicit. An overabundance of implicit casting paths can cause Greenplum Database to choose surprising interpretations of commands, or to be unable to resolve commands at all because there are multiple possible interpretations. A good general rule is to make a cast implicitly invokable only for information-preserving transformations between types in the same general type category. For example, the cast from int2
to int4
can reasonably be implicit, but the cast from float8
to int4
should probably be assignment-only. Cross-type-category casts, such as text
to int4
, are best made explicit-only.
NoteSometimes it is necessary for usability or standards-compliance reasons to provide multiple implicit casts among a set of types, resulting in ambiguity that cannot be avoided as described above. The parser uses a fallback heuristic based on type categories and preferred types that helps to provide desired behavior in such cases. See CREATE TYPE for more information.
To be able to create a cast, you must own the source or the target data type and have USAGE
privilege on the other type. To create a binary-coercible cast, you must be superuser. (This restriction is made because an erroneous binary-coercible cast conversion can easily crash the server.)
The function used to perform the cast. The function name may be schema-qualified. If it is not, Greenplum Database looks for the function in the schema search path. The function's result data type must match the target type of the cast.
Cast implementation functions may have one to three arguments. The first argument type must be identical to or binary-coercible from the cast's source type. The second argument, if present, must be type integer
; it receives the type modifier associated with the destination type, or -1
if there is none. The third argument, if present, must be type boolean
; it receives true
if the cast is an explicit cast, false
otherwise. The SQL specification demands different behaviors for explicit and implicit casts in some cases. This argument is supplied for functions that must implement such casts. It is not recommended that you design your own data types this way.
The return type of a cast function must be identical to or binary-coercible to the cast's target type.
Ordinarily a cast must have different source and target data types. However, you are permitted to declare a cast with identical source and target types if it has a cast implementation function that takes more than one argument. This is used to represent type-specific length coercion functions in the system catalogs. The named function is used to coerce a value of the type to the type modifier value given by its second argument.
When a cast has different source and target types and a function that takes more than one argument, the cast converts from one type to another and applies a length coercion in a single step. When no such entry is available, coercion to a type that uses a type modifier involves two steps, one to convert between data types and a second to apply the modifier.
Note that in this release of Greenplum Database, user-defined functions used in a user-defined cast must be defined as IMMUTABLE
. Any compiled code (shared library files) for custom functions must be placed in the same location on every host in your Greenplum Database array (coordinator and all segments). This location must also be in the LD_LIBRARY_PATH
so that the server can locate the files.
Remember that if you want to be able to convert types both ways you need to declare casts both ways explicitly.
It is normally not necessary to create casts between user-defined types and the standard string types (text
, varchar
, and char(*n*)
, as well as user-defined types that are defined to be in the string category). Greenplum Database provides automatic I/O conversion casts for these. The automatic casts to string types are treated as assignment casts, while the automatic casts from string types are explicit-only. You can override this behavior by declaring your own cast to replace an automatic cast, but usually the only reason to do so is if you want the conversion to be more easily invokable than the standard assignment-only or explicit-only setting. Another possible reason is that you want the conversion to behave differently from the type's I/O function - think twice before doing this. (A small number of the built-in types do indeed have different behaviors for conversions, mostly because of requirements of the SQL standard.)
It is recommended that you follow the convention of naming cast implementation functions after the target data type, as the built-in cast implementation functions are named. Many users are used to being able to cast data types using a function-style notation, that is typename(x)
.
There are two cases in which a function-call construct is treated as a cast request without having matched it to an actual function. If a function call *name\(x\)*
does not exactly match any existing function, but *name*
is the name of a data type and pg_cast
provides a binary-coercible cast to this type from the type of *x*
, then the call will be construed as a binary-coercible cast. Greenplum Database makes this exception so that binary-coercible casts can be invoked using functional syntax, even though they lack any function. Likewise, if there is no pg_cast
entry but the cast would be to or from a string type, the call is construed as an I/O conversion cast. This exception allows I/O conversion casts to be invoked using functional syntax.
There is an exception to the exception above: I/O conversion casts from composite types to string types cannot be invoked using functional syntax, but must be written in explicit cast syntax (either CAST
or :: notation). This exception exists because after the introduction of automatically-provided I/O conversion casts, it was found to be too easy to accidentally invoke such a cast when you intended a function or column reference.
To create an assignment cast from type bigint
to type int4
using the function int4(bigint)
(This cast is already predefined in the system.):
CREATE CAST (bigint AS int4) WITH FUNCTION int4(bigint) AS ASSIGNMENT;
The CREATE CAST
command conforms to the SQL standard, except that SQL does not make provisions for binary-coercible types or extra arguments to implementation functions. AS IMPLICIT
is a Greenplum Database extension, too.
CREATE FUNCTION, CREATE TYPE, DROP CAST
Parent topic: SQL Commands