4 CREATE CAST — define a new cast
8 CREATE CAST (source_type AS target_type)
9 WITH FUNCTION function_name [ (argument_type [, ...]) ]
10 [ AS ASSIGNMENT | AS IMPLICIT ]
12 CREATE CAST (source_type AS target_type)
14 [ AS ASSIGNMENT | AS IMPLICIT ]
16 CREATE CAST (source_type AS target_type)
18 [ AS ASSIGNMENT | AS IMPLICIT ]
22 CREATE CAST defines a new cast. A cast specifies how to perform a
23 conversion between two data types. For example,
24 SELECT CAST(42 AS float8);
26 converts the integer constant 42 to type float8 by invoking a
27 previously specified function, in this case float8(int4). (If no
28 suitable cast has been defined, the conversion fails.)
30 Two types can be binary coercible, which means that the conversion can
31 be performed “for free” without invoking any function. This requires
32 that corresponding values use the same internal representation. For
33 instance, the types text and varchar are binary coercible both ways.
34 Binary coercibility is not necessarily a symmetric relationship. For
35 example, the cast from xml to text can be performed for free in the
36 present implementation, but the reverse direction requires a function
37 that performs at least a syntax check. (Two types that are binary
38 coercible both ways are also referred to as binary compatible.)
40 You can define a cast as an I/O conversion cast by using the WITH INOUT
41 syntax. An I/O conversion cast is performed by invoking the output
42 function of the source data type, and passing the resulting string to
43 the input function of the target data type. In many common cases, this
44 feature avoids the need to write a separate cast function for
45 conversion. An I/O conversion cast acts the same as a regular
46 function-based cast; only the implementation is different.
48 By default, a cast can be invoked only by an explicit cast request,
49 that is an explicit CAST(x AS typename) or x::typename construct.
51 If the cast is marked AS ASSIGNMENT then it can be invoked implicitly
52 when assigning a value to a column of the target data type. For
53 example, supposing that foo.f1 is a column of type text, then:
54 INSERT INTO foo (f1) VALUES (42);
56 will be allowed if the cast from type integer to type text is marked AS
57 ASSIGNMENT, otherwise not. (We generally use the term assignment cast
58 to describe this kind of cast.)
60 If the cast is marked AS IMPLICIT then it can be invoked implicitly in
61 any context, whether assignment or internally in an expression. (We
62 generally use the term implicit cast to describe this kind of cast.)
63 For example, consider this query:
66 The parser initially marks the constants as being of type integer and
67 numeric respectively. There is no integer + numeric operator in the
68 system catalogs, but there is a numeric + numeric operator. The query
69 will therefore succeed if a cast from integer to numeric is available
70 and is marked AS IMPLICIT — which in fact it is. The parser will apply
71 the implicit cast and resolve the query as if it had been written
72 SELECT CAST ( 2 AS numeric ) + 4.0;
74 Now, the catalogs also provide a cast from numeric to integer. If that
75 cast were marked AS IMPLICIT — which it is not — then the parser would
76 be faced with choosing between the above interpretation and the
77 alternative of casting the numeric constant to integer and applying the
78 integer + integer operator. Lacking any knowledge of which choice to
79 prefer, it would give up and declare the query ambiguous. The fact that
80 only one of the two casts is implicit is the way in which we teach the
81 parser to prefer resolution of a mixed numeric-and-integer expression
82 as numeric; there is no built-in knowledge about that.
84 It is wise to be conservative about marking casts as implicit. An
85 overabundance of implicit casting paths can cause PostgreSQL to choose
86 surprising interpretations of commands, or to be unable to resolve
87 commands at all because there are multiple possible interpretations. A
88 good rule of thumb is to make a cast implicitly invokable only for
89 information-preserving transformations between types in the same
90 general type category. For example, the cast from int2 to int4 can
91 reasonably be implicit, but the cast from float8 to int4 should
92 probably be assignment-only. Cross-type-category casts, such as text to
93 int4, are best made explicit-only.
97 Sometimes it is necessary for usability or standards-compliance reasons
98 to provide multiple implicit casts among a set of types, resulting in
99 ambiguity that cannot be avoided as above. The parser has a fallback
100 heuristic based on type categories and preferred types that can help to
101 provide desired behavior in such cases. See CREATE TYPE for more
104 To be able to create a cast, you must own the source or the target data
105 type and have USAGE privilege on the other type. To create a
106 binary-coercible cast, you must be superuser. (This restriction is made
107 because an erroneous binary-coercible cast conversion can easily crash
113 The name of the source data type of the cast.
116 The name of the target data type of the cast.
118 function_name[(argument_type [, ...])]
119 The function used to perform the cast. The function name can be
120 schema-qualified. If it is not, the function will be looked up
121 in the schema search path. The function's result data type must
122 match the target type of the cast. Its arguments are discussed
123 below. If no argument list is specified, the function name must
124 be unique in its schema.
127 Indicates that the source type is binary-coercible to the target
128 type, so no function is required to perform the cast.
131 Indicates that the cast is an I/O conversion cast, performed by
132 invoking the output function of the source data type, and
133 passing the resulting string to the input function of the target
137 Indicates that the cast can be invoked implicitly in assignment
141 Indicates that the cast can be invoked implicitly in any
144 Cast implementation functions can have one to three arguments. The
145 first argument type must be identical to or binary-coercible from the
146 cast's source type. The second argument, if present, must be type
147 integer; it receives the type modifier associated with the destination
148 type, or -1 if there is none. The third argument, if present, must be
149 type boolean; it receives true if the cast is an explicit cast, false
150 otherwise. (Bizarrely, the SQL standard demands different behaviors for
151 explicit and implicit casts in some cases. This argument is supplied
152 for functions that must implement such casts. It is not recommended
153 that you design your own data types so that this matters.)
155 The return type of a cast function must be identical to or
156 binary-coercible to the cast's target type.
158 Ordinarily a cast must have different source and target data types.
159 However, it is allowed to declare a cast with identical source and
160 target types if it has a cast implementation function with more than
161 one argument. This is used to represent type-specific length coercion
162 functions in the system catalogs. The named function is used to coerce
163 a value of the type to the type modifier value given by its second
166 When a cast has different source and target types and a function that
167 takes more than one argument, it supports converting from one type to
168 another and applying a length coercion in a single step. When no such
169 entry is available, coercion to a type that uses a type modifier
170 involves two cast steps, one to convert between data types and a second
171 to apply the modifier.
173 A cast to or from a domain type currently has no effect. Casting to or
174 from a domain uses the casts associated with its underlying type.
178 Use DROP CAST to remove user-defined casts.
180 Remember that if you want to be able to convert types both ways you
181 need to declare casts both ways explicitly.
183 It is normally not necessary to create casts between user-defined types
184 and the standard string types (text, varchar, and char(n), as well as
185 user-defined types that are defined to be in the string category).
186 PostgreSQL provides automatic I/O conversion casts for that. The
187 automatic casts to string types are treated as assignment casts, while
188 the automatic casts from string types are explicit-only. You can
189 override this behavior by declaring your own cast to replace an
190 automatic cast, but usually the only reason to do so is if you want the
191 conversion to be more easily invokable than the standard
192 assignment-only or explicit-only setting. Another possible reason is
193 that you want the conversion to behave differently from the type's I/O
194 function; but that is sufficiently surprising that you should think
195 twice about whether it's a good idea. (A small number of the built-in
196 types do indeed have different behaviors for conversions, mostly
197 because of requirements of the SQL standard.)
199 While not required, it is recommended that you continue to follow this
200 old convention of naming cast implementation functions after the target
201 data type. Many users are used to being able to cast data types using a
202 function-style notation, that is typename(x). This notation is in fact
203 nothing more nor less than a call of the cast implementation function;
204 it is not specially treated as a cast. If your conversion functions are
205 not named to support this convention then you will have surprised
206 users. Since PostgreSQL allows overloading of the same function name
207 with different argument types, there is no difficulty in having
208 multiple conversion functions from different types that all use the
213 Actually the preceding paragraph is an oversimplification: there are
214 two cases in which a function-call construct will be treated as a cast
215 request without having matched it to an actual function. If a function
216 call name(x) does not exactly match any existing function, but name is
217 the name of a data type and pg_cast provides a binary-coercible cast to
218 this type from the type of x, then the call will be construed as a
219 binary-coercible cast. This exception is made so that binary-coercible
220 casts can be invoked using functional syntax, even though they lack any
221 function. Likewise, if there is no pg_cast entry but the cast would be
222 to or from a string type, the call will be construed as an I/O
223 conversion cast. This exception allows I/O conversion casts to be
224 invoked using functional syntax.
228 There is also an exception to the exception: I/O conversion casts from
229 composite types to string types cannot be invoked using functional
230 syntax, but must be written in explicit cast syntax (either CAST or ::
231 notation). This exception was added because after the introduction of
232 automatically-provided I/O conversion casts, it was found too easy to
233 accidentally invoke such a cast when a function or column reference was
238 To create an assignment cast from type bigint to type int4 using the
239 function int4(bigint):
240 CREATE CAST (bigint AS int4) WITH FUNCTION int4(bigint) AS ASSIGNMENT;
242 (This cast is already predefined in the system.)
246 The CREATE CAST command conforms to the SQL standard, except that SQL
247 does not make provisions for binary-coercible types or extra arguments
248 to implementation functions. AS IMPLICIT is a PostgreSQL extension,
253 CREATE FUNCTION, CREATE TYPE, DROP CAST