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

NAME

6       CREATE_TYPE - define a new data type
7

SYNOPSIS

9       CREATE TYPE name AS
10           ( [ attribute_name data_type [ COLLATE collation ] [, ... ] ] )
11
12       CREATE TYPE name AS ENUM
13           ( [ 'label' [, ... ] ] )
14
15       CREATE TYPE name AS RANGE (
16           SUBTYPE = subtype
17           [ , SUBTYPE_OPCLASS = subtype_operator_class ]
18           [ , COLLATION = collation ]
19           [ , CANONICAL = canonical_function ]
20           [ , SUBTYPE_DIFF = subtype_diff_function ]
21       )
22
23       CREATE TYPE name (
24           INPUT = input_function,
25           OUTPUT = output_function
26           [ , RECEIVE = receive_function ]
27           [ , SEND = send_function ]
28           [ , TYPMOD_IN = type_modifier_input_function ]
29           [ , TYPMOD_OUT = type_modifier_output_function ]
30           [ , ANALYZE = analyze_function ]
31           [ , INTERNALLENGTH = { internallength | VARIABLE } ]
32           [ , PASSEDBYVALUE ]
33           [ , ALIGNMENT = alignment ]
34           [ , STORAGE = storage ]
35           [ , LIKE = like_type ]
36           [ , CATEGORY = category ]
37           [ , PREFERRED = preferred ]
38           [ , DEFAULT = default ]
39           [ , ELEMENT = element ]
40           [ , DELIMITER = delimiter ]
41           [ , COLLATABLE = collatable ]
42       )
43
44       CREATE TYPE name
45

DESCRIPTION

47       CREATE TYPE registers a new data type for use in the current database.
48       The user who defines a type becomes its owner.
49
50       If a schema name is given then the type is created in the specified
51       schema. Otherwise it is created in the current schema. The type name
52       must be distinct from the name of any existing type or domain in the
53       same schema. (Because tables have associated data types, the type name
54       must also be distinct from the name of any existing table in the same
55       schema.)
56
57       There are five forms of CREATE TYPE, as shown in the syntax synopsis
58       above. They respectively create a composite type, an enum type, a range
59       type, a base type, or a shell type. The first four of these are
60       discussed in turn below. A shell type is simply a placeholder for a
61       type to be defined later; it is created by issuing CREATE TYPE with no
62       parameters except for the type name. Shell types are needed as forward
63       references when creating range types and base types, as discussed in
64       those sections.
65
66   Composite Types
67       The first form of CREATE TYPE creates a composite type. The composite
68       type is specified by a list of attribute names and data types. An
69       attribute's collation can be specified too, if its data type is
70       collatable. A composite type is essentially the same as the row type of
71       a table, but using CREATE TYPE avoids the need to create an actual
72       table when all that is wanted is to define a type. A stand-alone
73       composite type is useful, for example, as the argument or return type
74       of a function.
75
76       To be able to create a composite type, you must have USAGE privilege on
77       all attribute types.
78
79   Enumerated Types
80       The second form of CREATE TYPE creates an enumerated (enum) type, as
81       described in Section 8.7, “Enumerated Types”, in the documentation.
82       Enum types take a list of one or more quoted labels, each of which must
83       be less than NAMEDATALEN bytes long (64 bytes in a standard PostgreSQL
84       build).
85
86   Range Types
87       The third form of CREATE TYPE creates a new range type, as described in
88       Section 8.17, “Range Types”, in the documentation.
89
90       The range type's subtype can be any type with an associated b-tree
91       operator class (to determine the ordering of values for the range
92       type). Normally the subtype's default b-tree operator class is used to
93       determine ordering; to use a non-default opclass, specify its name with
94       subtype_opclass. If the subtype is collatable, and you want to use a
95       non-default collation in the range's ordering, specify the desired
96       collation with the collation option.
97
98       The optional canonical function must take one argument of the range
99       type being defined, and return a value of the same type. This is used
100       to convert range values to a canonical form, when applicable. See
101       Section 8.17.8, “Defining New Range Types”, in the documentation for
102       more information. Creating a canonical function is a bit tricky, since
103       it must be defined before the range type can be declared. To do this,
104       you must first create a shell type, which is a placeholder type that
105       has no properties except a name and an owner. This is done by issuing
106       the command CREATE TYPE name, with no additional parameters. Then the
107       function can be declared using the shell type as argument and result,
108       and finally the range type can be declared using the same name. This
109       automatically replaces the shell type entry with a valid range type.
110
111       The optional subtype_diff function must take two values of the subtype
112       type as argument, and return a double precision value representing the
113       difference between the two given values. While this is optional,
114       providing it allows much greater efficiency of GiST indexes on columns
115       of the range type. See Section 8.17.8, “Defining New Range Types”, in
116       the documentation for more information.
117
118   Base Types
119       The fourth form of CREATE TYPE creates a new base type (scalar type).
120       To create a new base type, you must be a superuser. (This restriction
121       is made because an erroneous type definition could confuse or even
122       crash the server.)
123
124       The parameters can appear in any order, not only that illustrated
125       above, and most are optional. You must register two or more functions
126       (using CREATE FUNCTION) before defining the type. The support functions
127       input_function and output_function are required, while the functions
128       receive_function, send_function, type_modifier_input_function,
129       type_modifier_output_function and analyze_function are optional.
130       Generally these functions have to be coded in C or another low-level
131       language.
132
133       The input_function converts the type's external textual representation
134       to the internal representation used by the operators and functions
135       defined for the type.  output_function performs the reverse
136       transformation. The input function can be declared as taking one
137       argument of type cstring, or as taking three arguments of types
138       cstring, oid, integer. The first argument is the input text as a C
139       string, the second argument is the type's own OID (except for array
140       types, which instead receive their element type's OID), and the third
141       is the typmod of the destination column, if known (-1 will be passed if
142       not). The input function must return a value of the data type itself.
143       Usually, an input function should be declared STRICT; if it is not, it
144       will be called with a NULL first parameter when reading a NULL input
145       value. The function must still return NULL in this case, unless it
146       raises an error. (This case is mainly meant to support domain input
147       functions, which might need to reject NULL inputs.) The output function
148       must be declared as taking one argument of the new data type. The
149       output function must return type cstring. Output functions are not
150       invoked for NULL values.
151
152       The optional receive_function converts the type's external binary
153       representation to the internal representation. If this function is not
154       supplied, the type cannot participate in binary input. The binary
155       representation should be chosen to be cheap to convert to internal
156       form, while being reasonably portable. (For example, the standard
157       integer data types use network byte order as the external binary
158       representation, while the internal representation is in the machine's
159       native byte order.) The receive function should perform adequate
160       checking to ensure that the value is valid. The receive function can be
161       declared as taking one argument of type internal, or as taking three
162       arguments of types internal, oid, integer. The first argument is a
163       pointer to a StringInfo buffer holding the received byte string; the
164       optional arguments are the same as for the text input function. The
165       receive function must return a value of the data type itself. Usually,
166       a receive function should be declared STRICT; if it is not, it will be
167       called with a NULL first parameter when reading a NULL input value. The
168       function must still return NULL in this case, unless it raises an
169       error. (This case is mainly meant to support domain receive functions,
170       which might need to reject NULL inputs.) Similarly, the optional
171       send_function converts from the internal representation to the external
172       binary representation. If this function is not supplied, the type
173       cannot participate in binary output. The send function must be declared
174       as taking one argument of the new data type. The send function must
175       return type bytea. Send functions are not invoked for NULL values.
176
177       You should at this point be wondering how the input and output
178       functions can be declared to have results or arguments of the new type,
179       when they have to be created before the new type can be created. The
180       answer is that the type should first be defined as a shell type, which
181       is a placeholder type that has no properties except a name and an
182       owner. This is done by issuing the command CREATE TYPE name, with no
183       additional parameters. Then the I/O functions can be defined
184       referencing the shell type. Finally, CREATE TYPE with a full definition
185       replaces the shell entry with a complete, valid type definition, after
186       which the new type can be used normally.
187
188       The optional type_modifier_input_function and
189       type_modifier_output_function are needed if the type supports
190       modifiers, that is optional constraints attached to a type declaration,
191       such as char(5) or numeric(30,2).  PostgreSQL allows user-defined types
192       to take one or more simple constants or identifiers as modifiers.
193       However, this information must be capable of being packed into a single
194       non-negative integer value for storage in the system catalogs. The
195       type_modifier_input_function is passed the declared modifier(s) in the
196       form of a cstring array. It must check the values for validity
197       (throwing an error if they are wrong), and if they are correct, return
198       a single non-negative integer value that will be stored as the column
199       “typmod”. Type modifiers will be rejected if the type does not have a
200       type_modifier_input_function. The type_modifier_output_function
201       converts the internal integer typmod value back to the correct form for
202       user display. It must return a cstring value that is the exact string
203       to append to the type name; for example numeric's function might return
204       (30,2). It is allowed to omit the type_modifier_output_function, in
205       which case the default display format is just the stored typmod integer
206       value enclosed in parentheses.
207
208       The optional analyze_function performs type-specific statistics
209       collection for columns of the data type. By default, ANALYZE will
210       attempt to gather statistics using the type's “equals” and “less-than”
211       operators, if there is a default b-tree operator class for the type.
212       For non-scalar types this behavior is likely to be unsuitable, so it
213       can be overridden by specifying a custom analysis function. The
214       analysis function must be declared to take a single argument of type
215       internal, and return a boolean result. The detailed API for analysis
216       functions appears in src/include/commands/vacuum.h.
217
218       While the details of the new type's internal representation are only
219       known to the I/O functions and other functions you create to work with
220       the type, there are several properties of the internal representation
221       that must be declared to PostgreSQL. Foremost of these is
222       internallength. Base data types can be fixed-length, in which case
223       internallength is a positive integer, or variable length, indicated by
224       setting internallength to VARIABLE. (Internally, this is represented by
225       setting typlen to -1.) The internal representation of all
226       variable-length types must start with a 4-byte integer giving the total
227       length of this value of the type.
228
229       The optional flag PASSEDBYVALUE indicates that values of this data type
230       are passed by value, rather than by reference. You cannot pass by value
231       types whose internal representation is larger than the size of the
232       Datum type (4 bytes on most machines, 8 bytes on a few).
233
234       The alignment parameter specifies the storage alignment required for
235       the data type. The allowed values equate to alignment on 1, 2, 4, or 8
236       byte boundaries. Note that variable-length types must have an alignment
237       of at least 4, since they necessarily contain an int4 as their first
238       component.
239
240       The storage parameter allows selection of storage strategies for
241       variable-length data types. (Only plain is allowed for fixed-length
242       types.)  plain specifies that data of the type will always be stored
243       in-line and not compressed.  extended specifies that the system will
244       first try to compress a long data value, and will move the value out of
245       the main table row if it's still too long.  external allows the value
246       to be moved out of the main table, but the system will not try to
247       compress it.  main allows compression, but discourages moving the value
248       out of the main table. (Data items with this storage strategy might
249       still be moved out of the main table if there is no other way to make a
250       row fit, but they will be kept in the main table preferentially over
251       extended and external items.)
252
253       The like_type parameter provides an alternative method for specifying
254       the basic representation properties of a data type: copy them from some
255       existing type. The values of internallength, passedbyvalue, alignment,
256       and storage are copied from the named type. (It is possible, though
257       usually undesirable, to override some of these values by specifying
258       them along with the LIKE clause.) Specifying representation this way is
259       especially useful when the low-level implementation of the new type
260       “piggybacks” on an existing type in some fashion.
261
262       The category and preferred parameters can be used to help control which
263       implicit cast will be applied in ambiguous situations. Each data type
264       belongs to a category named by a single ASCII character, and each type
265       is either “preferred” or not within its category. The parser will
266       prefer casting to preferred types (but only from other types within the
267       same category) when this rule is helpful in resolving overloaded
268       functions or operators. For more details see Chapter 10, Type
269       Conversion, in the documentation. For types that have no implicit casts
270       to or from any other types, it is sufficient to leave these settings at
271       the defaults. However, for a group of related types that have implicit
272       casts, it is often helpful to mark them all as belonging to a category
273       and select one or two of the “most general” types as being preferred
274       within the category. The category parameter is especially useful when
275       adding a user-defined type to an existing built-in category, such as
276       the numeric or string types. However, it is also possible to create new
277       entirely-user-defined type categories. Select any ASCII character other
278       than an upper-case letter to name such a category.
279
280       A default value can be specified, in case a user wants columns of the
281       data type to default to something other than the null value. Specify
282       the default with the DEFAULT key word. (Such a default can be
283       overridden by an explicit DEFAULT clause attached to a particular
284       column.)
285
286       To indicate that a type is an array, specify the type of the array
287       elements using the ELEMENT key word. For example, to define an array of
288       4-byte integers (int4), specify ELEMENT = int4. More details about
289       array types appear below.
290
291       To indicate the delimiter to be used between values in the external
292       representation of arrays of this type, delimiter can be set to a
293       specific character. The default delimiter is the comma (,). Note that
294       the delimiter is associated with the array element type, not the array
295       type itself.
296
297       If the optional Boolean parameter collatable is true, column
298       definitions and expressions of the type may carry collation information
299       through use of the COLLATE clause. It is up to the implementations of
300       the functions operating on the type to actually make use of the
301       collation information; this does not happen automatically merely by
302       marking the type collatable.
303
304   Array Types
305       Whenever a user-defined type is created, PostgreSQL automatically
306       creates an associated array type, whose name consists of the element
307       type's name prepended with an underscore, and truncated if necessary to
308       keep it less than NAMEDATALEN bytes long. (If the name so generated
309       collides with an existing type name, the process is repeated until a
310       non-colliding name is found.) This implicitly-created array type is
311       variable length and uses the built-in input and output functions
312       array_in and array_out. The array type tracks any changes in its
313       element type's owner or schema, and is dropped if the element type is.
314
315       You might reasonably ask why there is an ELEMENT option, if the system
316       makes the correct array type automatically. The only case where it's
317       useful to use ELEMENT is when you are making a fixed-length type that
318       happens to be internally an array of a number of identical things, and
319       you want to allow these things to be accessed directly by subscripting,
320       in addition to whatever operations you plan to provide for the type as
321       a whole. For example, type point is represented as just two
322       floating-point numbers, each can be accessed using point[0] and
323       point[1]. Note that this facility only works for fixed-length types
324       whose internal form is exactly a sequence of identical fixed-length
325       fields. A subscriptable variable-length type must have the generalized
326       internal representation used by array_in and array_out. For historical
327       reasons (i.e., this is clearly wrong but it's far too late to change
328       it), subscripting of fixed-length array types starts from zero, rather
329       than from one as for variable-length arrays.
330

PARAMETERS

332       name
333           The name (optionally schema-qualified) of a type to be created.
334
335       attribute_name
336           The name of an attribute (column) for the composite type.
337
338       data_type
339           The name of an existing data type to become a column of the
340           composite type.
341
342       collation
343           The name of an existing collation to be associated with a column of
344           a composite type, or with a range type.
345
346       label
347           A string literal representing the textual label associated with one
348           value of an enum type.
349
350       subtype
351           The name of the element type that the range type will represent
352           ranges of.
353
354       subtype_operator_class
355           The name of a b-tree operator class for the subtype.
356
357       canonical_function
358           The name of the canonicalization function for the range type.
359
360       subtype_diff_function
361           The name of a difference function for the subtype.
362
363       input_function
364           The name of a function that converts data from the type's external
365           textual form to its internal form.
366
367       output_function
368           The name of a function that converts data from the type's internal
369           form to its external textual form.
370
371       receive_function
372           The name of a function that converts data from the type's external
373           binary form to its internal form.
374
375       send_function
376           The name of a function that converts data from the type's internal
377           form to its external binary form.
378
379       type_modifier_input_function
380           The name of a function that converts an array of modifier(s) for
381           the type into internal form.
382
383       type_modifier_output_function
384           The name of a function that converts the internal form of the
385           type's modifier(s) to external textual form.
386
387       analyze_function
388           The name of a function that performs statistical analysis for the
389           data type.
390
391       internallength
392           A numeric constant that specifies the length in bytes of the new
393           type's internal representation. The default assumption is that it
394           is variable-length.
395
396       alignment
397           The storage alignment requirement of the data type. If specified,
398           it must be char, int2, int4, or double; the default is int4.
399
400       storage
401           The storage strategy for the data type. If specified, must be
402           plain, external, extended, or main; the default is plain.
403
404       like_type
405           The name of an existing data type that the new type will have the
406           same representation as. The values of internallength,
407           passedbyvalue, alignment, and storage are copied from that type,
408           unless overridden by explicit specification elsewhere in this
409           CREATE TYPE command.
410
411       category
412           The category code (a single ASCII character) for this type. The
413           default is 'U' for “user-defined type”. Other standard category
414           codes can be found in Table 45.51, “typcategory Codes”. You may
415           also choose other ASCII characters in order to create custom
416           categories.
417
418       preferred
419           True if this type is a preferred type within its type category,
420           else false. The default is false. Be very careful about creating a
421           new preferred type within an existing type category, as this could
422           cause surprising changes in behavior.
423
424       default
425           The default value for the data type. If this is omitted, the
426           default is null.
427
428       element
429           The type being created is an array; this specifies the type of the
430           array elements.
431
432       delimiter
433           The delimiter character to be used between values in arrays made of
434           this type.
435
436       collatable
437           True if this type's operations can use collation information. The
438           default is false.
439

NOTES

441       Because there are no restrictions on use of a data type once it's been
442       created, creating a base type or range type is tantamount to granting
443       public execute permission on the functions mentioned in the type
444       definition. This is usually not an issue for the sorts of functions
445       that are useful in a type definition. But you might want to think twice
446       before designing a type in a way that would require “secret”
447       information to be used while converting it to or from external form.
448
449       Before PostgreSQL version 8.3, the name of a generated array type was
450       always exactly the element type's name with one underscore character
451       (_) prepended. (Type names were therefore restricted in length to one
452       less character than other names.) While this is still usually the case,
453       the array type name may vary from this in case of maximum-length names
454       or collisions with user type names that begin with underscore. Writing
455       code that depends on this convention is therefore deprecated. Instead,
456       use pg_type.typarray to locate the array type associated with a given
457       type.
458
459       It may be advisable to avoid using type and table names that begin with
460       underscore. While the server will change generated array type names to
461       avoid collisions with user-given names, there is still risk of
462       confusion, particularly with old client software that may assume that
463       type names beginning with underscores always represent arrays.
464
465       Before PostgreSQL version 8.2, the shell-type creation syntax CREATE
466       TYPE name did not exist. The way to create a new base type was to
467       create its input function first. In this approach, PostgreSQL will
468       first see the name of the new data type as the return type of the input
469       function. The shell type is implicitly created in this situation, and
470       then it can be referenced in the definitions of the remaining I/O
471       functions. This approach still works, but is deprecated and might be
472       disallowed in some future release. Also, to avoid accidentally
473       cluttering the catalogs with shell types as a result of simple typos in
474       function definitions, a shell type will only be made this way when the
475       input function is written in C.
476
477       In PostgreSQL versions before 7.3, it was customary to avoid creating a
478       shell type at all, by replacing the functions' forward references to
479       the type name with the placeholder pseudotype opaque. The cstring
480       arguments and results also had to be declared as opaque before 7.3. To
481       support loading of old dump files, CREATE TYPE will accept I/O
482       functions declared using opaque, but it will issue a notice and change
483       the function declarations to use the correct types.
484

EXAMPLES

486       This example creates a composite type and uses it in a function
487       definition:
488
489           CREATE TYPE compfoo AS (f1 int, f2 text);
490
491           CREATE FUNCTION getfoo() RETURNS SETOF compfoo AS $$
492               SELECT fooid, fooname FROM foo
493           $$ LANGUAGE SQL;
494
495       This example creates an enumerated type and uses it in a table
496       definition:
497
498           CREATE TYPE bug_status AS ENUM ('new', 'open', 'closed');
499
500           CREATE TABLE bug (
501               id serial,
502               description text,
503               status bug_status
504           );
505
506       This example creates a range type:
507
508           CREATE TYPE float8_range AS RANGE (subtype = float8, subtype_diff = float8mi);
509
510       This example creates the base data type box and then uses the type in a
511       table definition:
512
513           CREATE TYPE box;
514
515           CREATE FUNCTION my_box_in_function(cstring) RETURNS box AS ... ;
516           CREATE FUNCTION my_box_out_function(box) RETURNS cstring AS ... ;
517
518           CREATE TYPE box (
519               INTERNALLENGTH = 16,
520               INPUT = my_box_in_function,
521               OUTPUT = my_box_out_function
522           );
523
524           CREATE TABLE myboxes (
525               id integer,
526               description box
527           );
528
529       If the internal structure of box were an array of four float4 elements,
530       we might instead use:
531
532           CREATE TYPE box (
533               INTERNALLENGTH = 16,
534               INPUT = my_box_in_function,
535               OUTPUT = my_box_out_function,
536               ELEMENT = float4
537           );
538
539       which would allow a box value's component numbers to be accessed by
540       subscripting. Otherwise the type behaves the same as before.
541
542       This example creates a large object type and uses it in a table
543       definition:
544
545           CREATE TYPE bigobj (
546               INPUT = lo_filein, OUTPUT = lo_fileout,
547               INTERNALLENGTH = VARIABLE
548           );
549           CREATE TABLE big_objs (
550               id integer,
551               obj bigobj
552           );
553
554       More examples, including suitable input and output functions, are in
555       Section 35.11, “User-defined Types”, in the documentation.
556

COMPATIBILITY

558       The first form of the CREATE TYPE command, which creates a composite
559       type, conforms to the SQL standard. The other forms are PostgreSQL
560       extensions. The CREATE TYPE statement in the SQL standard also defines
561       other forms that are not implemented in PostgreSQL.
562
563       The ability to create a composite type with zero attributes is a
564       PostgreSQL-specific deviation from the standard (analogous to the same
565       case in CREATE TABLE).
566

SEE ALSO

568       ALTER TYPE (ALTER_TYPE(7)), CREATE DOMAIN (CREATE_DOMAIN(7)), CREATE
569       FUNCTION (CREATE_FUNCTION(7)), DROP TYPE (DROP_TYPE(7))
570
571
572
573PostgreSQL 9.2.24                 2017-11-06                    CREATE TYPE(7)
Impressum