1CREATE CAST() SQL Commands CREATE CAST()
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
20 CREATE CAST defines a new cast. A cast specifies how to perform a con‐
21 version between two data types. For example,
22
23 SELECT CAST(42 AS text);
24
25 converts the integer constant 42 to type text by invoking a previously
26 specified function, in this case text(int4). (If no suitable cast has
27 been defined, the conversion fails.)
28
29 Two types may be binary compatible, which means that they can be con‐
30 verted into one another ``for free'' without invoking any function.
31 This requires that corresponding values use the same internal represen‐
32 tation. For instance, the types text and varchar are binary compatible.
33
34 By default, a cast can be invoked only by an explicit cast request,
35 that is an explicit CAST(x AS typename) or x::typename construct.
36
37 If the cast is marked AS ASSIGNMENT then it can be invoked implicitly
38 when assigning a value to a column of the target data type. For exam‐
39 ple, supposing that foo.f1 is a column of type text, then
40
41 INSERT INTO foo (f1) VALUES (42);
42
43 will be allowed if the cast from type integer to type text is marked AS
44 ASSIGNMENT, otherwise not. (We generally use the term assignment cast
45 to describe this kind of cast.)
46
47 If the cast is marked AS IMPLICIT then it can be invoked implicitly in
48 any context, whether assignment or internally in an expression. For
49 example, since || takes text operands,
50
51 SELECT 'The time is ' || now();
52
53 will be allowed only if the cast from type timestamp to text is marked
54 AS IMPLICIT. Otherwise it will be necessary to write the cast explic‐
55 itly, for example
56
57 SELECT 'The time is ' || CAST(now() AS text);
58
59 (We generally use the term implicit cast to describe this kind of
60 cast.)
61
62 It is wise to be conservative about marking casts as implicit. An over‐
63 abundance of implicit casting paths can cause PostgreSQL to choose sur‐
64 prising interpretations of commands, or to be unable to resolve com‐
65 mands at all because there are multiple possible interpretations. A
66 good rule of thumb is to make a cast implicitly invokable only for
67 information-preserving transformations between types in the same gen‐
68 eral type category. For example, the cast from int2 to int4 can reason‐
69 ably be implicit, but the cast from float8 to int4 should probably be
70 assignment-only. Cross-type-category casts, such as text to int4, are
71 best made explicit-only.
72
73 To be able to create a cast, you must own the source or the target data
74 type. To create a binary-compatible cast, you must be superuser. (This
75 restriction is made because an erroneous binary-compatible cast conver‐
76 sion can easily crash the server.)
77
79 sourcetype
80 The name of the source data type of the cast.
81
82 targettype
83 The name of the target data type of the cast.
84
85 funcname(argtypes)
86 The function used to perform the cast. The function name may be
87 schema-qualified. If it is not, the function will be looked up
88 in the schema search path. The function's result data type must
89 match the target type of the cast. Its arguments are discussed
90 below.
91
92 WITHOUT FUNCTION
93 Indicates that the source type and the target type are binary
94 compatible, so no function is required to perform the cast.
95
96 AS ASSIGNMENT
97 Indicates that the cast may be invoked implicitly in assignment
98 contexts.
99
100 AS IMPLICIT
101 Indicates that the cast may be invoked implicitly in any con‐
102 text.
103
104 Cast implementation functions may have one to three arguments. The
105 first argument type must be identical to the cast's source type. The
106 second argument, if present, must be type integer; it receives the type
107 modifier associated with the destination type, or -1 if there is none.
108 The third argument, if present, must be type boolean; it receives true
109 if the cast is an explicit cast, false otherwise. (Bizarrely, the SQL
110 spec demands different behaviors for explicit and implicit casts in
111 some cases. This argument is supplied for functions that must implement
112 such casts. It is not recommended that you design your own data types
113 so that this matters.)
114
115 Ordinarily a cast must have different source and target data types.
116 However, it is allowed to declare a cast with identical source and tar‐
117 get types if it has a cast implementation function with more than one
118 argument. This is used to represent type-specific length coercion func‐
119 tions in the system catalogs. The named function is used to coerce a
120 value of the type to the type modifier value given by its second argu‐
121 ment. (Since the grammar presently permits only certain built-in data
122 types to have type modifiers, this feature is of no use for user-
123 defined target types, but we mention it for completeness.)
124
125 When a cast has different source and target types and a function that
126 takes more than one argument, it represents converting from one type to
127 another and applying a length coercion in a single step. When no such
128 entry is available, coercion to a type that uses a type modifier
129 involves two steps, one to convert between data types and a second to
130 apply the modifier.
131
133 Use DROP CAST [drop_cast(7)] to remove user-defined casts.
134
135 Remember that if you want to be able to convert types both ways you
136 need to declare casts both ways explicitly.
137
138 Prior to PostgreSQL 7.3, every function that had the same name as a
139 data type, returned that data type, and took one argument of a differ‐
140 ent type was automatically a cast function. This convention has been
141 abandoned in face of the introduction of schemas and to be able to rep‐
142 resent binary compatible casts in the system catalogs. The built-in
143 cast functions still follow this naming scheme, but they have to be
144 shown as casts in the system catalog pg_cast as well.
145
146 While not required, it is recommended that you continue to follow this
147 old convention of naming cast implementation functions after the target
148 data type. Many users are used to being able to cast data types using a
149 function-style notation, that is typename(x). This notation is in fact
150 nothing more nor less than a call of the cast implementation function;
151 it is not specially treated as a cast. If your conversion functions are
152 not named to support this convention then you will have surprised
153 users. Since PostgreSQL allows overloading of the same function name
154 with different argument types, there is no difficulty in having multi‐
155 ple conversion functions from different types that all use the target
156 type's name.
157
158 Note: There is one small lie in the preceding paragraph: there
159 is still one case in which pg_cast will be used to resolve the
160 meaning of an apparent function call. If a function call name(x)
161 matches no actual function, but name is the name of a data type
162 and pg_cast shows a binary-compatible cast to this type from the
163 type of x, then the call will be construed as an explicit cast.
164 This exception is made so that binary-compatible casts can be
165 invoked using functional syntax, even though they lack any func‐
166 tion.
167
168
170 To create a cast from type text to type int4 using the function
171 int4(text):
172
173 CREATE CAST (text AS int4) WITH FUNCTION int4(text);
174
175 (This cast is already predefined in the system.)
176
178 The CREATE CAST command conforms to the SQL standard, except that SQL
179 does not make provisions for binary-compatible types or extra arguments
180 to implementation functions. AS IMPLICIT is a PostgreSQL extension,
181 too.
182
184 CREATE FUNCTION [create_function(7)], CREATE TYPE [create_type(7)],
185 DROP CAST [drop_cast(7)]
186
187
188
189SQL - Language Statements 2008-06-08 CREATE CAST()