From: drh The sqlite_changes() API function returns the number of rows
that were inserted, deleted, or modified during the most recent
sqlite_exec() call. The number reported includes any changes
-that were later undo by a ROLLBACK or ABORT. But rows that are
+that were later undone by a ROLLBACK or ABORT. But rows that are
deleted because of a DROP TABLE are not counted. SQLite implements the command "DELETE FROM table" (without
@@ -425,7 +425,7 @@ is necessary, use "DELETE FROM table WHERE 1" instead. The sqlite_get_table() function is a wrapper around
sqlite_exec() that collects all the information from successive
-callbacks and write it into memory obtained from malloc(). This
+callbacks and writes it into memory obtained from malloc(). This
is a convenience function that allows the application to get the
entire result of a database query with a single function call.
As an example, consider the following query:
@@ -619,7 +619,7 @@ additional arguments are attached to the end of the function call. functions instead of sprintf(). First of all, with the SQLite printf routines, there is never a danger of overflowing a static buffer as there is with sprintf(). The SQLite -printf routines automatically allocate (and later free) +printf routines automatically allocate (and later frees) as much memory as is necessary to hold the SQL statements generated. diff --git a/www/datatypes.tcl b/www/datatypes.tcl index 5623d44cc9..b3db49c3ed 100644 --- a/www/datatypes.tcl +++ b/www/datatypes.tcl @@ -1,7 +1,7 @@ # # Run this script to generated a datatypes.html output file # -set rcsid {$Id: datatypes.tcl,v 1.2 2002/08/14 03:03:58 drh Exp $} +set rcsid {$Id: datatypes.tcl,v 1.3 2002/08/15 11:48:14 drh Exp $} puts { @@ -184,10 +184,70 @@ TEXTThe search for these strings in the type declaration is case insensitive, of course. If any of the above strings occur anywhere in the type -declaration, then the datatype of the column is text. Otherwise the -datatype is numeric. Note in particular that the datatype for columns +declaration, then the datatype of the column is text. Notice that +the type "VARCHAR" contains "CHAR" as a substring so it is considered +text.
+ +If none of the strings above occur anywhere in the type declaration, +then the datatype is numeric. Note in particular that the datatype for columns with an empty type declaration is numeric.
+ ++Consider the following two command sequences: +
+ ++ ++CREATE TABLE t1(a INTEGER UNIQUE); CREATE TABLE t2(b TEXT UNIQUE); +INSERT INTO t1 VALUES('0'); INSERT INTO t2 VALUES(0); +INSERT INTO t1 VALUES('0.0'); INSERT INTO t2 VALUES(0.0); +
In the sequence on the left, the second insert will fail. In this case, +the strings '0' and '0.0' are treated as numbers since they are being +inserted into a numeric column but 0==0.0 which violates the uniqueness +constraint. However, the second insert in the right-hand sequence works. In +this case, the constants 0 and 0.0 are treated a strings which means that +they are distinct.
+ +SQLite always converts numbers into double-precision (64-bit) floats +for comparison purposes. This means that a long sequence of digits that +differ only in digits of far to the right will compare equal if they +are in a numeric column but will compare unequal if they are in a text +column. We have:
+ ++ ++INSERT INTO t1 INSERT INTO t2 + VALUES('12345678901234567890'); VALUES(12345678901234567890); +INSERT INTO t1 INSERT INTO t2 + VALUES('12345678901234567891'); VALUES(12345678901234567891); +
As before, the second insert on the left will fail because the comparison +will convert both strings into floating-point number first and the only +difference in the strings is in the 20-th digit which exceeds the resolution +of a 64-bit float. In contrast, the second insert on the right will work +because in that case, the numbers being inserted are strings and are +compared using memcmp().
+ ++Numeric and text types make a difference for the DISTINCT keyword too: +
+ ++ ++CREATE TABLE t3(a INTEGER); CREATE TABLE t4(b TEXT); +INSERT INTO t3 VALUES('0'); INSERT INTO t4 VALUES(0); +INSERT INTO t3 VALUES('0.0'); INSERT INTO t4 VALUES(0.0); +SELECT DISTINCT * FROM t3; SELECT DISTINCT * FROM t4; +
+The SELECT statement on the left returns a single row since '0' and '0.0' +are treated as numbers and are therefore indistinct. But the SELECT +statement on the right returns two rows since 0 and 0.0 are treated +a strings which are different.
} puts { diff --git a/www/faq.tcl b/www/faq.tcl index d8447bd5cc..ecd7249159 100644 --- a/www/faq.tcl +++ b/www/faq.tcl @@ -1,7 +1,7 @@ # # Run this script to generated a faq.html output file # -set rcsid {$Id: faq.tcl,v 1.16 2002/08/14 12:56:56 drh Exp $} +set rcsid {$Id: faq.tcl,v 1.17 2002/08/15 11:48:14 drh Exp $} puts { @@ -79,6 +79,9 @@ faq {An exception to this rule is a column of type INTEGER PRIMARY KEY. Such columns must hold an integer. An attempt to put a non-integer value into an INTEGER PRIMARY KEY column will generate an error.
+ +There is a page on datatypes in SQLite + that explains this concept further.
} faq { @@ -88,65 +91,78 @@ faq { inserted into any column. You can put arbitrary length strings into integer columns, floating point numbers in boolean columns, or dates in character columns. The datatype you assign to a column in the - CREATE TABLE command is (mostly) ignored. Every column is able to hold + CREATE TABLE command does not restrict what data can be put into + that column. Every column is able to hold an arbitrary length string. (There is one exception: Columns of type INTEGER PRIMARY KEY may only hold an integer. An error will result if you try to put anything other than an integer into an INTEGER PRIMARY KEY column.) -Because SQLite ignores data types, you can omit the data type definition - from columns in CREATE TABLE statements. For example, instead of saying -
- You can save yourself a lot of typing and formatting by omitting the - data type declarations, like this: --CREATE TABLE t1( - f1 int, - f2 varchar(10), - f3 boolean -); -
-CREATE TABLE t1(f1,f2,f3); +The datatype does effect how values are compared, however. For + columns with a numeric type (such as "integer") any string that looks + like a number is treated as a number for comparison and sorting purposes. + Consider these two command sequences:
+ +- + ++CREATE TABLE t1(a INTEGER UNIQUE); CREATE TABLE t2(b TEXT UNIQUE); +INSERT INTO t1 VALUES('0'); INSERT INTO t2 VALUES(0); +INSERT INTO t1 VALUES('0.0'); INSERT INTO t2 VALUES(0.0);In the sequence on the left, the second insert will fail. In this case, + the strings '0' and '0.0' are treated as numbers since they are being + inserted into a numeric column and 0==0.0 which violates the uniqueness + constraint. But the second insert in the right-hand sequence works. In + this case, the constants 0 and 0.0 are treated a strings which means that + they are distinct.
+ +There is a page on datatypes in SQLite + that explains this concept further.
} faq { Why does SQLite think that the expression '0'=='00' is TRUE? } { -This is a consequence of SQLite being typeless. All data is stored - internally as a null-terminated string. There is no concept of - separate data types for strings and numbers.
- -When doing a comparison, SQLite looks at the string on both sides of - the comparison operator. If both strings look like pure numeric - values (with no extra punctuation or spacing) then the strings are - converted to floating point numbers using atof() and the results - are compared. The results of atof("0") and atof("00") - are both 0.0, so those two strings are considered to be equal.
- -If only one string in a comparison is a pure numeric, then that string - is assumed to be less than the other. Of neither string is a pure numeric, - then strcmp() is used for the comparison.
+As of version 2.7.0, it doesn't.
+ +But if one of the two values being compared is stored in a column that + has a numeric type, the the other value is treated as a number, not a + string and the result succeeds. For example:
+ ++ ++CREATE TABLE t3(a INTEGER, b TEXT); +INSERT INTO t3 VALUES(0,0); +SELECT count(*) FROM t3 WHERE a=='00'; +The SELECT in the above series of commands returns 1. The "a" column + is numeric so in the WHERE clause the string '00' is converted into a + number for comparison against "a". 0==00 so the test is true. Now + consider a different SELECT:
+ ++ ++SELECT count(*) FROM t3 WHERE b=='00'; +In this case the answer is 0. B is a text column so a text comparison + is done against '00'. '0'!='00' so the WHERE clause returns FALSE and + the count is zero.
+ +There is a page on datatypes in SQLite + that explains this concept further.
} faq { Why doesn't SQLite allow me to use '0' and '0.0' as the primary key on two different rows of the same table? } { -Every row much have a unique primary key. - But SQLite thinks that '0' and '0.0' are the +
Your primary key must have a numeric type. Change the datatype of + your primary key to TEXT and it should work.
+ +Every row must have a unique primary key. For a column with a + numeric type, SQLite thinks that '0' and '0.0' are the same value because they compare equal to one another numerically. (See the previous question.) Hence the values are not unique.
- -You can work around this issue in two ways:
--
} faq { diff --git a/www/lang.tcl b/www/lang.tcl index cc0099d76e..72a55ceee1 100644 --- a/www/lang.tcl +++ b/www/lang.tcl @@ -1,7 +1,7 @@ # # Run this Tcl script to generate the sqlite.html file. # -set rcsid {$Id: lang.tcl,v 1.42 2002/08/14 00:08:13 drh Exp $} +set rcsid {$Id: lang.tcl,v 1.43 2002/08/15 11:48:14 drh Exp $} puts { @@ -283,7 +283,7 @@ for use by the engine.- -
Remove the primary key clause from the CREATE TABLE.
- -
Prepend a space to the beginning of every value you use for - the primary key. The initial - space will mean that the entries are not pure numerics and hence - will be compared as strings using strcmp().
Each column definition is the name of the column followed by the datatype for that column, then one or more optional column constraints. SQLite is typeless. -The datatype for the column does not constraint what data may be put +The datatype for the column does not restrict what data may be put in that column. All information is stored as null-terminated strings. The UNIQUE constraint causes an index to be created on the specified