1CREATE CAST(7)          PostgreSQL 9.2.24 Documentation         CREATE CAST(7)
2
3
4

NAME

6       CREATE_CAST - define a new cast
7

SYNOPSIS

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

DESCRIPTION

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

PARAMETERS

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.
125
126       WITHOUT FUNCTION
127           Indicates that the source type is binary-coercible to the target
128           type, so no function is required to perform the cast.
129
130       WITH INOUT
131           Indicates that the cast is an I/O conversion cast, performed by
132           invoking the output function of the source data type, and passing
133           the resulting string to the input function of the target data type.
134
135       AS ASSIGNMENT
136           Indicates that the cast can be invoked implicitly in assignment
137           contexts.
138
139       AS IMPLICIT
140           Indicates that the cast can be invoked implicitly in any context.
141
142       Cast implementation functions can have one to three arguments. The
143       first argument type must be identical to or binary-coercible from the
144       cast's source type. The second argument, if present, must be type
145       integer; it receives the type modifier associated with the destination
146       type, or -1 if there is none. The third argument, if present, must be
147       type boolean; it receives true if the cast is an explicit cast, false
148       otherwise. (Bizarrely, the SQL standard demands different behaviors for
149       explicit and implicit casts in some cases. This argument is supplied
150       for functions that must implement such casts. It is not recommended
151       that you design your own data types so that this matters.)
152
153       The return type of a cast function must be identical to or
154       binary-coercible to the cast's target type.
155
156       Ordinarily a cast must have different source and target data types.
157       However, it is allowed to declare a cast with identical source and
158       target types if it has a cast implementation function with more than
159       one argument. This is used to represent type-specific length coercion
160       functions in the system catalogs. The named function is used to coerce
161       a value of the type to the type modifier value given by its second
162       argument.
163
164       When a cast has different source and target types and a function that
165       takes more than one argument, it supports converting from one type to
166       another and applying a length coercion in a single step. When no such
167       entry is available, coercion to a type that uses a type modifier
168       involves two cast steps, one to convert between data types and a second
169       to apply the modifier.
170
171       A cast to or from a domain type currently has no effect. Casting to or
172       from a domain uses the casts associated with its underlying type.
173

NOTES

175       Use DROP CAST (DROP_CAST(7)) to remove user-defined casts.
176
177       Remember that if you want to be able to convert types both ways you
178       need to declare casts both ways explicitly.
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
184       automatic casts to string types are treated as assignment casts, while
185       the automatic casts from string types are explicit-only. You can
186       override this behavior by declaring your own cast to replace an
187       automatic cast, but usually the only reason to do so is if you want the
188       conversion to be more easily invokable than the standard
189       assignment-only or explicit-only setting. Another possible reason is
190       that you want the conversion to behave differently from the type's I/O
191       function; but that is sufficiently surprising that you should think
192       twice about whether it's a good idea. (A small number of the built-in
193       types do indeed have different behaviors for conversions, mostly
194       because of requirements of the 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
198       different type was automatically a cast function. This convention has
199       been abandoned in face of the introduction of schemas and to be able to
200       represent binary-coercible casts in the system catalogs. The built-in
201       cast functions still follow this naming scheme, but they have to be
202       shown as 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
213       multiple conversion functions from different types that all use the
214       target type's name.
215
216           Note
217           Actually the preceding paragraph is an oversimplification: there
218           are two cases in which a function-call construct will be treated as
219           a cast request without having matched it to an actual function. If
220           a function call name(x) does not exactly match any existing
221           function, but name is the name of a data type and pg_cast provides
222           a binary-coercible cast to this type from the type of x, then the
223           call will be construed as a binary-coercible cast. This exception
224           is made so that binary-coercible casts can be invoked using
225           functional syntax, even though they lack any function. Likewise, if
226           there is no pg_cast entry but the cast would be to or from a string
227           type, the call will be construed as an I/O conversion cast. This
228           exception allows I/O conversion casts to be invoked using
229           functional syntax.
230
231           Note
232           There is also an exception to the exception: I/O conversion casts
233           from composite types to string types cannot be invoked using
234           functional syntax, but must be written in explicit cast syntax
235           (either CAST or :: notation). This exception was added because
236           after the introduction of automatically-provided I/O conversion
237           casts, it was found too easy to accidentally invoke such a cast
238           when a function or column reference was intended.
239

EXAMPLES

241       To create an assignment cast from type bigint to type int4 using the
242       function int4(bigint):
243
244           CREATE CAST (bigint AS int4) WITH FUNCTION int4(bigint) AS ASSIGNMENT;
245
246       (This cast is already predefined in the system.)
247

COMPATIBILITY

249       The CREATE CAST command conforms to the SQL standard, except that SQL
250       does not make provisions for binary-coercible types or extra arguments
251       to implementation functions.  AS IMPLICIT is a PostgreSQL extension,
252       too.
253

SEE ALSO

255       CREATE FUNCTION (CREATE_FUNCTION(7)), CREATE TYPE (CREATE_TYPE(7)),
256       DROP CAST (DROP_CAST(7))
257
258
259
260PostgreSQL 9.2.24                 2017-11-06                    CREATE CAST(7)
Impressum