File: lang_altertable.html

package info (click to toggle)
sqlite3 3.8.7.1-1
  • links: PTS
  • area: main
  • in suites: jessie-kfreebsd
  • size: 39,012 kB
  • sloc: ansic: 150,070; sh: 20,920; tcl: 11,058; makefile: 1,290; yacc: 1,093; awk: 268
file content (421 lines) | stat: -rw-r--r-- 18,481 bytes parent folder | download | duplicates (2)
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
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01//EN" "http://www.w3.org/TR/html4/strict.dtd">
<html><head>
<meta http-equiv="content-type" content="text/html; charset=UTF-8">
<title>SQLite Query Language: ALTER TABLE</title>
<style type="text/css">
body {
    margin: auto;
    font-family: Verdana, sans-serif;
    padding: 8px 1%;
}

a { color: #044a64 }
a:visited { color: #734559 }

.logo { position:absolute; margin:3px; }
.tagline {
  float:right;
  text-align:right;
  font-style:italic;
  width:300px;
  margin:12px;
  margin-top:58px;
}

.menubar {
  clear: both;
  border-radius: 8px;
  background: #044a64;
  padding: 0px;
  margin: 0px;
  cell-spacing: 0px;
}    
.toolbar {
  text-align: center;
  line-height: 1.6em;
  margin: 0;
  padding: 0px 8px;
}
.toolbar a { color: white; text-decoration: none; padding: 6px 12px; }
.toolbar a:visited { color: white; }
.toolbar a:hover { color: #044a64; background: white; }

.content    { margin: 5%; }
.content dt { font-weight:bold; }
.content dd { margin-bottom: 25px; margin-left:20%; }
.content ul { padding:0px; padding-left: 15px; margin:0px; }

/* Things for "fancyformat" documents start here. */
.fancy img+p {font-style:italic}
.fancy .codeblock i { color: darkblue; }
.fancy h1,.fancy h2,.fancy h3,.fancy h4 {font-weight:normal;color:#044a64}
.fancy h2 { margin-left: 10px }
.fancy h3 { margin-left: 20px }
.fancy h4 { margin-left: 30px }
.fancy th {white-space:nowrap;text-align:left;border-bottom:solid 1px #444}
.fancy th, .fancy td {padding: 0.2em 1ex; vertical-align:top}
.fancy #toc a        { color: darkblue ; text-decoration: none }
.fancy .todo         { color: #AA3333 ; font-style : italic }
.fancy .todo:before  { content: 'TODO:' }
.fancy p.todo        { border: solid #AA3333 1px; padding: 1ex }
.fancy img { display:block; }
.fancy :link:hover, .fancy :visited:hover { background: wheat }
.fancy p,.fancy ul,.fancy ol { margin: 1em 5ex }
.fancy li p { margin: 1em 0 }
/* End of "fancyformat" specific rules. */

</style>
  
</head>
<body>
<div><!-- container div to satisfy validator -->

<a href="index.html">
<img class="logo" src="images/sqlite370_banner.gif" alt="SQLite Logo"
 border="0"></a>
<div><!-- IE hack to prevent disappearing logo--></div>
<div class="tagline">Small. Fast. Reliable.<br>Choose any three.</div>

<table width=100% class="menubar"><tr>
  <td width=100%>
  <div class="toolbar">
    <a href="about.html">About</a>
    <a href="sitemap.html">Sitemap</a>
    <a href="docs.html">Documentation</a>
    <a href="download.html">Download</a>
    <a href="copyright.html">License</a>
    <a href="news.html">News</a>
    <a href="support.html">Support</a>
  </div>
<script>
  gMsg = "Search SQLite Docs..."
  function entersearch() {
    var q = document.getElementById("q");
    if( q.value == gMsg ) { q.value = "" }
    q.style.color = "black"
    q.style.fontStyle = "normal"
  }
  function leavesearch() {
    var q = document.getElementById("q");
    if( q.value == "" ) { 
      q.value = gMsg
      q.style.color = "#044a64"
      q.style.fontStyle = "italic"
    }
  }
  function hideorshow(btn,obj){
    var x = document.getElementById(obj);
    var b = document.getElementById(btn);
    if( x.style.display!='none' ){
      x.style.display = 'none';
      b.innerHTML='show';
    }else{
      x.style.display = '';
      b.innerHTML='hide';
    }
    return false;
  }
</script>
<td>
    <div style="padding:0 1em 0px 0;white-space:nowrap">
    <form name=f method="GET" action="http://www.sqlite.org/search">
      <input id=q name=q type=text
       onfocus="entersearch()" onblur="leavesearch()" style="width:24ex;padding:1px 1ex; border:solid white 1px; font-size:0.9em ; font-style:italic;color:#044a64;" value="Search SQLite Docs...">
      <input type=submit value="Go" style="border:solid white 1px;background-color:#044a64;color:white;font-size:0.9em;padding:0 1ex">
    </form>
    </div>
  </table>

<div class=startsearch></div>
  
<h1 align="center">SQL As Understood By SQLite</h1><p><a href="lang.html">[Top]</a></p><h2>ALTER TABLE</h2><p><b><a href="syntax/alter-table-stmt.html">alter-table-stmt:</a></b>
<button id='x737' onclick='hideorshow("x737","x738")'>hide</button></p>
 <blockquote id='x738'>
 <img alt="syntax diagram alter-table-stmt" src="images/syntax/alter-table-stmt.gif" />
<p><b><a href="syntax/column-def.html">column-def:</a></b>
<button id='x739' onclick='hideorshow("x739","x740")'>show</button></p>
 <blockquote id='x740' style='display:none;'>
 <img alt="syntax diagram column-def" src="images/syntax/column-def.gif" />
<p><b><a href="syntax/column-constraint.html">column-constraint:</a></b>
<button id='x741' onclick='hideorshow("x741","x742")'>show</button></p>
 <blockquote id='x742' style='display:none;'>
 <img alt="syntax diagram column-constraint" src="images/syntax/column-constraint.gif" />
<p><b><a href="syntax/conflict-clause.html">conflict-clause:</a></b>
<button id='x743' onclick='hideorshow("x743","x744")'>show</button></p>
 <blockquote id='x744' style='display:none;'>
 <img alt="syntax diagram conflict-clause" src="images/syntax/conflict-clause.gif" />
</blockquote>
<p><b><a href="syntax/expr.html">expr:</a></b>
<button id='x745' onclick='hideorshow("x745","x746")'>show</button></p>
 <blockquote id='x746' style='display:none;'>
 <img alt="syntax diagram expr" src="images/syntax/expr.gif" />
<p><b><a href="syntax/raise-function.html">raise-function:</a></b>
<button id='x747' onclick='hideorshow("x747","x748")'>show</button></p>
 <blockquote id='x748' style='display:none;'>
 <img alt="syntax diagram raise-function" src="images/syntax/raise-function.gif" />
</blockquote>
<p><b><a href="syntax/select-stmt.html">select-stmt:</a></b>
<button id='x749' onclick='hideorshow("x749","x750")'>show</button></p>
 <blockquote id='x750' style='display:none;'>
 <img alt="syntax diagram select-stmt" src="images/syntax/select-stmt.gif" />
<p><b><a href="syntax/common-table-expression.html">common-table-expression:</a></b>
<button id='x751' onclick='hideorshow("x751","x752")'>show</button></p>
 <blockquote id='x752' style='display:none;'>
 <img alt="syntax diagram common-table-expression" src="images/syntax/common-table-expression.gif" />
</blockquote>
<p><b><a href="syntax/compound-operator.html">compound-operator:</a></b>
<button id='x753' onclick='hideorshow("x753","x754")'>show</button></p>
 <blockquote id='x754' style='display:none;'>
 <img alt="syntax diagram compound-operator" src="images/syntax/compound-operator.gif" />
</blockquote>
<p><b><a href="syntax/join-clause.html">join-clause:</a></b>
<button id='x755' onclick='hideorshow("x755","x756")'>show</button></p>
 <blockquote id='x756' style='display:none;'>
 <img alt="syntax diagram join-clause" src="images/syntax/join-clause.gif" />
<p><b><a href="syntax/join-constraint.html">join-constraint:</a></b>
<button id='x757' onclick='hideorshow("x757","x758")'>show</button></p>
 <blockquote id='x758' style='display:none;'>
 <img alt="syntax diagram join-constraint" src="images/syntax/join-constraint.gif" />
</blockquote>
<p><b><a href="syntax/join-operator.html">join-operator:</a></b>
<button id='x759' onclick='hideorshow("x759","x760")'>show</button></p>
 <blockquote id='x760' style='display:none;'>
 <img alt="syntax diagram join-operator" src="images/syntax/join-operator.gif" />
</blockquote>
</blockquote>
<p><b><a href="syntax/ordering-term.html">ordering-term:</a></b>
<button id='x761' onclick='hideorshow("x761","x762")'>show</button></p>
 <blockquote id='x762' style='display:none;'>
 <img alt="syntax diagram ordering-term" src="images/syntax/ordering-term.gif" />
</blockquote>
<p><b><a href="syntax/result-column.html">result-column:</a></b>
<button id='x763' onclick='hideorshow("x763","x764")'>show</button></p>
 <blockquote id='x764' style='display:none;'>
 <img alt="syntax diagram result-column" src="images/syntax/result-column.gif" />
</blockquote>
<p><b><a href="syntax/table-or-subquery.html">table-or-subquery:</a></b>
<button id='x765' onclick='hideorshow("x765","x766")'>show</button></p>
 <blockquote id='x766' style='display:none;'>
 <img alt="syntax diagram table-or-subquery" src="images/syntax/table-or-subquery.gif" />
</blockquote>
</blockquote>
</blockquote>
<p><b><a href="syntax/foreign-key-clause.html">foreign-key-clause:</a></b>
<button id='x767' onclick='hideorshow("x767","x768")'>show</button></p>
 <blockquote id='x768' style='display:none;'>
 <img alt="syntax diagram foreign-key-clause" src="images/syntax/foreign-key-clause.gif" />
</blockquote>
<p><b><a href="syntax/literal-value.html">literal-value:</a></b>
<button id='x769' onclick='hideorshow("x769","x770")'>show</button></p>
 <blockquote id='x770' style='display:none;'>
 <img alt="syntax diagram literal-value" src="images/syntax/literal-value.gif" />
</blockquote>
<p><b><a href="syntax/signed-number.html">signed-number:</a></b>
<button id='x771' onclick='hideorshow("x771","x772")'>show</button></p>
 <blockquote id='x772' style='display:none;'>
 <img alt="syntax diagram signed-number" src="images/syntax/signed-number.gif" />
</blockquote>
</blockquote>
<p><b><a href="syntax/type-name.html">type-name:</a></b>
<button id='x773' onclick='hideorshow("x773","x774")'>show</button></p>
 <blockquote id='x774' style='display:none;'>
 <img alt="syntax diagram type-name" src="images/syntax/type-name.gif" />
<p><b><a href="syntax/signed-number.html">signed-number:</a></b>
<button id='x775' onclick='hideorshow("x775","x776")'>show</button></p>
 <blockquote id='x776' style='display:none;'>
 <img alt="syntax diagram signed-number" src="images/syntax/signed-number.gif" />
</blockquote>
</blockquote>
</blockquote>
</blockquote>


<p>SQLite supports a limited subset of ALTER TABLE.
The ALTER TABLE command in SQLite allows the user to rename a table
or to add a new column to an existing table.
</p>

<p> The RENAME TO syntax is used to rename the table identified by 
<i>&#91;database-name.&#93;table-name</i> to <i>new-table-name</i>.
This command 
cannot be used to move a table between attached databases, only to rename 
a table within the same database.</p>

<p> If the table being renamed has triggers or indices, then these remain
attached to the table after it has been renamed.  However, if there are
any view definitions, or statements executed by triggers that refer to
the table being renamed, these are not automatically modified to use the new
table name. If this is required, the triggers or view definitions must be
dropped and recreated to use the new table name by hand.
</p>

<blockquote><table border="1" cellpadding="10">
<tr><td>
<em>Important Note:</em>
The 'ALTER TABLE ... RENAME TO ...' command does not update action
statements within triggers or SELECT statements within views.
If the table being renamed is referenced from within triggers or views,
then those triggers and views must be dropped and recreated separately
by the application.
</td></tr></table>
</blockquote>

<p>If <a href="foreignkeys.html">foreign key constraints</a> are 
<a href="pragma.html#pragma_foreign_keys">enabled</a> when a table is renamed, then any
<a href="syntax/foreign-key-clause.html">REFERENCES clauses</a> in any table (either the
table being renamed or some other table)
that refer to the table being renamed are modified to refer 
to the renamed table by its new name.

<p> The ADD COLUMN syntax
is used to add a new column to an existing table.
The new column is always appended to the end of the list of existing columns.
The <a href="syntax/column-def.html">column-def</a> rule defines the characteristics of the new column.
The new column may take any of the forms permissible in a <a href="lang_createtable.html">CREATE TABLE</a>
statement, with the following restrictions:
<ul>
<li>The column may not have a PRIMARY KEY or UNIQUE constraint.</li>
<li>The column may not have a default value of CURRENT_TIME, CURRENT_DATE, 
    CURRENT_TIMESTAMP, or an expression in parentheses.</li>
<li>If a NOT NULL constraint is specified, then the column must have a
    default value other than NULL.
<li>If <a href="foreignkeys.html">foreign key constraints</a> are <a href="pragma.html#pragma_foreign_keys">enabled</a> and
    a column with a <a href="syntax/foreign-key-clause.html">REFERENCES clause</a>
    is added, the column must have a default value of NULL.
</ul>

<p>Note also that when adding a <a href="lang_createtable.html#ckconst">CHECK constraint</a>, the CHECK constraint
is not tested against preexisting rows of the table.
This can result in a table that contains data that
is in violation of the CHECK constraint.  Future versions of SQLite might
change to validate CHECK constraints as they are added.</p>

<p> The execution time of the ALTER TABLE command is independent of
the amount of data in the table.  The ALTER TABLE command runs as quickly
on a table with 10 million rows as it does on a table with 1 row.
</p>

<p>After ADD COLUMN has been run on a database, that database will not
be readable by SQLite version 3.1.3 and earlier.</p>

<a name="otheralter"></a>

<h3>Making Other Kinds Of Table Schema Changes</h3>

<p> The only schema altering commands directly supported by SQLite are the
"rename table" and "add column" commands shown above.  However, applications
can make other arbitrary changes to the format of a table using a simple
sequence of operations.
The steps to make arbitrary changes to the schema design of some table X
are as follows:

<ol>
<li><p>
Remember the format of all indexes and triggers associated with table X.
This information will be needed in step 7 below.  One way to do this is
to run a query like the following:
SELECT type, sql FROM sqlite_master WHERE tbl_name='X'.

<li><p>
Use <a href="lang_createtable.html">CREATE TABLE</a> to construct a new table "new_X" that is in the desired
revised format of table X.  Make sure that the name "new_X" does not collide
with any existing table name, of course.

<li><p>
Transfer content from X into new_X using a statement
like: INSERT INTO new_X SELECT ... FROM X.

<li><p>
If foreign key constraints are enabled,
disable them using <a href="pragma.html#pragma_foreign_keys">PRAGMA foreign_keys=OFF</a>.

<li><p>
Drop the old table X:  <a href="lang_droptable.html">DROP TABLE X</a>.

<li><p>
Change the name of new_X to X using: ALTER TABLE new_X RENAME TO X.

<li><p>
Use <a href="lang_createindex.html">CREATE INDEX</a> and <a href="lang_createtrigger.html">CREATE TRIGGER</a> to reconstruct indexes and triggers
associated with table X.  Perhaps use the old format of the triggers and
indexes saved from step 1 above as a guide, making changes as appropriate
for the alteration.

<li><p>
If foreign key constraints were originally enabled (prior to
step 4) then run <a href="pragma.html#pragma_foreign_key_check">PRAGMA foreign_key_check</a> to verify that the schema
change did not break any foreign key constraints, and run
<a href="pragma.html#pragma_foreign_keys">PRAGMA foreign_keys=ON</a> to re-enable foreign key
constraints.

<li><p>If any views refer to table X in a way that is affected by the
schema change, then drop those views using <a href="lang_dropview.html">DROP VIEW</a> and recreate them
with whatever changes are necessary to accommodate the schema change
using <a href="lang_createview.html">CREATE VIEW</a>.

</ol>

<p>The procedure above is completely general and will work even if the
schema change causes the information stored in the table to change.
So the full procedure above is appropriate for dropping a column,
changing the order of columns, adding or removing a UNIQUE constraint
or PRIMARY KEY, adding CHECK or FOREIGN KEY or NOT NULL constraints,
or changing the datatype for a column, for example.  However, a simpler
and faster procedure can optionally be used for
some changes that do no affect the on-disk content in any way.
The following simpler procedure is appropriate for removing
CHECK or FOREIGN KEY or NOT NULL constraints,
renaming columns, or adding or removing or changing default values on
a column.

<ol>
<li><p> Run <a href="pragma.html#pragma_schema_version">PRAGMA schema_version</a> to determine the current schema
version number.  This number will be needed for step 5 below.

<li><p> Activate schema editing using 
<a href="pragma.html#pragma_writable_schema">PRAGMA writable_schema=ON</a>.

<li><p> Run an <a href="lang_update.html">UPDATE</a> statement to change the definition of table X
in the <a href="fileformat2.html#sqlite_master">sqlite_master table</a>: 
UPDATE sqlite_master SET sql=... WHERE type='table' AND name='X';
<p><em>Caution:</em>  Making a change to the sqlite_master table like this will
render the database corrupt and unreadable if the change contains
a syntax error.  It is suggested that careful testing of the UPDATE
statement be done on a separate blank database prior to using it on
a database containing important data.

<li><p> If the change to table X also affects other tables or indexes or
triggers are views within schema, then run <a href="lang_update.html">UPDATE</a> statements to modify
those other tables indexes and views too.  For example, if the name of
a column changes, all FOREIGN KEY constraints, triggers, indexes, and
views that refer to that column must be modified.
<p><em>Caution:</em>  Once again, making changes to the sqlite_master 
table like this will render the database corrupt and unreadable if the 
change contains an error.  Carefully test of this entire procedure
on a separate test database prior to using it on
a database containing important data and/or make backup copies of
important databases prior to running this procedure.

<li><p> Increment the schema version number using
<a href="pragma.html#pragma_schema_version">PRAGMA schema_version=X</a> where X is one
more than the old schema version number found in step 2 above.

<li><p> Disable schema editing using 
<a href="pragma.html#pragma_writable_schema">PRAGMA writable_schema=OFF</a>.

<li><p> (Optional) Run <a href="pragma.html#pragma_integrity_check">PRAGMA integrity_check</a> to verify that the
schema changes did not damage the database.
</ol>

<p>It is important that both of the above procedures be run from within
a transaction to prevent other processes from accessing the database file
while the schema change is only partially complete.  

<p>If some future version of SQLite adds new ALTER TABLE capabilities, 
those capabilities will very likely use one of the two procedures
outlined above.