1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
|
'\" t
.\" Title: CREATE DOMAIN
.\" Author: The PostgreSQL Global Development Group
.\" Generator: DocBook XSL Stylesheets vsnapshot <http://docbook.sf.net/>
.\" Date: 2024
.\" Manual: PostgreSQL 16.2 Documentation
.\" Source: PostgreSQL 16.2
.\" Language: English
.\"
.TH "CREATE DOMAIN" "7" "2024" "PostgreSQL 16.2" "PostgreSQL 16.2 Documentation"
.\" -----------------------------------------------------------------
.\" * Define some portability stuff
.\" -----------------------------------------------------------------
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.\" http://bugs.debian.org/507673
.\" http://lists.gnu.org/archive/html/groff/2009-02/msg00013.html
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.ie \n(.g .ds Aq \(aq
.el .ds Aq '
.\" -----------------------------------------------------------------
.\" * set default formatting
.\" -----------------------------------------------------------------
.\" disable hyphenation
.nh
.\" disable justification (adjust text to left margin only)
.ad l
.\" -----------------------------------------------------------------
.\" * MAIN CONTENT STARTS HERE *
.\" -----------------------------------------------------------------
.SH "NAME"
CREATE_DOMAIN \- define a new domain
.SH "SYNOPSIS"
.sp
.nf
CREATE DOMAIN \fIname\fR [ AS ] \fIdata_type\fR
[ COLLATE \fIcollation\fR ]
[ DEFAULT \fIexpression\fR ]
[ \fIconstraint\fR [ \&.\&.\&. ] ]
where \fIconstraint\fR is:
[ CONSTRAINT \fIconstraint_name\fR ]
{ NOT NULL | NULL | CHECK (\fIexpression\fR) }
.fi
.SH "DESCRIPTION"
.PP
\fBCREATE DOMAIN\fR
creates a new domain\&. A domain is essentially a data type with optional constraints (restrictions on the allowed set of values)\&. The user who defines a domain becomes its owner\&.
.PP
If a schema name is given (for example,
CREATE DOMAIN myschema\&.mydomain \&.\&.\&.) then the domain is created in the specified schema\&. Otherwise it is created in the current schema\&. The domain name must be unique among the types and domains existing in its schema\&.
.PP
Domains are useful for abstracting common constraints on fields into a single location for maintenance\&. For example, several tables might contain email address columns, all requiring the same CHECK constraint to verify the address syntax\&. Define a domain rather than setting up each table\*(Aqs constraint individually\&.
.PP
To be able to create a domain, you must have
USAGE
privilege on the underlying type\&.
.SH "PARAMETERS"
.PP
\fIname\fR
.RS 4
The name (optionally schema\-qualified) of a domain to be created\&.
.RE
.PP
\fIdata_type\fR
.RS 4
The underlying data type of the domain\&. This can include array specifiers\&.
.RE
.PP
\fIcollation\fR
.RS 4
An optional collation for the domain\&. If no collation is specified, the domain has the same collation behavior as its underlying data type\&. The underlying type must be collatable if
COLLATE
is specified\&.
.RE
.PP
DEFAULT \fIexpression\fR
.RS 4
The
DEFAULT
clause specifies a default value for columns of the domain data type\&. The value is any variable\-free expression (but subqueries are not allowed)\&. The data type of the default expression must match the data type of the domain\&. If no default value is specified, then the default value is the null value\&.
.sp
The default expression will be used in any insert operation that does not specify a value for the column\&. If a default value is defined for a particular column, it overrides any default associated with the domain\&. In turn, the domain default overrides any default value associated with the underlying data type\&.
.RE
.PP
CONSTRAINT \fIconstraint_name\fR
.RS 4
An optional name for a constraint\&. If not specified, the system generates a name\&.
.RE
.PP
NOT NULL
.RS 4
Values of this domain are prevented from being null (but see notes below)\&.
.RE
.PP
NULL
.RS 4
Values of this domain are allowed to be null\&. This is the default\&.
.sp
This clause is only intended for compatibility with nonstandard SQL databases\&. Its use is discouraged in new applications\&.
.RE
.PP
CHECK (\fIexpression\fR)
.RS 4
CHECK
clauses specify integrity constraints or tests which values of the domain must satisfy\&. Each constraint must be an expression producing a Boolean result\&. It should use the key word
VALUE
to refer to the value being tested\&. Expressions evaluating to TRUE or UNKNOWN succeed\&. If the expression produces a FALSE result, an error is reported and the value is not allowed to be converted to the domain type\&.
.sp
Currently,
CHECK
expressions cannot contain subqueries nor refer to variables other than
VALUE\&.
.sp
When a domain has multiple
CHECK
constraints, they will be tested in alphabetical order by name\&. (PostgreSQL
versions before 9\&.5 did not honor any particular firing order for
CHECK
constraints\&.)
.RE
.SH "NOTES"
.PP
Domain constraints, particularly
NOT NULL, are checked when converting a value to the domain type\&. It is possible for a column that is nominally of the domain type to read as null despite there being such a constraint\&. For example, this can happen in an outer\-join query, if the domain column is on the nullable side of the outer join\&. A more subtle example is
.sp
.if n \{\
.RS 4
.\}
.nf
INSERT INTO tab (domcol) VALUES ((SELECT domcol FROM tab WHERE false));
.fi
.if n \{\
.RE
.\}
.sp
The empty scalar sub\-SELECT will produce a null value that is considered to be of the domain type, so no further constraint checking is applied to it, and the insertion will succeed\&.
.PP
It is very difficult to avoid such problems, because of SQL\*(Aqs general assumption that a null value is a valid value of every data type\&. Best practice therefore is to design a domain\*(Aqs constraints so that a null value is allowed, and then to apply column
NOT NULL
constraints to columns of the domain type as needed, rather than directly to the domain type\&.
.PP
PostgreSQL
assumes that
CHECK
constraints\*(Aq conditions are immutable, that is, they will always give the same result for the same input value\&. This assumption is what justifies examining
CHECK
constraints only when a value is first converted to be of a domain type, and not at other times\&. (This is essentially the same as the treatment of table
CHECK
constraints, as described in
Section\ \&5.4.1\&.)
.PP
An example of a common way to break this assumption is to reference a user\-defined function in a
CHECK
expression, and then change the behavior of that function\&.
PostgreSQL
does not disallow that, but it will not notice if there are stored values of the domain type that now violate the
CHECK
constraint\&. That would cause a subsequent database dump and restore to fail\&. The recommended way to handle such a change is to drop the constraint (using
\fBALTER DOMAIN\fR), adjust the function definition, and re\-add the constraint, thereby rechecking it against stored data\&.
.PP
It\*(Aqs also good practice to ensure that domain
CHECK
expressions will not throw errors\&.
.SH "EXAMPLES"
.PP
This example creates the
us_postal_code
data type and then uses the type in a table definition\&. A regular expression test is used to verify that the value looks like a valid US postal code:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE DOMAIN us_postal_code AS TEXT
CHECK(
VALUE ~ \*(Aq^\ed{5}$\*(Aq
OR VALUE ~ \*(Aq^\ed{5}\-\ed{4}$\*(Aq
);
CREATE TABLE us_snail_addy (
address_id SERIAL PRIMARY KEY,
street1 TEXT NOT NULL,
street2 TEXT,
street3 TEXT,
city TEXT NOT NULL,
postal us_postal_code NOT NULL
);
.fi
.if n \{\
.RE
.\}
.SH "COMPATIBILITY"
.PP
The command
\fBCREATE DOMAIN\fR
conforms to the SQL standard\&.
.SH "SEE ALSO"
ALTER DOMAIN (\fBALTER_DOMAIN\fR(7)), DROP DOMAIN (\fBDROP_DOMAIN\fR(7))
|