summaryrefslogtreecommitdiffstats
path: root/doc/src/sgml/ref/alter_database.sgml
blob: 89ed261b4c2d5a8b1c0f9c2e47a8ce06c14bced7 (plain)
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
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
<!--
doc/src/sgml/ref/alter_database.sgml
PostgreSQL documentation
-->

<refentry id="sql-alterdatabase">
 <indexterm zone="sql-alterdatabase">
  <primary>ALTER DATABASE</primary>
 </indexterm>

 <refmeta>
  <refentrytitle>ALTER DATABASE</refentrytitle>
  <manvolnum>7</manvolnum>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>ALTER DATABASE</refname>
  <refpurpose>change a database</refpurpose>
 </refnamediv>

 <refsynopsisdiv>
<synopsis>
ALTER DATABASE <replaceable class="parameter">name</replaceable> [ [ WITH ] <replaceable class="parameter">option</replaceable> [ ... ] ]

<phrase>where <replaceable class="parameter">option</replaceable> can be:</phrase>

    ALLOW_CONNECTIONS <replaceable class="parameter">allowconn</replaceable>
    CONNECTION LIMIT <replaceable class="parameter">connlimit</replaceable>
    IS_TEMPLATE <replaceable class="parameter">istemplate</replaceable>

ALTER DATABASE <replaceable class="parameter">name</replaceable> RENAME TO <replaceable>new_name</replaceable>

ALTER DATABASE <replaceable class="parameter">name</replaceable> OWNER TO { <replaceable>new_owner</replaceable> | CURRENT_ROLE | CURRENT_USER | SESSION_USER }

ALTER DATABASE <replaceable class="parameter">name</replaceable> SET TABLESPACE <replaceable class="parameter">new_tablespace</replaceable>

ALTER DATABASE <replaceable class="parameter">name</replaceable> REFRESH COLLATION VERSION

ALTER DATABASE <replaceable class="parameter">name</replaceable> SET <replaceable>configuration_parameter</replaceable> { TO | = } { <replaceable>value</replaceable> | DEFAULT }
ALTER DATABASE <replaceable class="parameter">name</replaceable> SET <replaceable>configuration_parameter</replaceable> FROM CURRENT
ALTER DATABASE <replaceable class="parameter">name</replaceable> RESET <replaceable>configuration_parameter</replaceable>
ALTER DATABASE <replaceable class="parameter">name</replaceable> RESET ALL
</synopsis>
 </refsynopsisdiv>

 <refsect1>
  <title>Description</title>

  <para>
   <command>ALTER DATABASE</command> changes the attributes
   of a database.
  </para>

  <para>
   The first form changes certain per-database settings.  (See below for
   details.)  Only the database owner or a superuser can change these settings.
  </para>

  <para>
   The second form changes the name of the database.  Only the database
   owner or a superuser can rename a database; non-superuser owners must
   also have the
   <literal>CREATEDB</literal> privilege.  The current database cannot
   be renamed.  (Connect to a different database if you need to do
   that.)
  </para>

  <para>
   The third form changes the owner of the database.
   To alter the owner, you must own the database and also be a direct or
   indirect member of the new owning role, and you must have the
   <literal>CREATEDB</literal> privilege.
   (Note that superusers have all these privileges automatically.)
  </para>

  <para>
   The fourth form changes the default tablespace of the database.
   Only the database owner or a superuser can do this; you must also have
   create privilege for the new tablespace.
   This command physically moves any tables or indexes in the database's old
   default tablespace to the new tablespace.  The new default tablespace
   must be empty for this database, and no one can be connected to
   the database.  Tables and indexes in non-default tablespaces are
   unaffected.
  </para>

  <para>
   The remaining forms change the session default for a run-time
   configuration variable for a <productname>PostgreSQL</productname>
   database. Whenever a new session is subsequently started in that
   database, the specified value becomes the session default value.
   The database-specific default overrides whatever setting is present
   in <filename>postgresql.conf</filename> or has been received from the
   <command>postgres</command> command line.  Only the database
   owner or a superuser can change the session defaults for a
   database.  Certain variables cannot be set this way, or can only be
   set by a superuser.
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

    <variablelist>
     <varlistentry>
      <term><replaceable class="parameter">name</replaceable></term>
      <listitem>
       <para>
        The name of the database whose attributes are to be altered.
       </para>
      </listitem>
     </varlistentry>

      <varlistentry>
       <term><replaceable class="parameter">allowconn</replaceable></term>
       <listitem>
        <para>
         If false then no one can connect to this database.
        </para>
       </listitem>
      </varlistentry>

      <varlistentry>
      <term><replaceable class="parameter">connlimit</replaceable></term>
      <listitem>
       <para>
        How many concurrent connections can be made
        to this database.  -1 means no limit.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
       <term><replaceable class="parameter">istemplate</replaceable></term>
       <listitem>
        <para>
         If true, then this database can be cloned by any user with <literal>CREATEDB</literal>
         privileges; if false, then only superusers or the owner of the
         database can clone it.
        </para>
       </listitem>
      </varlistentry>

   <varlistentry>
    <term><replaceable>new_name</replaceable></term>
    <listitem>
     <para>
      The new name of the database.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">new_owner</replaceable></term>
    <listitem>
     <para>
      The new owner of the database.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">new_tablespace</replaceable></term>
    <listitem>
     <para>
      The new default tablespace of the database.
     </para>

     <para>
      This form of the command cannot be executed inside a transaction block.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>REFRESH COLLATION VERSION</literal></term>
    <listitem>
     <para>
      Update the database collation version.  See <xref
      linkend="sql-altercollation-notes"/> for background.
     </para>
    </listitem>
   </varlistentry>

     <varlistentry>
      <term><replaceable>configuration_parameter</replaceable></term>
      <term><replaceable>value</replaceable></term>
      <listitem>
       <para>
        Set this database's session default for the specified configuration
        parameter to the given value.  If
        <replaceable>value</replaceable> is <literal>DEFAULT</literal>
        or, equivalently, <literal>RESET</literal> is used, the
        database-specific setting is removed, so the system-wide default
        setting will be inherited in new sessions.  Use <literal>RESET
        ALL</literal> to clear all database-specific settings.
        <literal>SET FROM CURRENT</literal> saves the session's current value of
        the parameter as the database-specific value.
       </para>

       <para>
        See <xref linkend="sql-set"/> and <xref linkend="runtime-config"/>
        for more information about allowed parameter names
        and values.
       </para>
      </listitem>
     </varlistentry>
  </variablelist>
 </refsect1>

 <refsect1>
  <title>Notes</title>

  <para>
   It is also possible to tie a session default to a specific role
   rather than to a database; see
   <xref linkend="sql-alterrole"/>.
   Role-specific settings override database-specific
   ones if there is a conflict.
  </para>
 </refsect1>

 <refsect1>
  <title>Examples</title>

  <para>
   To disable index scans by default in the database
   <literal>test</literal>:

<programlisting>
ALTER DATABASE test SET enable_indexscan TO off;
</programlisting></para>
 </refsect1>

 <refsect1>
  <title>Compatibility</title>

  <para>
   The <command>ALTER DATABASE</command> statement is a
   <productname>PostgreSQL</productname> extension.
  </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="sql-createdatabase"/></member>
   <member><xref linkend="sql-dropdatabase"/></member>
   <member><xref linkend="sql-set"/></member>
   <member><xref linkend="sql-createtablespace"/></member>
  </simplelist>
 </refsect1>
</refentry>