1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>CREATE DOMAIN</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="sql-createdatabase.html" title="CREATE DATABASE" /><link rel="next" href="sql-createeventtrigger.html" title="CREATE EVENT TRIGGER" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">CREATE DOMAIN</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="sql-createdatabase.html" title="CREATE DATABASE">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><th width="60%" align="center">SQL Commands</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="sql-createeventtrigger.html" title="CREATE EVENT TRIGGER">Next</a></td></tr></table><hr /></div><div class="refentry" id="SQL-CREATEDOMAIN"><div class="titlepage"></div><a id="id-1.9.3.62.1" class="indexterm"></a><div class="refnamediv"><h2><span class="refentrytitle">CREATE DOMAIN</span></h2><p>CREATE DOMAIN — define a new domain</p></div><div class="refsynopsisdiv"><h2>Synopsis</h2><pre class="synopsis">
3 CREATE DOMAIN <em class="replaceable"><code>name</code></em> [ AS ] <em class="replaceable"><code>data_type</code></em>
4 [ COLLATE <em class="replaceable"><code>collation</code></em> ]
5 [ DEFAULT <em class="replaceable"><code>expression</code></em> ]
6 [ <em class="replaceable"><code>domain_constraint</code></em> [ ... ] ]
8 <span class="phrase">where <em class="replaceable"><code>domain_constraint</code></em> is:</span>
10 [ CONSTRAINT <em class="replaceable"><code>constraint_name</code></em> ]
11 { NOT NULL | NULL | CHECK (<em class="replaceable"><code>expression</code></em>) }
12 </pre></div><div class="refsect1" id="id-1.9.3.62.5"><h2>Description</h2><p>
13 <code class="command">CREATE DOMAIN</code> creates a new domain. A domain is
14 essentially a data type with optional constraints (restrictions on
15 the allowed set of values).
16 The user who defines a domain becomes its owner.
18 If a schema name is given (for example, <code class="literal">CREATE DOMAIN
19 myschema.mydomain ...</code>) then the domain is created in the
20 specified schema. Otherwise it is created in the current schema.
21 The domain name must be unique among the types and domains existing
24 Domains are useful for abstracting common constraints on fields into
25 a single location for maintenance. For example, several tables might
26 contain email address columns, all requiring the same CHECK constraint
27 to verify the address syntax.
28 Define a domain rather than setting up each table's constraint
31 To be able to create a domain, you must have <code class="literal">USAGE</code>
32 privilege on the underlying type.
33 </p></div><div class="refsect1" id="id-1.9.3.62.6"><h2>Parameters</h2><div class="variablelist"><dl class="variablelist"><dt><span class="term"><em class="replaceable"><code>name</code></em></span></dt><dd><p>
34 The name (optionally schema-qualified) of a domain to be created.
35 </p></dd><dt><span class="term"><em class="replaceable"><code>data_type</code></em></span></dt><dd><p>
36 The underlying data type of the domain. This can include array
38 </p></dd><dt><span class="term"><em class="replaceable"><code>collation</code></em></span></dt><dd><p>
39 An optional collation for the domain. If no collation is
40 specified, the domain has the same collation behavior as its
42 The underlying type must be collatable if <code class="literal">COLLATE</code>
44 </p></dd><dt><span class="term"><code class="literal">DEFAULT <em class="replaceable"><code>expression</code></em></code></span></dt><dd><p>
45 The <code class="literal">DEFAULT</code> clause specifies a default value for
46 columns of the domain data type. The value is any
47 variable-free expression (but subqueries are not allowed).
48 The data type of the default expression must match the data
49 type of the domain. If no default value is specified, then
50 the default value is the null value.
52 The default expression will be used in any insert operation
53 that does not specify a value for the column. If a default
54 value is defined for a particular column, it overrides any
55 default associated with the domain. In turn, the domain
56 default overrides any default value associated with the
58 </p></dd><dt><span class="term"><code class="literal">CONSTRAINT <em class="replaceable"><code>constraint_name</code></em></code></span></dt><dd><p>
59 An optional name for a constraint. If not specified,
60 the system generates a name.
61 </p></dd><dt><span class="term"><code class="literal">NOT NULL</code></span></dt><dd><p>
62 Values of this domain are prevented from being null
63 (but see notes below).
64 </p></dd><dt><span class="term"><code class="literal">NULL</code></span></dt><dd><p>
65 Values of this domain are allowed to be null. This is the default.
67 This clause is only intended for compatibility with
68 nonstandard SQL databases. Its use is discouraged in new
70 </p></dd><dt><span class="term"><code class="literal">CHECK (<em class="replaceable"><code>expression</code></em>)</code></span></dt><dd><p><code class="literal">CHECK</code> clauses specify integrity constraints or tests
71 which values of the domain must satisfy.
72 Each constraint must be an expression
73 producing a Boolean result. It should use the key word <code class="literal">VALUE</code>
74 to refer to the value being tested. Expressions evaluating
75 to TRUE or UNKNOWN succeed. If the expression produces a FALSE result,
76 an error is reported and the value is not allowed to be converted
79 Currently, <code class="literal">CHECK</code> expressions cannot contain
80 subqueries nor refer to variables other than <code class="literal">VALUE</code>.
82 When a domain has multiple <code class="literal">CHECK</code> constraints,
83 they will be tested in alphabetical order by name.
84 (<span class="productname">PostgreSQL</span> versions before 9.5 did not honor any
85 particular firing order for <code class="literal">CHECK</code> constraints.)
86 </p></dd></dl></div></div><div class="refsect1" id="SQL-CREATEDOMAIN-NOTES"><h2>Notes</h2><p>
87 Domain constraints, particularly <code class="literal">NOT NULL</code>, are checked when
88 converting a value to the domain type. It is possible for a column that
89 is nominally of the domain type to read as null despite there being such
90 a constraint. For example, this can happen in an outer-join query, if
91 the domain column is on the nullable side of the outer join. A more
93 </p><pre class="programlisting">
94 INSERT INTO tab (domcol) VALUES ((SELECT domcol FROM tab WHERE false));
96 The empty scalar sub-SELECT will produce a null value that is considered
97 to be of the domain type, so no further constraint checking is applied
98 to it, and the insertion will succeed.
100 It is very difficult to avoid such problems, because of SQL's general
101 assumption that a null value is a valid value of every data type. Best practice
102 therefore is to design a domain's constraints so that a null value is allowed,
103 and then to apply column <code class="literal">NOT NULL</code> constraints to columns of
104 the domain type as needed, rather than directly to the domain type.
106 <span class="productname">PostgreSQL</span> assumes that
107 <code class="literal">CHECK</code> constraints' conditions are immutable, that is,
108 they will always give the same result for the same input value. This
109 assumption is what justifies examining <code class="literal">CHECK</code>
110 constraints only when a value is first converted to be of a domain type,
111 and not at other times. (This is essentially the same as the treatment
112 of table <code class="literal">CHECK</code> constraints, as described in
113 <a class="xref" href="ddl-constraints.html#DDL-CONSTRAINTS-CHECK-CONSTRAINTS" title="5.5.1. Check Constraints">Section 5.5.1</a>.)
115 An example of a common way to break this assumption is to reference a
116 user-defined function in a <code class="literal">CHECK</code> expression, and then
117 change the behavior of that
118 function. <span class="productname">PostgreSQL</span> does not disallow that,
119 but it will not notice if there are stored values of the domain type that
120 now violate the <code class="literal">CHECK</code> constraint. That would cause a
121 subsequent database dump and restore to fail. The recommended way to
122 handle such a change is to drop the constraint (using <code class="command">ALTER
123 DOMAIN</code>), adjust the function definition, and re-add the
124 constraint, thereby rechecking it against stored data.
126 It's also good practice to ensure that domain <code class="literal">CHECK</code>
127 expressions will not throw errors.
128 </p></div><div class="refsect1" id="id-1.9.3.62.8"><h2>Examples</h2><p>
129 This example creates the <code class="type">us_postal_code</code> data type and
130 then uses the type in a table definition. A regular expression test
131 is used to verify that the value looks like a valid US postal code:
133 </p><pre class="programlisting">
134 CREATE DOMAIN us_postal_code AS TEXT
137 OR VALUE ~ '^\d{5}-\d{4}$'
140 CREATE TABLE us_snail_addy (
141 address_id SERIAL PRIMARY KEY,
142 street1 TEXT NOT NULL,
146 postal us_postal_code NOT NULL
148 </pre></div><div class="refsect1" id="SQL-CREATEDOMAIN-COMPATIBILITY"><h2>Compatibility</h2><p>
149 The command <code class="command">CREATE DOMAIN</code> conforms to the SQL
152 The syntax <code class="literal">NOT NULL</code> in this command is a
153 <span class="productname">PostgreSQL</span> extension. (A standard-conforming
154 way to write the same for non-composite data types would be
155 <code class="literal">CHECK (VALUE IS NOT
156 NULL)</code>. However, per <a class="xref" href="sql-createdomain.html#SQL-CREATEDOMAIN-NOTES" title="Notes">the section called “Notes”</a>,
157 such constraints are best avoided in practice anyway.) The
158 <code class="literal">NULL</code> <span class="quote">“<span class="quote">constraint</span>”</span> is a
159 <span class="productname">PostgreSQL</span> extension (see also <a class="xref" href="sql-createtable.html#SQL-CREATETABLE-COMPATIBILITY" title="Compatibility">Compatibility</a>).
160 </p></div><div class="refsect1" id="SQL-CREATEDOMAIN-SEE-ALSO"><h2>See Also</h2><span class="simplelist"><a class="xref" href="sql-alterdomain.html" title="ALTER DOMAIN"><span class="refentrytitle">ALTER DOMAIN</span></a>, <a class="xref" href="sql-dropdomain.html" title="DROP DOMAIN"><span class="refentrytitle">DROP DOMAIN</span></a></span></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="sql-createdatabase.html" title="CREATE DATABASE">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="sql-createeventtrigger.html" title="CREATE EVENT TRIGGER">Next</a></td></tr><tr><td width="40%" align="left" valign="top">CREATE DATABASE </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> CREATE EVENT TRIGGER</td></tr></table></div></body></html>