lang_expr.html 13 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315
  1. <!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01//EN" "http://www.w3.org/TR/html4/strict.dtd">
  2. <html><head>
  3. <title>SQLite Query Language: expression</title>
  4. <style type="text/css">
  5. body {
  6. margin: auto;
  7. font-family: Verdana, sans-serif;
  8. padding: 8px 1%;
  9. }
  10. a { color: #45735f }
  11. a:visited { color: #734559 }
  12. .logo { position:absolute; margin:3px; }
  13. .tagline {
  14. float:right;
  15. text-align:right;
  16. font-style:italic;
  17. width:240px;
  18. margin:12px;
  19. margin-top:58px;
  20. }
  21. .toolbar {
  22. font-variant: small-caps;
  23. text-align: center;
  24. line-height: 1.6em;
  25. margin: 0;
  26. padding:1px 8px;
  27. }
  28. .toolbar a { color: white; text-decoration: none; padding: 6px 12px; }
  29. .toolbar a:visited { color: white; }
  30. .toolbar a:hover { color: #80a796; background: white; }
  31. .content { margin: 5%; }
  32. .content dt { font-weight:bold; }
  33. .content dd { margin-bottom: 25px; margin-left:20%; }
  34. .content ul { padding:0px; padding-left: 15px; margin:0px; }
  35. /* rounded corners */
  36. .se { background: url(images/se.png) 100% 100% no-repeat #80a796}
  37. .sw { background: url(images/sw.png) 0% 100% no-repeat }
  38. .ne { background: url(images/ne.png) 100% 0% no-repeat }
  39. .nw { background: url(images/nw.png) 0% 0% no-repeat }
  40. </style>
  41. <meta http-equiv="content-type" content="text/html; charset=UTF-8">
  42. </head>
  43. <body>
  44. <div><!-- container div to satisfy validator -->
  45. <a href="lang.html">
  46. <h2 align="center">SQL As Understood By SQLite</h2></a><h1>expression</h1><h4><a href="syntaxdiagrams.html#expr">expr:</a></h4><blockquote> <img alt="syntax diagram expr" src="images/syntax/expr.gif"></img> </blockquote>
  47. <h4><a href="syntaxdiagrams.html#literal-value">literal-value:</a></h4><blockquote> <img alt="syntax diagram literal-value" src="images/syntax/literal-value.gif"></img> </blockquote>
  48. <h4><a href="syntaxdiagrams.html#signed-number">signed-number:</a></h4><blockquote> <img alt="syntax diagram signed-number" src="images/syntax/signed-number.gif"></img> </blockquote>
  49. <h4><a href="syntaxdiagrams.html#raise-function">raise-function:</a></h4><blockquote> <img alt="syntax diagram raise-function" src="images/syntax/raise-function.gif"></img> </blockquote>
  50. <p>This section is different from the others. Most other sections of
  51. this document talks about a particular SQL command. This section does
  52. not talk about a standalone command but about "expressions" which are
  53. subcomponents of most other commands.</p>
  54. <a name="binaryops"></a>
  55. <h3>Operators</h3>
  56. <p>SQLite understands the following binary operators, in order from
  57. highest to lowest precedence:</p>
  58. <blockquote><pre>
  59. <font color="#2c2cf0"><big>||
  60. * / %
  61. + -
  62. &lt;&lt; &gt;&gt; &amp; |
  63. &lt; &lt;= &gt; &gt;=
  64. = == != &lt;&gt; </big>IS IN LIKE GLOB MATCH REGEXP
  65. AND
  66. OR</font>
  67. </pre></blockquote>
  68. <p>Supported unary prefix operators are these:</p>
  69. <blockquote><pre>
  70. <font color="#2c2cf0"><big>- + ~ NOT</big></font>
  71. </pre></blockquote>
  72. <p>The COLLATE operator can be thought of as a unary postfix
  73. operator. The COLLATE operator has the highest precedence.
  74. It always binds more tightly than any prefix unary operator or
  75. any binary operator.</p>
  76. <p>The unary operator <font color="#2c2cf0"><big>+</big></font> is a no-op. It can be applied
  77. to strings, numbers, or blobs and it always gives as its result the
  78. value of the operand.</p>
  79. <p>Note that there are two variations of the equals and not equals
  80. operators. Equals can be either
  81. <font color="#2c2cf0"><big>=</big></font> or <font color="#2c2cf0"><big>==</big></font>.
  82. The non-equals operator can be either
  83. <font color="#2c2cf0"><big>!=</big></font> or <font color="#2c2cf0"><big>&lt;&gt;</big></font>.
  84. The <font color="#2c2cf0"><big>||</big></font> operator is "concatenate" - it joins together
  85. the two strings of its operands.
  86. The operator <font color="#2c2cf0"><big>%</big></font> outputs the remainder of its left
  87. operand modulo its right operand.</p>
  88. <p>The result of any binary operator is a numeric value, except
  89. for the <font color="#2c2cf0"><big>||</big></font> concatenation operator which gives a string
  90. result.</p><a name="isisnot"></a>
  91. <p>The <font color="#2c2cf0"><big>IS</big></font> and <font color="#2c2cf0"><big>IS NOT</big></font> operators work
  92. like <font color="#2c2cf0"><big>=</big></font> and <font color="#2c2cf0"><big>!=</big></font> except that NULL values compare
  93. equal to one another. <font color="#2c2cf0"><big>IS</big></font> and <font color="#2c2cf0"><big>IS NOT</big></font>
  94. have the same precedence as <font color="#2c2cf0"><big>=</big></font>.<a name="litvalue"></a>
  95. <h3>Literal Values</h3>
  96. <p>
  97. A literal value is a constant of some kind.
  98. Literal values may be integers, floating point numbers, strings,
  99. BLOBs, or NULLs.
  100. Scientific notation is supported for floating point literal values.
  101. The "." character is always used
  102. as the decimal point even if the locale setting specifies "," for
  103. this role - the use of "," for the decimal point would result in
  104. syntactic ambiguity. A string constant is formed by enclosing the
  105. string in single quotes ('). A single quote within the string can
  106. be encoded by putting two single quotes in a row - as in Pascal.
  107. C-style escapes using the backslash character are not supported because
  108. they are not standard SQL.
  109. BLOB literals are string literals containing hexadecimal data and
  110. preceded by a single "x" or "X" character. For example:</p>
  111. <blockquote><pre>
  112. X'53514C697465'
  113. </pre></blockquote>
  114. <p>
  115. A literal value can also be the token "NULL".
  116. </p>
  117. <a name="varparam"></a>
  118. <h3>Parameters</h3>
  119. <p>
  120. A "variable" or "parameter" token
  121. specifies a placeholder in the expression for a literal
  122. value that is filled in at runtime using the
  123. Bind() APIs.
  124. Parameters can take several forms:
  125. </p
  126. <blockquote>
  127. <table>
  128. <tr>
  129. <td align="right" valign="top"><b>?</b><i>NNN</i></td><td width="20"></td>
  130. <td>A question mark followed by a number <i>NNN</i> holds a spot for the
  131. NNN-th parameter. NNN must be between 1 and SQLITE_MAX_VARIABLE_NUMBER.</td>
  132. </tr>
  133. <tr>
  134. <td align="right" valign="top"><b>?</b></td><td width="20"></td>
  135. <td>A question mark that is not followed by a number holds a spot for
  136. the next unused parameter.</td>
  137. </tr>
  138. <tr>
  139. <td align="right" valign="top"><b>:</b><i>AAAA</i></td><td width="20"></td>
  140. <td>A colon followed by an identifier name holds a spot for a named
  141. parameter with the name AAAA. Named parameters are also numbered.
  142. The number assigned is the next unused number. To avoid confusion,
  143. it is best to avoid mixing named and numbered parameters.</td>
  144. </tr>
  145. <tr>
  146. <td align="right" valign="top"><b>@</b><i>AAAA</i></td><td width="20"></td>
  147. <td>An "at" sign works exactly like a colon.</td>
  148. </tr>
  149. <tr>
  150. <td align="right" valign="top"><b>$</b><i>AAAA</i></td><td width="20"></td>
  151. <td>A dollar-sign followed by an identifier name also holds a spot for a named
  152. parameter with the name AAAA. The identifier name in this case can include
  153. one or more occurances of "::" and a suffix enclosed in "(...)" containing
  154. any text at all. This syntax is the form of a variable name in the Tcl
  155. programming language.</td>
  156. </tr>
  157. </table>
  158. </blockquote>
  159. <p>Parameters that are not assigned values using
  160. Bind() are treated
  161. as NULL.</p>
  162. <a name="like"></a>
  163. <h3>The LIKE and GLOB operators</h3>
  164. <p>The LIKE operator does a pattern matching comparison. The operand
  165. to the right contains the pattern, the left hand operand contains the
  166. string to match against the pattern.
  167. A percent symbol ("%") in the pattern matches any
  168. sequence of zero or more characters in the string. An underscore
  169. ("_") in the pattern matches any single character in the
  170. string. Any other character matches itself or it's lower/upper case
  171. equivalent (i.e. case-insensitive matching). (A bug: SQLite only
  172. understands upper/lower case for ASCII characters. The
  173. LIKE operator is case sensitive for unicode characters that are beyond
  174. the ASCII range. For example, the expression <b>'a'&nbsp;LIKE&nbsp;'A'</b>
  175. is TRUE but <b>'&aelig;'&nbsp;LIKE&nbsp;'&AElig;'</b> is FALSE.).</p>
  176. <p>If the optional ESCAPE clause is present, then the expression
  177. following the ESCAPE keyword must evaluate to a string consisting of
  178. a single character. This character may be used in the LIKE pattern
  179. to include literal percent or underscore characters. The escape
  180. character followed by a percent symbol, underscore or itself matches a
  181. literal percent symbol, underscore or escape character in the string,
  182. respectively.
  183. <p>The infix LIKE operator is implemented by calling the
  184. application-defined SQL functions <a href="lang_corefunc.html#like">like(<i>Y</i>,<i>X</i>)</a> or
  185. <a href="lang_corefunc.html#like">like(<i>Y</i>,<i>X</i>,<i>Z</i>)</a></a>.</p>
  186. <p>The LIKE operator can be made case sensitive using the
  187. <a href="pragma.html#pragma_case_sensitive_like">case_sensitive_like pragma</a>.</p>
  188. <a name="glob"></a>
  189. <p>The GLOB operator is similar to LIKE but uses the Unix
  190. file globbing syntax for its wildcards. Also, GLOB is case
  191. sensitive, unlike LIKE. Both GLOB and LIKE may be preceded by
  192. the NOT keyword to invert the sense of the test. The infix GLOB
  193. operator is implemented by calling the function
  194. <a href="lang_corefunc.html#glob">glob(<i>Y</i>,<i>X</i>)</a> and can be modified by overriding
  195. that function.</p>
  196. <a name="regexp"></a>
  197. <p>The REGEXP operator is a special syntax for the regexp()
  198. user function. No regexp() user function is defined by default
  199. and so use of the REGEXP operator will normally result in an
  200. error message. If a user-defined function named "regexp"
  201. is added at run-time, that function will be called in order
  202. to implement the REGEXP operator.</p>
  203. <a name="match"></a>
  204. <p>The MATCH operator is a special syntax for the match()
  205. user function. The default match() function implementation
  206. raises an exception and is not really useful for anything.
  207. But extensions can override the match() function with more
  208. helpful logic.</p>
  209. <a name="between"></a>
  210. <h3>The BETWEEN operator</h3>
  211. <p>The BETWEEN operator is equivalent to a pair of comparisons.
  212. "<i>a</i> <b>BETWEEN</b> <i>b</i> <b>AND</b> <i>c</i>" is
  213. equivalent to
  214. "<i>a</i><b>&gt;=</b><i>b</i> <b>AND</b> <i>a</i><b>&lt;=</b><i>c</i>".
  215. The precedence of the BETWEEN operator is the same as the precedence
  216. as operators <b>==</b> and <b>!=</b> and <b>LIKE</b> and groups left to right.
  217. <h3>Table Column Names</h3>
  218. <p>A column name can be any of the names defined in the <a href="lang_createtable.html">CREATE TABLE</a>
  219. statement or one of the following special identifiers: "<b>ROWID</b>",
  220. "<b>OID</b>", or "<b>_ROWID_</b>".
  221. These special identifiers all describe the
  222. unique integer key (the <a href="lang_createtable.html#rowid">rowid</a>) associated with every
  223. row of every table.
  224. The special identifiers only refer to the row key if the <a href="lang_createtable.html">CREATE TABLE</a>
  225. statement does not define a real column with the same name.
  226. The rowid can be used anywhere a regular
  227. column can be used.</p>
  228. <h3>Subqueries</h3>
  229. <p><a href="lang_select.html">SELECT</a> statements can appear in expressions as either the
  230. right-hand operand of the IN operator, as a scalar quantity, or
  231. as the operand of an EXISTS operator.
  232. As a scalar quantity or the operand of an IN operator,
  233. the SELECT should have only a single column in its
  234. result. Compound SELECTs (connected with keywords like UNION or
  235. EXCEPT) are allowed.
  236. With the EXISTS operator, the columns in the result set of the <a href="lang_select.html">SELECT</a> are
  237. ignored and the expression returns TRUE if one or more rows exist
  238. and FALSE if the result set is empty.
  239. If no terms in the <a href="lang_select.html">SELECT</a> expression refer to values in the containing
  240. query, then the expression is evaluated once prior to any other
  241. processing and the result is reused as necessary. If the <a href="lang_select.html">SELECT</a> expression
  242. does contain variables from the outer query, then the <a href="lang_select.html">SELECT</a> is reevaluated
  243. every time it is needed.</p>
  244. <p>When a SELECT is the right operand of the IN operator, the IN
  245. operator returns TRUE if the result of the left operand is any of
  246. the values generated by the select. The IN operator may be preceded
  247. by the NOT keyword to invert the sense of the test.</p>
  248. <p>When a SELECT appears within an expression but is not the right
  249. operand of an IN operator, then the first row of the result of the
  250. SELECT becomes the value used in the expression. If the SELECT yields
  251. more than one result row, all rows after the first are ignored. If
  252. the SELECT yields no rows, then the value of the SELECT is NULL.</p>
  253. <h3>CAST expressions</h3>
  254. <p>A CAST expression changes the <a href="datatype3.html">datatype</a> of the <expr> into the
  255. type specified by &lt;type&gt;.
  256. &lt;type&gt; can be any non-empty type name that is valid
  257. for the type in a column definition of a <a href="lang_createtable.html">CREATE TABLE</a> statement.</p>
  258. <h3>Functions</h3>
  259. <p>Both <a href="lang_corefunc.html">simple</a> and <a href="lang_aggfunc.html">aggregate</a> functions are supported.
  260. (For presentation purposes, simple functions are further subdivided into
  261. <a href="lang_corefunc.html">core functions</a> and <a href="lang_datefunc.html">date-time functions</a>.)
  262. A simple function can be used in any expression. Simple functions return
  263. a result immediately based on their inputs. Aggregate functions
  264. may only be used in a SELECT statement. Aggregate functions compute
  265. their result across all rows of the result set.</p>