1CREATE CAST(7) SQL Commands CREATE CAST(7)
2
3
4
6 CREATE CAST - define a new cast
7
8
10 CREATE CAST (sourcetype AS targettype)
11 WITH FUNCTION funcname (argtypes)
12 [ AS ASSIGNMENT | AS IMPLICIT ]
13
14 CREATE CAST (sourcetype AS targettype)
15 WITHOUT FUNCTION
16 [ AS ASSIGNMENT | AS IMPLICIT ]
17
18 CREATE CAST (sourcetype AS targettype)
19 WITH INOUT
20 [ AS ASSIGNMENT | AS IMPLICIT ]
21
22
24 CREATE CAST defines a new cast. A cast specifies how to perform a con‐
25 version between two data types. For example:
26
27 SELECT CAST(42 AS float8);
28
29 converts the integer constant 42 to type float8 by invoking a previ‐
30 ously specified function, in this case float8(int4). (If no suitable
31 cast has been defined, the conversion fails.)
32
33 Two types can be binary coercible, which means that the conversion can
34 be performed ``for free'' without invoking any function. This requires
35 that corresponding values use the same internal representation. For
36 instance, the types text and varchar are binary coercible both ways.
37 Binary coercibility is not necessarily a symmetric relationship. For
38 example, the cast from xml to text can be performed for free in the
39 present implementation, but the reverse direction requires a function
40 that performs at least a syntax check. (Two types that are binary
41 coercible both ways are also referred to as binary compatible.)
42
43 You can define a cast as an I/O conversion cast using the WITH INOUT
44 syntax. An I/O conversion cast is performed by invoking the output
45 function of the source data type, and passing the result to the input
46 function of the target data type.
47
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.
50
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 exam‐
53 ple, supposing that foo.f1 is a column of type text, then:
54
55 INSERT INTO foo (f1) VALUES (42);
56
57 will be allowed if the cast from type integer to type text is marked AS
58 ASSIGNMENT, otherwise not. (We generally use the term assignment cast
59 to describe this kind of cast.)
60
61 If the cast is marked AS IMPLICIT then it can be invoked implicitly in
62 any context, whether assignment or internally in an expression. (We
63 generally use the term implicit cast to describe this kind of cast.)
64 For example, consider this query:
65
66 SELECT 2 + 4.0;
67
68 The parser initially marks the constants as being of type integer and
69 numeric respectively. There is no integer + numeric operator in the
70 system catalogs, but there is a numeric + numeric operator. The query
71 will therefore succeed if a cast from integer to numeric is available
72 and is marked AS IMPLICIT — which in fact it is. The parser will apply
73 the implicit cast and resolve the query as if it had been written
74
75 SELECT CAST ( 2 AS numeric ) + 4.0;
76
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 alter‐
81 native 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 over‐
89 abundance of implicit casting paths can cause PostgreSQL to choose sur‐
90 prising interpretations of commands, or to be unable to resolve com‐
91 mands 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 gen‐
94 eral type category. For example, the cast from int2 to int4 can reason‐
95 ably be implicit, but the cast from float8 to int4 should probably be
96 assignment-only. Cross-type-category casts, such as text to int4, are
97 best made explicit-only.
98
99 Note: Sometimes it is necessary for usability or standards-com‐
100 pliance reasons to provide multiple implicit casts among a set
101 of types, resulting in ambiguity that cannot be avoided as
102 above. The parser has a fallback heuristic based on type cate‐
103 gories and preferred types that can help to provide desired
104 behavior in such cases. See CREATE TYPE [create_type(7)] for
105 more information.
106
107
108 To be able to create a cast, you must own the source or the target data
109 type. To create a binary-coercible cast, you must be superuser. (This
110 restriction is made because an erroneous binary-coercible cast conver‐
111 sion can easily crash the server.)
112
114 sourcetype
115 The name of the source data type of the cast.
116
117 targettype
118 The name of the target data type of the cast.
119
120 funcname(argtypes)
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
123 in the schema search path. The function's result data type must
124 match the target type of the cast. Its arguments are discussed
125 below.
126
127 WITHOUT FUNCTION
128 Indicates that the source type is binary-coercible to the target
129 type, so no function is required to perform the cast.
130
131 WITH INOUT
132 Indicates that the cast is an I/O conversion cast, performed by
133 invoking the output function of the source data type, and pass‐
134 ing the result to the input function of the target data type.
135
136 AS ASSIGNMENT
137 Indicates that the cast can be invoked implicitly in assignment
138 contexts.
139
140 AS IMPLICIT
141 Indicates that the cast can be invoked implicitly in any con‐
142 text.
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 inte‐
147 ger; 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
151 for explicit and implicit casts in some cases. This argument is sup‐
152 plied for functions that must implement such casts. It is not recom‐
153 mended 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 binary-
156 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 tar‐
160 get types if it has a cast implementation function with more than one
161 argument. This is used to represent type-specific length coercion func‐
162 tions in the system catalogs. The named function is used to coerce a
163 value of the type to the type modifier value given by its second argu‐
164 ment.
165
166 When a cast has different source and target types and a function that
167 takes more than one argument, it represents 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 steps, one to convert between data types and a second to
171 apply the modifier.
172
174 Use DROP CAST [drop_cast(7)] to remove user-defined casts.
175
176 Remember that if you want to be able to convert types both ways you
177 need to declare casts both ways explicitly.
178
179
180 It is normally not necessary to create casts between user-defined types
181 and the standard string types (text, varchar, and char(n), as well as
182 user-defined types that are defined to be in the string category).
183 PostgreSQL provides automatic I/O conversion casts for that. The auto‐
184 matic casts to string types are treated as assignment casts, while the
185 automatic casts from string types are explicit-only. You can override
186 this behavior by declaring your own cast to replace an automatic cast,
187 but usually the only reason to do so is if you want the conversion to
188 be more easily invokable than the standard assignment-only or explicit-
189 only setting. Another possible reason is that you want the conversion
190 to behave differently from the type's I/O function; but that is suffi‐
191 ciently surprising that you should think twice about whether it's a
192 good idea. (A small number of the built-in types do indeed have differ‐
193 ent behaviors for conversions, mostly because of requirements of the
194 SQL standard.)
195
196 Prior to PostgreSQL 7.3, every function that had the same name as a
197 data type, returned that data type, and took one argument of a differ‐
198 ent type was automatically a cast function. This convention has been
199 abandoned in face of the introduction of schemas and to be able to rep‐
200 resent binary-coercible casts in the system catalogs. The built-in cast
201 functions still follow this naming scheme, but they have to be shown as
202 casts in the system catalog pg_cast as well.
203
204 While not required, it is recommended that you continue to follow this
205 old convention of naming cast implementation functions after the target
206 data type. Many users are used to being able to cast data types using a
207 function-style notation, that is typename(x). This notation is in fact
208 nothing more nor less than a call of the cast implementation function;
209 it is not specially treated as a cast. If your conversion functions are
210 not named to support this convention then you will have surprised
211 users. Since PostgreSQL allows overloading of the same function name
212 with different argument types, there is no difficulty in having multi‐
213 ple conversion functions from different types that all use the target
214 type's name.
215
216 Note: Actually the preceding paragraph is an oversimplification:
217 there are two cases in which a function-call construct will be
218 treated as a cast request without having matched it to an actual
219 function. If a function call name(x) does not exactly match any
220 existing function, but name is the name of a data type and
221 pg_cast provides a binary-coercible cast to this type from the
222 type of x, then the call will be construed as a binary-coercible
223 cast. This exception is made so that binary-coercible casts can
224 be invoked using functional syntax, even though they lack any
225 function. Likewise, if there is no pg_cast entry but the cast
226 would be to or from a string type, the call will be construed as
227 an I/O conversion cast. This exception allows I/O conversion
228 casts to be invoked using functional syntax.
229
230
232 To create an assignment cast from type bigint to type int4 using the
233 function int4(bigint):
234
235 CREATE CAST (bigint AS int4) WITH FUNCTION int4(bigint) AS ASSIGNMENT;
236
237 (This cast is already predefined in the system.)
238
240 The CREATE CAST command conforms to the SQL standard, except that SQL
241 does not make provisions for binary-coercible types or extra arguments
242 to implementation functions. AS IMPLICIT is a PostgreSQL extension,
243 too.
244
246 CREATE FUNCTION [create_function(7)], CREATE TYPE [create_type(7)],
247 DROP CAST [drop_cast(7)]
248
249
250
251SQL - Language Statements 2014-02-17 CREATE CAST(7)