xref: /sqlite-3.40.0/test/without_rowid5.test (revision a32536b4)
1ef1bd970Sdrh# 2013-11-26
2ef1bd970Sdrh#
3ef1bd970Sdrh# The author disclaims copyright to this source code.  In place of
4ef1bd970Sdrh# a legal notice, here is a blessing:
5ef1bd970Sdrh#
6ef1bd970Sdrh#    May you do good and not evil.
7ef1bd970Sdrh#    May you find forgiveness for yourself and forgive others.
8ef1bd970Sdrh#    May you share freely, never taking more than you give.
9ef1bd970Sdrh#
10ef1bd970Sdrh#***********************************************************************
11ef1bd970Sdrh#
12ef1bd970Sdrh# Requirements testing for WITHOUT ROWID tables.
13ef1bd970Sdrh#
14ef1bd970Sdrh
15ef1bd970Sdrhset testdir [file dirname $argv0]
16ef1bd970Sdrhsource $testdir/tester.tcl
17ef1bd970Sdrh
18*a32536b4Sdanifcapable !incrblob {
19*a32536b4Sdan  finish_test
20*a32536b4Sdan  return
21*a32536b4Sdan}
22ef1bd970Sdrh
23ef1bd970Sdrh# EVIDENCE-OF: R-36924-43758 By default, every row in SQLite has a
24ef1bd970Sdrh# special column, usually called the "rowid", that uniquely identifies
25ef1bd970Sdrh# that row within the table.
26ef1bd970Sdrh#
27ef1bd970Sdrh# EVIDENCE-OF: R-32341-39358 However if the phrase "WITHOUT ROWID" is
28ef1bd970Sdrh# added to the end of a CREATE TABLE statement, then the special "rowid"
29ef1bd970Sdrh# column is omitted.
30ef1bd970Sdrh#
31ef1bd970Sdrhdo_execsql_test without_rowid5-1.1 {
32ef1bd970Sdrh  CREATE TABLE t1(a PRIMARY KEY,b,c);
33ef1bd970Sdrh  CREATE TABLE t1w(a PRIMARY KEY,b,c) WITHOUT ROWID;
34ef1bd970Sdrh  INSERT INTO t1 VALUES(1565,681,1148),(1429,1190,1619),(425,358,1306);
35ef1bd970Sdrh  INSERT INTO t1w SELECT a,b,c FROM t1;
36ef1bd970Sdrh  SELECT rowid, _rowid_, oid FROM t1 ORDER BY a DESC;
37ef1bd970Sdrh} {1 1 1 2 2 2 3 3 3}
38ef1bd970Sdrhdo_catchsql_test without_rowid5-1.2 {
39ef1bd970Sdrh  SELECT rowid FROM t1w;
40ef1bd970Sdrh} {1 {no such column: rowid}}
41ef1bd970Sdrhdo_catchsql_test without_rowid5-1.3 {
42ef1bd970Sdrh  SELECT _rowid_ FROM t1w;
43ef1bd970Sdrh} {1 {no such column: _rowid_}}
44ef1bd970Sdrhdo_catchsql_test without_rowid5-1.4 {
45ef1bd970Sdrh  SELECT oid FROM t1w;
46ef1bd970Sdrh} {1 {no such column: oid}}
47ef1bd970Sdrh
48ef1bd970Sdrh# EVIDENCE-OF: R-00217-01605 To create a WITHOUT ROWID table, simply add
49ef1bd970Sdrh# the keywords "WITHOUT ROWID" to the end of the CREATE TABLE statement.
50ef1bd970Sdrh# For example: CREATE TABLE IF NOT EXISTS wordcount( word TEXT PRIMARY
51ef1bd970Sdrh# KEY, cnt INTEGER ) WITHOUT ROWID;
52ef1bd970Sdrh#
53ef1bd970Sdrhdo_execsql_test without_rowid5-2.1 {
54ef1bd970Sdrh  CREATE TABLE IF NOT EXISTS wordcount(
55ef1bd970Sdrh    word TEXT PRIMARY KEY,
56ef1bd970Sdrh    cnt INTEGER
57ef1bd970Sdrh  ) WITHOUT ROWID;
58ef1bd970Sdrh  INSERT INTO wordcount VALUES('one',1);
59ef1bd970Sdrh} {}
60ef1bd970Sdrhdo_catchsql_test without_rowid5-2.2 {
61ef1bd970Sdrh  SELECT rowid FROM wordcount;
62ef1bd970Sdrh} {1 {no such column: rowid}}
63ef1bd970Sdrh
64ef1bd970Sdrh# EVIDENCE-OF: R-24770-17719 As with all SQL syntax, the case of the
65ef1bd970Sdrh# keywords does not matter. One can write "WITHOUT rowid" or "without
66ef1bd970Sdrh# rowid" or "WiThOuT rOwId" and it will mean the same thing.
67ef1bd970Sdrh#
68ef1bd970Sdrhdo_execsql_test without_rowid5-2.3 {
69ef1bd970Sdrh  CREATE TABLE IF NOT EXISTS wordcount_b(
70ef1bd970Sdrh    word TEXT PRIMARY KEY,
71ef1bd970Sdrh    cnt INTEGER
72ef1bd970Sdrh  ) WITHOUT rowid;
73ef1bd970Sdrh  INSERT INTO wordcount_b VALUES('one',1);
74ef1bd970Sdrh} {}
75ef1bd970Sdrhdo_catchsql_test without_rowid5-2.4 {
76ef1bd970Sdrh  SELECT rowid FROM wordcount_b;
77ef1bd970Sdrh} {1 {no such column: rowid}}
78ef1bd970Sdrhdo_execsql_test without_rowid5-2.5 {
79ef1bd970Sdrh  CREATE TABLE IF NOT EXISTS wordcount_c(
80ef1bd970Sdrh    word TEXT PRIMARY KEY,
81ef1bd970Sdrh    cnt INTEGER
82ef1bd970Sdrh  ) without rowid;
83ef1bd970Sdrh  INSERT INTO wordcount_c VALUES('one',1);
84ef1bd970Sdrh} {}
85ef1bd970Sdrhdo_catchsql_test without_rowid5-2.6 {
86ef1bd970Sdrh  SELECT rowid FROM wordcount_c;
87ef1bd970Sdrh} {1 {no such column: rowid}}
88ef1bd970Sdrhdo_execsql_test without_rowid5-2.7 {
89ef1bd970Sdrh  CREATE TABLE IF NOT EXISTS wordcount_d(
90ef1bd970Sdrh    word TEXT PRIMARY KEY,
91ef1bd970Sdrh    cnt INTEGER
92ef1bd970Sdrh  ) WITHOUT rowid;
93ef1bd970Sdrh  INSERT INTO wordcount_d VALUES('one',1);
94ef1bd970Sdrh} {}
95ef1bd970Sdrhdo_catchsql_test without_rowid5-2.8 {
96ef1bd970Sdrh  SELECT rowid FROM wordcount_d;
97ef1bd970Sdrh} {1 {no such column: rowid}}
98ef1bd970Sdrh
99ef1bd970Sdrh# EVIDENCE-OF: R-01418-51310 However, only "rowid" works as the keyword
100ef1bd970Sdrh# in the CREATE TABLE statement.
101ef1bd970Sdrh#
102ef1bd970Sdrhdo_catchsql_test without_rowid5-3.1 {
103ef1bd970Sdrh  CREATE TABLE IF NOT EXISTS error1(
104ef1bd970Sdrh    word TEXT PRIMARY KEY,
105ef1bd970Sdrh    cnt INTEGER
106ef1bd970Sdrh  ) WITHOUT _rowid_;
107ef1bd970Sdrh} {1 {unknown table option: _rowid_}}
108ef1bd970Sdrhdo_catchsql_test without_rowid5-3.2 {
109ef1bd970Sdrh  CREATE TABLE IF NOT EXISTS error2(
110ef1bd970Sdrh    word TEXT PRIMARY KEY,
111ef1bd970Sdrh    cnt INTEGER
112ef1bd970Sdrh  ) WITHOUT oid;
113ef1bd970Sdrh} {1 {unknown table option: oid}}
114ef1bd970Sdrh
115ef1bd970Sdrh# EVIDENCE-OF: R-58033-17334 An error is raised if a CREATE TABLE
116ef1bd970Sdrh# statement with the WITHOUT ROWID clause lacks a PRIMARY KEY.
117ef1bd970Sdrh#
118ef1bd970Sdrh# EVIDENCE-OF: R-63443-09418 Every WITHOUT ROWID table must have a
119ef1bd970Sdrh# PRIMARY KEY.
120ef1bd970Sdrh#
121ef1bd970Sdrh# EVIDENCE-OF: R-27966-31616 An attempt to create a WITHOUT ROWID table
122ef1bd970Sdrh# without a PRIMARY KEY results in an error.
123ef1bd970Sdrh#
124ef1bd970Sdrhdo_catchsql_test without_rowid5-4.1 {
125ef1bd970Sdrh  CREATE TABLE IF NOT EXISTS error3(
126ef1bd970Sdrh    word TEXT UNIQUE,
127ef1bd970Sdrh    cnt INTEGER
128ef1bd970Sdrh  ) WITHOUT ROWID;
129ef1bd970Sdrh} {1 {PRIMARY KEY missing on table error3}}
130ef1bd970Sdrh
131ef1bd970Sdrh# EVIDENCE-OF: R-48230-36247 The special behaviors associated "INTEGER
132ef1bd970Sdrh# PRIMARY KEY" do not apply on WITHOUT ROWID tables.
133ef1bd970Sdrh#
134ef1bd970Sdrhdo_execsql_test without_rowid5-5.1 {
135ef1bd970Sdrh  CREATE TABLE ipk(key INTEGER PRIMARY KEY, val TEXT) WITHOUT ROWID;
136ef1bd970Sdrh  INSERT INTO ipk VALUES('rival','bonus'); -- ok to insert non-integer key
137ef1bd970Sdrh  SELECT * FROM ipk;
138ef1bd970Sdrh} {rival bonus}
139dc0b1f1cSdrhdo_catchsql_test without_rowid5-5.2a {
140dc0b1f1cSdrh  BEGIN;
141ef1bd970Sdrh  INSERT INTO ipk VALUES(NULL,'sample'); -- no automatic generation of keys
142ef1bd970Sdrh} {1 {NOT NULL constraint failed: ipk.key}}
143dc0b1f1cSdrhdo_execsql_test without_rowid5-5.2b {
144dc0b1f1cSdrh  ROLLBACK;
145dc0b1f1cSdrh} {}
146ef1bd970Sdrh
147ef1bd970Sdrh# EVIDENCE-OF: R-33142-02092 AUTOINCREMENT does not work on WITHOUT
148ef1bd970Sdrh# ROWID tables.
149ef1bd970Sdrh#
150ef1bd970Sdrh# EVIDENCE-OF: R-53084-07740 An error is raised if the "AUTOINCREMENT"
151ef1bd970Sdrh# keyword is used in the CREATE TABLE statement for a WITHOUT ROWID
152ef1bd970Sdrh# table.
153ef1bd970Sdrh#
154ef1bd970Sdrhdo_catchsql_test without_rowid5-5.3 {
155ef1bd970Sdrh  CREATE TABLE ipk2(key INTEGER PRIMARY KEY AUTOINCREMENT, val TEXT)WITHOUT ROWID;
156ef1bd970Sdrh} {1 {AUTOINCREMENT not allowed on WITHOUT ROWID tables}}
157ef1bd970Sdrh
158ef1bd970Sdrh# EVIDENCE-OF: R-27831-00579 NOT NULL is enforced on every column of the
159ef1bd970Sdrh# PRIMARY KEY in a WITHOUT ROWID table.
160ef1bd970Sdrh#
161ef1bd970Sdrh# EVIDENCE-OF: R-29781-51289 So, ordinary rowid tables in SQLite violate
162ef1bd970Sdrh# the SQL standard and allow NULL values in PRIMARY KEY fields.
163ef1bd970Sdrh#
164ef1bd970Sdrh# EVIDENCE-OF: R-27472-62612 But WITHOUT ROWID tables do follow the
165ef1bd970Sdrh# standard and will throw an error on any attempt to insert a NULL into
166ef1bd970Sdrh# a PRIMARY KEY column.
167ef1bd970Sdrh#
168ef1bd970Sdrhdo_execsql_test without_rowid5-5.4 {
169ef1bd970Sdrh  CREATE TABLE nn(a, b, c, d, e, PRIMARY KEY(c,a,e));
170ef1bd970Sdrh  CREATE TABLE nnw(a, b, c, d, e, PRIMARY KEY(c,a,e)) WITHOUT ROWID;
171ef1bd970Sdrh  INSERT INTO nn VALUES(1,2,3,4,5);
172ef1bd970Sdrh  INSERT INTO nnw VALUES(1,2,3,4,5);
173ef1bd970Sdrh} {}
174ef1bd970Sdrhdo_execsql_test without_rowid5-5.5 {
175ef1bd970Sdrh  INSERT INTO nn VALUES(NULL, 3,4,5,6);
176ef1bd970Sdrh  INSERT INTO nn VALUES(3,4,NULL,7,8);
177ef1bd970Sdrh  INSERT INTO nn VALUES(4,5,6,7,NULL);
178ef1bd970Sdrh  SELECT count(*) FROM nn;
179ef1bd970Sdrh} {4}
180ef1bd970Sdrhdo_catchsql_test without_rowid5-5.6 {
181ef1bd970Sdrh  INSERT INTO nnw VALUES(NULL, 3,4,5,6);
182ef1bd970Sdrh} {1 {NOT NULL constraint failed: nnw.a}}
183ef1bd970Sdrhdo_catchsql_test without_rowid5-5.7 {
184ef1bd970Sdrh  INSERT INTO nnw VALUES(3,4,NULL,7,8)
185ef1bd970Sdrh} {1 {NOT NULL constraint failed: nnw.c}}
186ef1bd970Sdrhdo_catchsql_test without_rowid5-5.8 {
187ef1bd970Sdrh  INSERT INTO nnw VALUES(4,5,6,7,NULL)
188ef1bd970Sdrh} {1 {NOT NULL constraint failed: nnw.e}}
189ef1bd970Sdrhdo_execsql_test without_rowid5-5.9 {
190ef1bd970Sdrh  SELECT count(*) FROM nnw;
191ef1bd970Sdrh} {1}
192ef1bd970Sdrh
193fd46ec64Sdrh# Ticket f2be158c57aaa8c6 (2021-08-18)
194fd46ec64Sdrh# NOT NULL ON CONFLICT clauses work on WITHOUT ROWID tables now.
195fd46ec64Sdrh#
196fd46ec64Sdrhdo_test without_rowid5-5.100 {
197fd46ec64Sdrh  db eval {
198fd46ec64Sdrh    DROP TABLE IF EXISTS t5;
199fd46ec64Sdrh    CREATE TABLE t5(
200fd46ec64Sdrh      a INT NOT NULL ON CONFLICT ROLLBACK,
201fd46ec64Sdrh      b TEXT,
202fd46ec64Sdrh      c TEXT,
203fd46ec64Sdrh      PRIMARY KEY(a,b)
204fd46ec64Sdrh    ) WITHOUT ROWID;
205fd46ec64Sdrh    BEGIN;
206fd46ec64Sdrh    INSERT INTO t5(a,b,c) VALUES(1,2,3);
207fd46ec64Sdrh  }
208fd46ec64Sdrh  catch {db eval {INSERT INTO t5(a,b,c) VALUES(NULL,6,7);}}
209fd46ec64Sdrh  db eval {
210fd46ec64Sdrh    SELECT * FROM t5;
211fd46ec64Sdrh  }
212fd46ec64Sdrh} {}
213fd46ec64Sdrhdo_test without_rowid5-5.101 {
214fd46ec64Sdrh  db eval {
215fd46ec64Sdrh    DROP TABLE IF EXISTS t5;
216fd46ec64Sdrh    CREATE TABLE t5(
217fd46ec64Sdrh      a INT NOT NULL ON CONFLICT ABORT,
218fd46ec64Sdrh      b TEXT,
219fd46ec64Sdrh      c TEXT,
220fd46ec64Sdrh      PRIMARY KEY(a,b)
221fd46ec64Sdrh    ) WITHOUT ROWID;
222fd46ec64Sdrh    BEGIN;
223fd46ec64Sdrh    INSERT INTO t5(a,b,c) VALUES(1,2,3);
224fd46ec64Sdrh  }
225fd46ec64Sdrh  catch {db eval {INSERT INTO t5(a,b,c) VALUES(NULL,6,7);}}
226fd46ec64Sdrh  db eval {
227fd46ec64Sdrh    COMMIT;
228fd46ec64Sdrh    SELECT * FROM t5;
229fd46ec64Sdrh  }
230fd46ec64Sdrh} {1 2 3}
231fd46ec64Sdrhdo_test without_rowid5-5.102 {
232fd46ec64Sdrh  db eval {
233fd46ec64Sdrh    DROP TABLE IF EXISTS t5;
234fd46ec64Sdrh    CREATE TABLE t5(
235fd46ec64Sdrh      a INT NOT NULL ON CONFLICT FAIL,
236fd46ec64Sdrh      b TEXT,
237fd46ec64Sdrh      c TEXT,
238fd46ec64Sdrh      PRIMARY KEY(a,b)
239fd46ec64Sdrh    ) WITHOUT ROWID;
240fd46ec64Sdrh  }
241fd46ec64Sdrh  catch {db eval {INSERT INTO t5(a,b,c) VALUES(1,2,3),(NULL,4,5),(6,7,8);}}
242fd46ec64Sdrh  db eval {
243fd46ec64Sdrh    SELECT * FROM t5;
244fd46ec64Sdrh  }
245fd46ec64Sdrh} {1 2 3}
246fd46ec64Sdrhdo_test without_rowid5-5.103 {
247fd46ec64Sdrh  db eval {
248fd46ec64Sdrh    DROP TABLE IF EXISTS t5;
249fd46ec64Sdrh    CREATE TABLE t5(
250fd46ec64Sdrh      a INT NOT NULL ON CONFLICT IGNORE,
251fd46ec64Sdrh      b TEXT,
252fd46ec64Sdrh      c TEXT,
253fd46ec64Sdrh      PRIMARY KEY(a,b)
254fd46ec64Sdrh    ) WITHOUT ROWID;
255fd46ec64Sdrh    INSERT INTO t5(a,b,c) VALUES(1,2,3),(NULL,4,5),(6,7,8);
256fd46ec64Sdrh    SELECT * FROM t5;
257fd46ec64Sdrh  }
258fd46ec64Sdrh} {1 2 3 6 7 8}
259fd46ec64Sdrhdo_test without_rowid5-5.104 {
260fd46ec64Sdrh  db eval {
261fd46ec64Sdrh    DROP TABLE IF EXISTS t5;
262fd46ec64Sdrh    CREATE TABLE t5(
263fd46ec64Sdrh      a INT NOT NULL ON CONFLICT REPLACE DEFAULT 3,
264fd46ec64Sdrh      b TEXT,
265fd46ec64Sdrh      c TEXT,
266fd46ec64Sdrh      PRIMARY KEY(a,b)
267fd46ec64Sdrh    ) WITHOUT ROWID;
268fd46ec64Sdrh    INSERT INTO t5(a,b,c) VALUES(1,2,3),(NULL,4,5),(6,7,8);
269fd46ec64Sdrh    SELECT * FROM t5;
270fd46ec64Sdrh  }
271fd46ec64Sdrh} {1 2 3 3 4 5 6 7 8}
272fd46ec64Sdrh
273fd46ec64Sdrh
274ef1bd970Sdrh# EVIDENCE-OF: R-12643-30541 The incremental blob I/O mechanism does not
275ef1bd970Sdrh# work for WITHOUT ROWID tables.
276ef1bd970Sdrh#
277b391b944Sdan# EVIDENCE-OF: R-40134-30296 Table zTable is a WITHOUT ROWID table
278ef1bd970Sdrh#
279ef1bd970Sdrhdo_execsql_test without_rowid5-6.1 {
280ef1bd970Sdrh  CREATE TABLE b1(a INTEGER PRIMARY KEY, b BLOB) WITHOUT ROWID;
281ef1bd970Sdrh  INSERT INTO b1 VALUES(1,x'0102030405060708090a0b0c0d0e0f');
282ef1bd970Sdrh} {}
283ef1bd970Sdrhdo_test without_rowid5-6.2 {
284ef1bd970Sdrh  set rc [catch {db incrblob b1 b 1} msg]
285ef1bd970Sdrh  lappend rc $msg
286ef1bd970Sdrh} {1 {cannot open table without rowid: b1}}
287ef1bd970Sdrh
288ef1bd970Sdrh
289ef1bd970Sdrhfinish_test
290