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
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
|
<!--
doc/src/sgml/ref/create_schema.sgml
PostgreSQL documentation
-->
<refentry id="sql-createschema">
<indexterm zone="sql-createschema">
<primary>CREATE SCHEMA</primary>
</indexterm>
<refmeta>
<refentrytitle>CREATE SCHEMA</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>CREATE SCHEMA</refname>
<refpurpose>define a new schema</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
CREATE SCHEMA <replaceable class="parameter">schema_name</replaceable> [ AUTHORIZATION <replaceable class="parameter">role_specification</replaceable> ] [ <replaceable class="parameter">schema_element</replaceable> [ ... ] ]
CREATE SCHEMA AUTHORIZATION <replaceable class="parameter">role_specification</replaceable> [ <replaceable class="parameter">schema_element</replaceable> [ ... ] ]
CREATE SCHEMA IF NOT EXISTS <replaceable class="parameter">schema_name</replaceable> [ AUTHORIZATION <replaceable class="parameter">role_specification</replaceable> ]
CREATE SCHEMA IF NOT EXISTS AUTHORIZATION <replaceable class="parameter">role_specification</replaceable>
<phrase>where <replaceable class="parameter">role_specification</replaceable> can be:</phrase>
<replaceable class="parameter">user_name</replaceable>
| CURRENT_ROLE
| CURRENT_USER
| SESSION_USER
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<command>CREATE SCHEMA</command> enters a new schema
into the current database.
The schema name must be distinct from the name of any existing schema
in the current database.
</para>
<para>
A schema is essentially a namespace:
it contains named objects (tables, data types, functions, and operators)
whose names can duplicate those of other objects existing in other
schemas. Named objects are accessed either by <quote>qualifying</quote>
their names with the schema name as a prefix, or by setting a search
path that includes the desired schema(s). A <literal>CREATE</literal> command
specifying an unqualified object name creates the object
in the current schema (the one at the front of the search path,
which can be determined with the function <function>current_schema</function>).
</para>
<para>
Optionally, <command>CREATE SCHEMA</command> can include subcommands
to create objects within the new schema. The subcommands are treated
essentially the same as separate commands issued after creating the
schema, except that if the <literal>AUTHORIZATION</literal> clause is used,
all the created objects will be owned by that user.
</para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><replaceable class="parameter">schema_name</replaceable></term>
<listitem>
<para>
The name of a schema to be created. If this is omitted, the
<replaceable class="parameter">user_name</replaceable>
is used as the schema name. The name cannot
begin with <literal>pg_</literal>, as such names
are reserved for system schemas.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">user_name</replaceable></term>
<listitem>
<para>
The role name of the user who will own the new schema. If omitted,
defaults to the user executing the command. To create a schema
owned by another role, you must be able to
<literal>SET ROLE</literal> to that role.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">schema_element</replaceable></term>
<listitem>
<para>
An SQL statement defining an object to be created within the
schema. Currently, only <command>CREATE
TABLE</command>, <command>CREATE VIEW</command>, <command>CREATE
INDEX</command>, <command>CREATE SEQUENCE</command>, <command>CREATE
TRIGGER</command> and <command>GRANT</command> are accepted as clauses
within <command>CREATE SCHEMA</command>. Other kinds of objects may
be created in separate commands after the schema is created.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>IF NOT EXISTS</literal></term>
<listitem>
<para>
Do nothing (except issuing a notice) if a schema with the same name
already exists. <replaceable class="parameter">schema_element</replaceable>
subcommands cannot be included when this option is used.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
To create a schema, the invoking user must have the
<literal>CREATE</literal> privilege for the current database.
(Of course, superusers bypass this check.)
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
Create a schema:
<programlisting>
CREATE SCHEMA myschema;
</programlisting>
</para>
<para>
Create a schema for user <literal>joe</literal>; the schema will also be
named <literal>joe</literal>:
<programlisting>
CREATE SCHEMA AUTHORIZATION joe;
</programlisting>
</para>
<para>
Create a schema named <literal>test</literal> that will be owned by user
<literal>joe</literal>, unless there already is a schema named <literal>test</literal>.
(It does not matter whether <literal>joe</literal> owns the pre-existing schema.)
<programlisting>
CREATE SCHEMA IF NOT EXISTS test AUTHORIZATION joe;
</programlisting>
</para>
<para>
Create a schema and create a table and view within it:
<programlisting>
CREATE SCHEMA hollywood
CREATE TABLE films (title text, release date, awards text[])
CREATE VIEW winners AS
SELECT title, release FROM films WHERE awards IS NOT NULL;
</programlisting>
Notice that the individual subcommands do not end with semicolons.
</para>
<para>
The following is an equivalent way of accomplishing the same result:
<programlisting>
CREATE SCHEMA hollywood;
CREATE TABLE hollywood.films (title text, release date, awards text[]);
CREATE VIEW hollywood.winners AS
SELECT title, release FROM hollywood.films WHERE awards IS NOT NULL;
</programlisting></para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
The SQL standard allows a <literal>DEFAULT CHARACTER SET</literal> clause
in <command>CREATE SCHEMA</command>, as well as more subcommand
types than are presently accepted by
<productname>PostgreSQL</productname>.
</para>
<para>
The SQL standard specifies that the subcommands in <command>CREATE
SCHEMA</command> can appear in any order. The present
<productname>PostgreSQL</productname> implementation does not
handle all cases of forward references in subcommands; it might
sometimes be necessary to reorder the subcommands in order to avoid
forward references.
</para>
<para>
According to the SQL standard, the owner of a schema always owns
all objects within it. <productname>PostgreSQL</productname>
allows schemas to contain objects owned by users other than the
schema owner. This can happen only if the schema owner grants the
<literal>CREATE</literal> privilege on their schema to someone else, or a
superuser chooses to create objects in it.
</para>
<para>
The <literal>IF NOT EXISTS</literal> option is a
<productname>PostgreSQL</productname> extension.
</para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-alterschema"/></member>
<member><xref linkend="sql-dropschema"/></member>
</simplelist>
</refsect1>
</refentry>
|