1CREATE CAST(7) PostgreSQL 11.3 Documentation CREATE CAST(7)
2
3
4
6 CREATE_CAST - define a new cast
7
9 CREATE CAST (source_type AS target_type)
10 WITH FUNCTION function_name [ (argument_type [, ...]) ]
11 [ AS ASSIGNMENT | AS IMPLICIT ]
12
13 CREATE CAST (source_type AS target_type)
14 WITHOUT FUNCTION
15 [ AS ASSIGNMENT | AS IMPLICIT ]
16
17 CREATE CAST (source_type AS target_type)
18 WITH INOUT
19 [ AS ASSIGNMENT | AS IMPLICIT ]
20
22 CREATE CAST defines a new cast. A cast specifies how to perform a
23 conversion between two data types. For example,
24
25 SELECT CAST(42 AS float8);
26
27 converts the integer constant 42 to type float8 by invoking a
28 previously specified function, in this case float8(int4). (If no
29 suitable cast has been defined, the conversion fails.)
30
31 Two types can be binary coercible, which means that the conversion can
32 be performed “for free” without invoking any function. This requires
33 that corresponding values use the same internal representation. For
34 instance, the types text and varchar are binary coercible both ways.
35 Binary coercibility is not necessarily a symmetric relationship. For
36 example, the cast from xml to text can be performed for free in the
37 present implementation, but the reverse direction requires a function
38 that performs at least a syntax check. (Two types that are binary
39 coercible both ways are also referred to as binary compatible.)
40
41 You can define a cast as an I/O conversion cast by using the WITH INOUT
42 syntax. An I/O conversion cast is performed by invoking the output
43 function of the source data type, and passing the resulting string to
44 the input function of the target data type. In many common cases, this
45 feature avoids the need to write a separate cast function for
46 conversion. An I/O conversion cast acts the same as a regular
47 function-based cast; only the implementation is different.
48
49 By default, a cast can be invoked only by an explicit cast request,
50 that is an explicit CAST(x AS typename) or x::typename construct.
51
52 If the cast is marked AS ASSIGNMENT then it can be invoked implicitly
53 when assigning a value to a column of the target data type. For
54 example, supposing that foo.f1 is a column of type text, then:
55
56 INSERT INTO foo (f1) VALUES (42);
57
58 will be allowed if the cast from type integer to type text is marked AS
59 ASSIGNMENT, otherwise not. (We generally use the term assignment cast
60 to describe this kind of cast.)
61
62 If the cast is marked AS IMPLICIT then it can be invoked implicitly in
63 any context, whether assignment or internally in an expression. (We
64 generally use the term implicit cast to describe this kind of cast.)
65 For example, consider this query:
66
67 SELECT 2 + 4.0;
68
69 The parser initially marks the constants as being of type integer and
70 numeric respectively. There is no integer + numeric operator in the
71 system catalogs, but there is a numeric + numeric operator. The query
72 will therefore succeed if a cast from integer to numeric is available
73 and is marked AS IMPLICIT — which in fact it is. The parser will apply
74 the implicit cast and resolve the query as if it had been written
75
76 SELECT CAST ( 2 AS numeric ) + 4.0;
77
78 Now, the catalogs also provide a cast from numeric to integer. If that
79 cast were marked AS IMPLICIT — which it is not — then the parser would
80 be faced with choosing between the above interpretation and the
81 alternative of casting the numeric constant to integer and applying the
82 integer + integer operator. Lacking any knowledge of which choice to
83 prefer, it would give up and declare the query ambiguous. The fact that
84 only one of the two casts is implicit is the way in which we teach the
85 parser to prefer resolution of a mixed numeric-and-integer expression
86 as numeric; there is no built-in knowledge about that.
87
88 It is wise to be conservative about marking casts as implicit. An
89 overabundance of implicit casting paths can cause PostgreSQL to choose
90 surprising interpretations of commands, or to be unable to resolve
91 commands at all because there are multiple possible interpretations. A
92 good rule of thumb is to make a cast implicitly invokable only for
93 information-preserving transformations between types in the same
94 general type category. For example, the cast from int2 to int4 can
95 reasonably be implicit, but the cast from float8 to int4 should
96 probably be assignment-only. Cross-type-category casts, such as text to
97 int4, are best made explicit-only.
98
99 Note
100 Sometimes it is necessary for usability or standards-compliance
101 reasons to provide multiple implicit casts among a set of types,
102 resulting in ambiguity that cannot be avoided as above. The parser
103 has a fallback heuristic based on type categories and preferred
104 types that can help to provide desired behavior in such cases. See
105 CREATE TYPE (CREATE_TYPE(7)) for more information.
106
107 To be able to create a cast, you must own the source or the target data
108 type and have USAGE privilege on the other type. To create a
109 binary-coercible cast, you must be superuser. (This restriction is made
110 because an erroneous binary-coercible cast conversion can easily crash
111 the server.)
112
114 source_type
115 The name of the source data type of the cast.
116
117 target_type
118 The name of the target data type of the cast.
119
120 function_name[(argument_type [, ...])]
121 The function used to perform the cast. The function name can be
122 schema-qualified. If it is not, the function will be looked up in
123 the schema search path. The function's result data type must match
124 the target type of the cast. Its arguments are discussed below. If
125 no argument list is specified, the function name must be unique in
126 its schema.
127
128 WITHOUT FUNCTION
129 Indicates that the source type is binary-coercible to the target
130 type, so no function is required to perform the cast.
131
132 WITH INOUT
133 Indicates that the cast is an I/O conversion cast, performed by
134 invoking the output function of the source data type, and passing
135 the resulting string to the input function of the target data type.
136
137 AS ASSIGNMENT
138 Indicates that the cast can be invoked implicitly in assignment
139 contexts.
140
141 AS IMPLICIT
142 Indicates that the cast can be invoked implicitly in any context.
143
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.)
154
155 The return type of a cast function must be identical to or
156 binary-coercible to the cast's target type.
157
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
164 argument.
165
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.
172
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.
175
177 Use DROP CAST (DROP_CAST(7)) to remove user-defined casts.
178
179 Remember that if you want to be able to convert types both ways you
180 need to declare casts both ways explicitly.
181
182 It is normally not necessary to create casts between user-defined types
183 and the standard string types (text, varchar, and char(n), as well as
184 user-defined types that are defined to be in the string category).
185 PostgreSQL provides automatic I/O conversion casts for that. The
186 automatic casts to string types are treated as assignment casts, while
187 the automatic casts from string types are explicit-only. You can
188 override this behavior by declaring your own cast to replace an
189 automatic cast, but usually the only reason to do so is if you want the
190 conversion to be more easily invokable than the standard
191 assignment-only or explicit-only setting. Another possible reason is
192 that you want the conversion to behave differently from the type's I/O
193 function; but that is sufficiently surprising that you should think
194 twice about whether it's a good idea. (A small number of the built-in
195 types do indeed have different behaviors for conversions, mostly
196 because of requirements of the SQL standard.)
197
198 While not required, it is recommended that you continue to follow this
199 old convention of naming cast implementation functions after the target
200 data type. Many users are used to being able to cast data types using a
201 function-style notation, that is typename(x). This notation is in fact
202 nothing more nor less than a call of the cast implementation function;
203 it is not specially treated as a cast. If your conversion functions are
204 not named to support this convention then you will have surprised
205 users. Since PostgreSQL allows overloading of the same function name
206 with different argument types, there is no difficulty in having
207 multiple conversion functions from different types that all use the
208 target type's name.
209
210 Note
211 Actually the preceding paragraph is an oversimplification: there
212 are two cases in which a function-call construct will be treated as
213 a cast request without having matched it to an actual function. If
214 a function call name(x) does not exactly match any existing
215 function, but name is the name of a data type and pg_cast provides
216 a binary-coercible cast to this type from the type of x, then the
217 call will be construed as a binary-coercible cast. This exception
218 is made so that binary-coercible casts can be invoked using
219 functional syntax, even though they lack any function. Likewise, if
220 there is no pg_cast entry but the cast would be to or from a string
221 type, the call will be construed as an I/O conversion cast. This
222 exception allows I/O conversion casts to be invoked using
223 functional syntax.
224
225 Note
226 There is also an exception to the exception: I/O conversion casts
227 from composite types to string types cannot be invoked using
228 functional syntax, but must be written in explicit cast syntax
229 (either CAST or :: notation). This exception was added because
230 after the introduction of automatically-provided I/O conversion
231 casts, it was found too easy to accidentally invoke such a cast
232 when a function or column reference was intended.
233
235 To create an assignment cast from type bigint to type int4 using the
236 function int4(bigint):
237
238 CREATE CAST (bigint AS int4) WITH FUNCTION int4(bigint) AS ASSIGNMENT;
239
240 (This cast is already predefined in the system.)
241
243 The CREATE CAST command conforms to the SQL standard, except that SQL
244 does not make provisions for binary-coercible types or extra arguments
245 to implementation functions. AS IMPLICIT is a PostgreSQL extension,
246 too.
247
249 CREATE FUNCTION (CREATE_FUNCTION(7)), CREATE TYPE (CREATE_TYPE(7)),
250 DROP CAST (DROP_CAST(7))
251
252
253
254PostgreSQL 11.3 2019 CREATE CAST(7)