Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Update the NULL-handling document to show current behavior of OCELOT. (CVS 1046) |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
1d4c92c7325f69ee84b901a2de74a306 |
User & Date: | drh 2003-07-07 00:10:40.000 |
Context
2003-07-07
| ||
10:47 | A proported fix for ticket #374. (CVS 1047) (check-in: a49ee69e98 user: drh tags: trunk) | |
00:10 | Update the NULL-handling document to show current behavior of OCELOT. (CVS 1046) (check-in: 1d4c92c732 user: drh tags: trunk) | |
2003-07-06
| ||
17:22 | Correctly handle comparing an INTEGER PRIMARY KEY against a floating point number. Ticket #377. (CVS 1045) (check-in: 982aa3356b user: drh tags: trunk) | |
Changes
Changes to www/nulls.tcl.
1 2 3 | # # Run this script to generated a nulls.html output file # | | | 1 2 3 4 5 6 7 8 9 10 11 | # # Run this script to generated a nulls.html output file # set rcsid {$Id: nulls.tcl,v 1.3 2003/07/07 00:10:40 drh Exp $} puts {<html> <head> <title>NULL Handling In SQLite Versus Other Database Engines</title> </head> <body bgcolor="white"> <h1 align="center"> |
︙ | ︙ | |||
40 41 42 43 44 45 46 | SQLite was originally coded in such a way that the answer to all questions in the chart below would be "Yes". But the expriments run on other SQL engines showed that none of them worked this way. So SQLite was modified to work the same as Oracle, PostgreSQL, and DB2. This involved making NULLs indistinct for the purposes of the SELECT DISTINCT statement and for the UNION operator in a SELECT. NULLs are still distinct | | | > > > | > > > > > > | < < < | < < < < < < | 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 | SQLite was originally coded in such a way that the answer to all questions in the chart below would be "Yes". But the expriments run on other SQL engines showed that none of them worked this way. So SQLite was modified to work the same as Oracle, PostgreSQL, and DB2. This involved making NULLs indistinct for the purposes of the SELECT DISTINCT statement and for the UNION operator in a SELECT. NULLs are still distinct in a UNIQUE column. This seems somewhat arbitrary, but the desire to be compatible with other engines outweighted that objection. </p> <p> It is possible to make SQLite treat NULLs as distinct for the purposes of the SELECT DISTINCT and UNION. To do so, one should change the value of the NULL_ALWAYS_DISTINCT #define in the <tt>sqliteInt.h</tt> source file and recompile. </p> <p> The following table shows the results of the NULL handling experiments. </p> <table border=1 cellpadding=3 width="100%"> <tr><th>  </th> <th>SQLite</th> <th>PostgreSQL</th> <th>Oracle</th> <th>Informix</th> <th>DB2</th> <th>MS-SQL</th> <th>OCELOT</th> </tr> <tr><td>Adding anything to null gives null</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> </tr> <tr><td>Multiplying null by zero gives null</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> </tr> <tr><td>nulls are distinct in a UNIQUE column</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> </tr> <tr><td>nulls are distinct in SELECT DISTINCT</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> </tr> <tr><td>nulls are distinct in a UNION</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> </tr> <tr><td>"CASE WHEN null THEN 1 ELSE 0 END" is 0?</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> </tr> <tr><td>"null OR true" is true</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> </tr> <tr><td>"not (null AND false)" is true</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> </tr> </table> <table border=1 cellpadding=3 width="100%"> <tr><th>  </th> <th>MySQL</th> <th>Firebird</th> <th>SQL Anywhere</th> <th>Borland Interbase</th> </tr> <tr><td>Adding anything to null gives null</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> </tr> <tr><td>Multiplying null by zero gives null</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> </tr> <tr><td>nulls are distinct in a UNIQUE column</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#aaaad2">(Note 4)</td> <td valign="center" align="center" bgcolor="#aaaad2">(Note 4)</td> </tr> <tr><td>nulls are distinct in SELECT DISTINCT</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#aaaad2">(Note 1)</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> </tr> <tr><td>nulls are distinct in a UNION</td> <td valign="center" align="center" bgcolor="#aaaad2">(Note 3)</td> <td valign="center" align="center" bgcolor="#aaaad2">(Note 1)</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> </tr> <tr><td>"CASE WHEN null THEN 1 ELSE 0 END" is 0?</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#aaaad2">(Note 2)</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#aaaad2">(Note 5)</td> </tr> <tr><td>"null OR true" is true</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> </tr> <tr><td>"not (null AND false)" is true</td> <td valign="center" align="center" bgcolor="#c7a9a9">No</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> <td valign="center" align="center" bgcolor="#a9c7a9">Yes</td> </tr> </table> |
︙ | ︙ |