syntax.sgml 66.2 KB
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 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119 1120 1121 1122 1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 1138 1139 1140 1141 1142 1143 1144 1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159 1160 1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309 1310 1311 1312 1313 1314 1315 1316 1317 1318 1319 1320 1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351 1352 1353 1354 1355 1356 1357 1358 1359 1360 1361 1362 1363 1364 1365 1366 1367 1368 1369 1370 1371 1372 1373 1374 1375 1376 1377 1378 1379 1380 1381 1382 1383 1384 1385 1386 1387 1388 1389 1390 1391 1392 1393 1394 1395 1396 1397 1398 1399 1400 1401 1402 1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418 1419 1420 1421 1422 1423 1424 1425 1426 1427 1428 1429 1430 1431 1432 1433 1434 1435 1436 1437 1438 1439 1440 1441 1442 1443 1444 1445 1446 1447 1448 1449 1450 1451 1452 1453 1454 1455 1456 1457 1458 1459 1460 1461 1462 1463 1464 1465 1466 1467 1468 1469 1470 1471 1472 1473 1474 1475 1476 1477 1478 1479 1480 1481 1482 1483 1484 1485 1486 1487 1488 1489 1490 1491 1492 1493 1494 1495 1496 1497 1498 1499 1500 1501 1502 1503 1504 1505 1506 1507 1508 1509 1510 1511 1512 1513 1514 1515 1516 1517 1518 1519 1520 1521 1522 1523 1524 1525 1526 1527 1528 1529 1530 1531 1532 1533 1534 1535 1536 1537 1538 1539 1540 1541 1542 1543 1544 1545 1546 1547 1548 1549 1550 1551 1552 1553 1554 1555 1556 1557 1558 1559 1560 1561 1562 1563 1564 1565 1566 1567 1568 1569 1570 1571 1572 1573 1574 1575 1576 1577 1578 1579 1580 1581 1582 1583 1584 1585 1586 1587 1588 1589 1590 1591 1592 1593 1594 1595 1596 1597 1598 1599 1600 1601 1602 1603 1604 1605 1606 1607 1608 1609 1610 1611 1612 1613 1614 1615 1616 1617 1618 1619 1620 1621 1622 1623 1624 1625 1626 1627 1628 1629 1630 1631 1632 1633 1634 1635 1636 1637 1638 1639 1640 1641 1642 1643 1644 1645 1646 1647 1648 1649 1650 1651 1652 1653 1654 1655 1656 1657 1658 1659 1660 1661 1662 1663 1664 1665 1666 1667 1668 1669 1670 1671 1672 1673 1674 1675 1676 1677 1678 1679 1680 1681 1682 1683 1684 1685 1686 1687 1688 1689 1690 1691 1692 1693 1694 1695 1696 1697 1698 1699 1700 1701 1702 1703 1704 1705 1706 1707 1708 1709 1710 1711 1712 1713 1714 1715 1716 1717 1718 1719 1720 1721 1722 1723 1724 1725 1726 1727 1728 1729 1730 1731 1732 1733 1734 1735 1736 1737 1738 1739 1740 1741 1742 1743 1744 1745 1746 1747 1748 1749 1750 1751 1752 1753 1754 1755 1756 1757 1758 1759 1760 1761 1762 1763 1764 1765 1766 1767 1768 1769 1770 1771 1772 1773 1774 1775 1776 1777 1778 1779 1780 1781 1782 1783 1784 1785 1786 1787 1788 1789 1790 1791 1792 1793 1794 1795 1796 1797 1798 1799 1800 1801 1802 1803 1804 1805 1806 1807 1808 1809 1810 1811 1812 1813 1814 1815 1816 1817 1818 1819 1820 1821 1822 1823 1824 1825 1826 1827 1828 1829 1830 1831 1832 1833 1834 1835 1836 1837 1838 1839 1840 1841 1842 1843 1844 1845 1846 1847 1848 1849 1850 1851 1852 1853 1854 1855 1856 1857 1858 1859 1860 1861 1862 1863 1864 1865 1866 1867 1868 1869 1870 1871 1872 1873 1874 1875 1876 1877 1878 1879 1880 1881 1882 1883 1884 1885 1886 1887 1888 1889 1890 1891 1892 1893 1894 1895 1896 1897 1898 1899 1900 1901 1902 1903 1904 1905 1906 1907 1908 1909 1910 1911 1912 1913 1914 1915 1916 1917 1918 1919 1920 1921 1922 1923 1924 1925 1926 1927 1928 1929 1930 1931 1932 1933 1934 1935 1936 1937 1938 1939 1940 1941 1942 1943 1944 1945 1946 1947 1948 1949 1950 1951 1952 1953 1954 1955
<!-- $PostgreSQL: pgsql/doc/src/sgml/syntax.sgml,v 1.124 2008/10/29 08:04:52 petere Exp $ -->

<chapter id="sql-syntax">
 <title>SQL Syntax</title>

 <indexterm zone="sql-syntax">
  <primary>syntax</primary>
  <secondary>SQL</secondary>
 </indexterm>

 <para>
  This chapter describes the syntax of SQL.  It forms the foundation
  for understanding the following chapters which will go into detail
  about how the SQL commands are applied to define and modify data.
 </para>

 <para>
  We also advise users who are already familiar with SQL to read this
  chapter carefully because there are several rules and concepts that
  are implemented inconsistently among SQL databases or that are
  specific to <productname>PostgreSQL</productname>.
 </para>

 <sect1 id="sql-syntax-lexical">
  <title>Lexical Structure</title>

  <indexterm>
   <primary>token</primary>
  </indexterm>

  <para>
   SQL input consists of a sequence of
   <firstterm>commands</firstterm>.  A command is composed of a
   sequence of <firstterm>tokens</firstterm>, terminated by a
   semicolon (<quote>;</quote>).  The end of the input stream also
   terminates a command.  Which tokens are valid depends on the syntax
   of the particular command.
  </para>

  <para>
   A token can be a <firstterm>key word</firstterm>, an
   <firstterm>identifier</firstterm>, a <firstterm>quoted
   identifier</firstterm>, a <firstterm>literal</firstterm> (or
   constant), or a special character symbol.  Tokens are normally
   separated by whitespace (space, tab, newline), but need not be if
   there is no ambiguity (which is generally only the case if a
   special character is adjacent to some other token type).
  </para>

  <para>
   Additionally, <firstterm>comments</firstterm> can occur in SQL
   input.  They are not tokens, they are effectively equivalent to
   whitespace.
  </para>

   <para>
    For example, the following is (syntactically) valid SQL input:
<programlisting>
SELECT * FROM MY_TABLE;
UPDATE MY_TABLE SET A = 5;
INSERT INTO MY_TABLE VALUES (3, 'hi there');
</programlisting>
    This is a sequence of three commands, one per line (although this
    is not required; more than one command can be on a line, and
    commands can usefully be split across lines).
   </para>

  <para>
   The SQL syntax is not very consistent regarding what tokens
   identify commands and which are operands or parameters.  The first
   few tokens are generally the command name, so in the above example
   we would usually speak of a <quote>SELECT</quote>, an
   <quote>UPDATE</quote>, and an <quote>INSERT</quote> command.  But
   for instance the <command>UPDATE</command> command always requires
   a <token>SET</token> token to appear in a certain position, and
   this particular variation of <command>INSERT</command> also
   requires a <token>VALUES</token> in order to be complete.  The
   precise syntax rules for each command are described in <xref linkend="reference">.
  </para>

  <sect2 id="sql-syntax-identifiers">
   <title>Identifiers and Key Words</title>

   <indexterm zone="sql-syntax-identifiers">
    <primary>identifier</primary>
    <secondary>syntax of</secondary>
   </indexterm>

   <indexterm zone="sql-syntax-identifiers">
    <primary>name</primary>
    <secondary>syntax of</secondary>
   </indexterm>

   <indexterm zone="sql-syntax-identifiers">
    <primary>key word</primary>
    <secondary>syntax of</secondary>
   </indexterm>

   <para>
    Tokens such as <token>SELECT</token>, <token>UPDATE</token>, or
    <token>VALUES</token> in the example above are examples of
    <firstterm>key words</firstterm>, that is, words that have a fixed
    meaning in the SQL language.  The tokens <token>MY_TABLE</token>
    and <token>A</token> are examples of
    <firstterm>identifiers</firstterm>.  They identify names of
    tables, columns, or other database objects, depending on the
    command they are used in.  Therefore they are sometimes simply
    called <quote>names</quote>.  Key words and identifiers have the
    same lexical structure, meaning that one cannot know whether a
    token is an identifier or a key word without knowing the language.
    A complete list of key words can be found in <xref
    linkend="sql-keywords-appendix">.
   </para>

   <para>
    SQL identifiers and key words must begin with a letter
    (<literal>a</literal>-<literal>z</literal>, but also letters with
    diacritical marks and non-Latin letters) or an underscore
    (<literal>_</literal>).  Subsequent characters in an identifier or
    key word can be letters, underscores, digits
    (<literal>0</literal>-<literal>9</literal>), or dollar signs
    (<literal>$</>).  Note that dollar signs are not allowed in identifiers
    according to the letter of the SQL standard, so their use might render
    applications less portable.
    The SQL standard will not define a key word that contains
    digits or starts or ends with an underscore, so identifiers of this
    form are safe against possible conflict with future extensions of the
    standard.
   </para>

   <para>
    <indexterm><primary>identifier</primary><secondary>length</secondary></indexterm>
    The system uses no more than <symbol>NAMEDATALEN</symbol>-1
    bytes of an identifier; longer names can be written in
    commands, but they will be truncated.  By default,
    <symbol>NAMEDATALEN</symbol> is 64 so the maximum identifier
    length is 63 bytes. If this limit is problematic, it can be raised by
    changing the <symbol>NAMEDATALEN</symbol> constant in
    <filename>src/include/pg_config_manual.h</filename>.
   </para>

   <para>
    <indexterm>
     <primary>case sensitivity</primary>
     <secondary>of SQL commands</secondary>
    </indexterm>
    Identifier and key word names are case insensitive.  Therefore:
<programlisting>
UPDATE MY_TABLE SET A = 5;
</programlisting>
    can equivalently be written as:
<programlisting>
uPDaTE my_TabLE SeT a = 5;
</programlisting>
    A convention often used is to write key words in upper
    case and names in lower case, e.g.:
<programlisting>
UPDATE my_table SET a = 5;
</programlisting>
   </para>

   <para>
    <indexterm>
     <primary>quotation marks</primary>
     <secondary>and identifiers</secondary>
    </indexterm>
    There is a second kind of identifier:  the <firstterm>delimited
    identifier</firstterm> or <firstterm>quoted
    identifier</firstterm>.  It is formed by enclosing an arbitrary
    sequence of characters in double-quotes
    (<literal>"</literal>). <!-- " font-lock mania --> A delimited
    identifier is always an identifier, never a key word.  So
    <literal>"select"</literal> could be used to refer to a column or
    table named <quote>select</quote>, whereas an unquoted
    <literal>select</literal> would be taken as a key word and
    would therefore provoke a parse error when used where a table or
    column name is expected.  The example can be written with quoted
    identifiers like this:
<programlisting>
UPDATE "my_table" SET "a" = 5;
</programlisting>
   </para>

   <para>
    Quoted identifiers can contain any character, except the character
    with code zero.  (To include a double quote, write two double quotes.)
    This allows constructing table or column names that would
    otherwise not be possible, such as ones containing spaces or
    ampersands.  The length limitation still applies.
   </para>

   <para>
    <indexterm><primary>Unicode escape</primary><secondary>in
    identifiers</secondary></indexterm> A variant of quoted
    identifiers allows including escaped Unicode characters identified
    by their code points.  This variant starts
    with <literal>U&</literal> (upper or lower case U followed by
    ampersand) immediately before the opening double quote, without
    any spaces in between, for example <literal>U&"foo"</literal>.
    (Note that this creates an ambiguity with the
    operator <literal>&</literal>.  Use spaces around the operator to
    avoid this problem.)  Inside the quotes, Unicode characters can be
    specified in escaped form by writing a backslash followed by the
    four-digit hexadecimal code point number or alternatively a
    backslash followed by a plus sign followed by a six-digit
    hexadecimal code point number.  For example, the
    identifier <literal>"data"</literal> could be written as
<programlisting>
U&"d\0061t\+000061"
</programlisting>
    The following less trivial example writes the Russian
    word <quote>slon</quote> (elephant) in Cyrillic letters:
<programlisting>
U&"\0441\043B\043E\043D"
</programlisting>
   </para>

   <para>
    If a different escape character than backslash is desired, it can
    be specified using
    the <literal>UESCAPE</literal><indexterm><primary>UESCAPE</primary></indexterm>
    clause after the string, for example:
<programlisting>
U&"d!0061t!+000061" UESCAPE '!'
</programlisting>
    The escape character can be any single character other than a
    hexadecimal digit, the plus sign, a single quote, a double quote,
    or a whitespace character.  Note that the escape character is
    written in single quotes, not double quotes.
   </para>

   <para>
    To include the escape character in the identifier literally, write
    it twice.
   </para>

   <para>
    The Unicode escape syntax works only when the server encoding is
    UTF8.  When other server encodings are used, only code points in
    the ASCII range (up to <literal>\007F</literal>) can be specified.
   </para>

   <para>
    Quoting an identifier also makes it case-sensitive, whereas
    unquoted names are always folded to lower case.  For example, the
    identifiers <literal>FOO</literal>, <literal>foo</literal>, and
    <literal>"foo"</literal> are considered the same by
    <productname>PostgreSQL</productname>, but
    <literal>"Foo"</literal> and <literal>"FOO"</literal> are
    different from these three and each other.  (The folding of
    unquoted names to lower case in <productname>PostgreSQL</> is
    incompatible with the SQL standard, which says that unquoted names
    should be folded to upper case.  Thus, <literal>foo</literal>
    should be equivalent to <literal>"FOO"</literal> not
    <literal>"foo"</literal> according to the standard.  If you want
    to write portable applications you are advised to always quote a
    particular name or never quote it.)
   </para>
  </sect2>


  <sect2 id="sql-syntax-constants">
   <title>Constants</title>

   <indexterm zone="sql-syntax-constants">
    <primary>constant</primary>
   </indexterm>

   <para>
    There are three kinds of <firstterm>implicitly-typed
    constants</firstterm> in <productname>PostgreSQL</productname>:
    strings, bit strings, and numbers.
    Constants can also be specified with explicit types, which can
    enable more accurate representation and more efficient handling by
    the system. These alternatives are discussed in the following
    subsections.
   </para>

   <sect3 id="sql-syntax-strings">
    <title>String Constants</title>

    <indexterm zone="sql-syntax-strings">
     <primary>character string</primary>
     <secondary>constant</secondary>
    </indexterm>

    <para>
     <indexterm>
      <primary>quotation marks</primary>
      <secondary>escaping</secondary>
     </indexterm>
     A string constant in SQL is an arbitrary sequence of characters
     bounded by single quotes (<literal>'</literal>), for example
     <literal>'This is a string'</literal>.  To include
     a single-quote character within a string constant,
     write two adjacent single quotes, e.g.
     <literal>'Dianne''s horse'</literal>.
     Note that this is <emphasis>not</> the same as a double-quote
     character (<literal>"</>). <!-- font-lock sanity: " -->
    </para>

    <para>
     Two string constants that are only separated by whitespace
     <emphasis>with at least one newline</emphasis> are concatenated
     and effectively treated as if the string had been written as one
     constant.  For example:
<programlisting>
SELECT 'foo'
'bar';
</programlisting>
     is equivalent to:
<programlisting>
SELECT 'foobar';
</programlisting>
     but:
<programlisting>
SELECT 'foo'      'bar';
</programlisting>
     is not valid syntax.  (This slightly bizarre behavior is specified
     by <acronym>SQL</acronym>; <productname>PostgreSQL</productname> is
     following the standard.)
    </para>
   </sect3>

   <sect3 id="sql-syntax-strings-escape">
    <title>String Constants with C-Style Escapes</title>

     <indexterm zone="sql-syntax-strings-escape">
      <primary>escape string syntax</primary>
     </indexterm>
     <indexterm zone="sql-syntax-strings-escape">
      <primary>backslash escapes</primary>
     </indexterm>

    <para>
     <productname>PostgreSQL</productname> also accepts <quote>escape</>
     string constants, which are an extension to the SQL standard.
     An escape string constant is specified by writing the letter
     <literal>E</literal> (upper or lower case) just before the opening single
     quote, e.g. <literal>E'foo'</>.  (When continuing an escape string
     constant across lines, write <literal>E</> only before the first opening
     quote.)
     Within an escape string, a backslash character (<literal>\</>) begins a
     C-like <firstterm>backslash escape</> sequence, in which the combination
     of backslash and following character(s) represent a special byte
     value, as shown in <xref linkend="sql-backslash-table">.
    </para>

     <table id="sql-backslash-table">
      <title>Backslash Escape Sequences</title>
      <tgroup cols="2">
      <thead>
       <row>
        <entry>Backslash Escape Sequence</>
        <entry>Interpretation</entry>
       </row>
      </thead>

      <tbody>
       <row>
        <entry><literal>\b</literal></entry>
        <entry>backspace</entry>
       </row>
       <row>
        <entry><literal>\f</literal></entry>
        <entry>form feed</entry>
       </row>
       <row>
        <entry><literal>\n</literal></entry>
        <entry>newline</entry>
       </row>
       <row>
        <entry><literal>\r</literal></entry>
        <entry>carriage return</entry>
       </row>
       <row>
        <entry><literal>\t</literal></entry>
        <entry>tab</entry>
       </row>
       <row>
        <entry>
         <literal>\<replaceable>o</replaceable></literal>,
         <literal>\<replaceable>oo</replaceable></literal>,
         <literal>\<replaceable>ooo</replaceable></literal>
         (<replaceable>o</replaceable> = 0 - 7)
        </entry>
        <entry>octal byte value</entry>
       </row>
       <row>
        <entry>
         <literal>\x<replaceable>h</replaceable></literal>,
         <literal>\x<replaceable>hh</replaceable></literal>
         (<replaceable>h</replaceable> = 0 - 9, A - F)
        </entry>
        <entry>hexadecimal byte value</entry>
       </row>
      </tbody>
      </tgroup>
     </table>

    <para>
     Any other
     character following a backslash is taken literally. Thus, to
     include a backslash character, write two backslashes (<literal>\\</>).
     Also, a single quote can be included in an escape string by writing
     <literal>\'</literal>, in addition to the normal way of <literal>''</>.
    </para>

    <para>
     It is your responsibility that the byte sequences you create are
     valid characters in the server character set encoding.  When the
     server encoding is UTF-8, then the alternative Unicode escape
     syntax, explained in <xref linkend="sql-syntax-strings-uescape">,
     should be used instead.  (The alternative would be doing the
     UTF-8 encoding by hand and writing out the bytes, which would be
     very cumbersome.)
    </para>

    <caution>
    <para>
     If the configuration parameter
     <xref linkend="guc-standard-conforming-strings"> is <literal>off</>,
     then <productname>PostgreSQL</productname> recognizes backslash escapes
     in both regular and escape string constants.  This is for backward
     compatibility with the historical behavior, in which backslash escapes
     were always recognized.
     Although <varname>standard_conforming_strings</> currently defaults to
     <literal>off</>, the default will change to <literal>on</> in a future
     release for improved standards compliance.  Applications are therefore
     encouraged to migrate away from using backslash escapes.  If you need
     to use a backslash escape to represent a special character, write the
     constant with an <literal>E</> to be sure it will be handled the same
     way in future releases.
    </para>

    <para>
     In addition to <varname>standard_conforming_strings</>, the configuration
     parameters <xref linkend="guc-escape-string-warning"> and
     <xref linkend="guc-backslash-quote"> govern treatment of backslashes
     in string constants.
    </para>
    </caution>

    <para>
     The character with the code zero cannot be in a string constant.
    </para>
   </sect3>

   <sect3 id="sql-syntax-strings-uescape">
    <title>String Constants with Unicode Escapes</title>

    <indexterm  zone="sql-syntax-strings-uescape">
     <primary>Unicode escape</primary>
     <secondary>in string constants</secondary>
    </indexterm>

    <para>
     <productname>PostgreSQL</productname> also supports another type
     of escape syntax for strings that allows specifying arbitrary
     Unicode characters by code point.  A Unicode escape string
     constant starts with <literal>U&</literal> (upper or lower case
     letter U followed by ampersand) immediately before the opening
     quote, without any spaces in between, for
     example <literal>U&'foo'</literal>.  (Note that this creates an
     ambiguity with the operator <literal>&</literal>.  Use spaces
     around the operator to avoid this problem.)  Inside the quotes,
     Unicode characters can be specified in escaped form by writing a
     backslash followed by the four-digit hexadecimal code point
     number or alternatively a backslash followed by a plus sign
     followed by a six-digit hexadecimal code point number.  For
     example, the string <literal>'data'</literal> could be written as
<programlisting>
U&'d\0061t\+000061'
</programlisting>
     The following less trivial example writes the Russian
     word <quote>slon</quote> (elephant) in Cyrillic letters:
<programlisting>
U&'\0441\043B\043E\043D'
</programlisting>
    </para>

    <para>
     If a different escape character than backslash is desired, it can
     be specified using
     the <literal>UESCAPE</literal><indexterm><primary>UESCAPE</primary></indexterm>
     clause after the string, for example:
<programlisting>
		   U&'d!0061t!+000061' UESCAPE '!'
</programlisting>
     The escape character can be any single character other than a
     hexadecimal digit, the plus sign, a single quote, a double quote,
     or a whitespace character.
    </para>

    <para>
     The Unicode escape syntax works only when the server encoding is
     UTF8.  When other server encodings are used, only code points in
     the ASCII range (up to <literal>\007F</literal>) can be
     specified.
    </para>

    <para>
     To include the escape character in the string literally, write it
     twice.
    </para>
   </sect3>

   <sect3 id="sql-syntax-dollar-quoting">
    <title>Dollar-Quoted String Constants</title>

     <indexterm>
      <primary>dollar quoting</primary>
     </indexterm>

    <para>
     While the standard syntax for specifying string constants is usually
     convenient, it can be difficult to understand when the desired string
     contains many single quotes or backslashes, since each of those must
     be doubled. To allow more readable queries in such situations,
     <productname>PostgreSQL</productname> provides another way, called
     <quote>dollar quoting</quote>, to write string constants.
     A dollar-quoted string constant
     consists of a dollar sign (<literal>$</literal>), an optional
     <quote>tag</quote> of zero or more characters, another dollar
     sign, an arbitrary sequence of characters that makes up the
     string content, a dollar sign, the same tag that began this
     dollar quote, and a dollar sign. For example, here are two
     different ways to specify the string <quote>Dianne's horse</>
     using dollar quoting:
<programlisting>
$$Dianne's horse$$
$SomeTag$Dianne's horse$SomeTag$
</programlisting>
     Notice that inside the dollar-quoted string, single quotes can be
     used without needing to be escaped.  Indeed, no characters inside
     a dollar-quoted string are ever escaped: the string content is always
     written literally.  Backslashes are not special, and neither are
     dollar signs, unless they are part of a sequence matching the opening
     tag.
    </para>

    <para>
     It is possible to nest dollar-quoted string constants by choosing
     different tags at each nesting level.  This is most commonly used in
     writing function definitions.  For example:
<programlisting>
$function$
BEGIN
    RETURN ($1 ~ $q$[\t\r\n\v\\]$q$);
END;
$function$
</programlisting>
     Here, the sequence <literal>$q$[\t\r\n\v\\]$q$</> represents a
     dollar-quoted literal string <literal>[\t\r\n\v\\]</>, which will
     be recognized when the function body is executed by
     <productname>PostgreSQL</>.  But since the sequence does not match
     the outer dollar quoting delimiter <literal>$function$</>, it is
     just some more characters within the constant so far as the outer
     string is concerned.
    </para>

    <para>
     The tag, if any, of a dollar-quoted string follows the same rules
     as an unquoted identifier, except that it cannot contain a dollar sign.
     Tags are case sensitive, so <literal>$tag$String content$tag$</literal>
     is correct, but <literal>$TAG$String content$tag$</literal> is not.
    </para>

    <para>
     A dollar-quoted string that follows a keyword or identifier must
     be separated from it by whitespace; otherwise the dollar quoting
     delimiter would be taken as part of the preceding identifier.
    </para>

    <para>
     Dollar quoting is not part of the SQL standard, but it is often a more
     convenient way to write complicated string literals than the
     standard-compliant single quote syntax.  It is particularly useful when
     representing string constants inside other constants, as is often needed
     in procedural function definitions.  With single-quote syntax, each
     backslash in the above example would have to be written as four
     backslashes, which would be reduced to two backslashes in parsing the
     original string constant, and then to one when the inner string constant
     is re-parsed during function execution.
    </para>
   </sect3>

   <sect3 id="sql-syntax-bit-strings">
    <title>Bit-String Constants</title>

    <indexterm zone="sql-syntax-bit-strings">
     <primary>bit string</primary>
     <secondary>constant</secondary>
    </indexterm>

    <para>
     Bit-string constants look like regular string constants with a
     <literal>B</literal> (upper or lower case) immediately before the
     opening quote (no intervening whitespace), e.g.,
     <literal>B'1001'</literal>.  The only characters allowed within
     bit-string constants are <literal>0</literal> and
     <literal>1</literal>.
    </para>

    <para>
     Alternatively, bit-string constants can be specified in hexadecimal
     notation, using a leading <literal>X</literal> (upper or lower case),
     e.g., <literal>X'1FF'</literal>.  This notation is equivalent to
     a bit-string constant with four binary digits for each hexadecimal digit.
    </para>

    <para>
     Both forms of bit-string constant can be continued
     across lines in the same way as regular string constants.
     Dollar quoting cannot be used in a bit-string constant.
    </para>
   </sect3>

   <sect3>
    <title>Numeric Constants</title>

    <indexterm>
     <primary>number</primary>
     <secondary>constant</secondary>
    </indexterm>

    <para>
     Numeric constants are accepted in these general forms:
<synopsis>
<replaceable>digits</replaceable>
<replaceable>digits</replaceable>.<optional><replaceable>digits</replaceable></optional><optional>e<optional>+-</optional><replaceable>digits</replaceable></optional>
<optional><replaceable>digits</replaceable></optional>.<replaceable>digits</replaceable><optional>e<optional>+-</optional><replaceable>digits</replaceable></optional>
<replaceable>digits</replaceable>e<optional>+-</optional><replaceable>digits</replaceable>
</synopsis>
     where <replaceable>digits</replaceable> is one or more decimal
     digits (0 through 9).  At least one digit must be before or after the
     decimal point, if one is used.  At least one digit must follow the
     exponent marker (<literal>e</literal>), if one is present.
     There cannot be any spaces or other characters embedded in the
     constant.  Note that any leading plus or minus sign is not actually
     considered part of the constant; it is an operator applied to the
     constant.
    </para>

    <para>
     These are some examples of valid numeric constants:
<literallayout>
42
3.5
4.
.001
5e2
1.925e-3
</literallayout>
    </para>

    <para>
     <indexterm><primary>integer</primary></indexterm>
     <indexterm><primary>bigint</primary></indexterm>
     <indexterm><primary>numeric</primary></indexterm>
     A numeric constant that contains neither a decimal point nor an
     exponent is initially presumed to be type <type>integer</> if its
     value fits in type <type>integer</> (32 bits); otherwise it is
     presumed to be type <type>bigint</> if its
     value fits in type <type>bigint</> (64 bits); otherwise it is
     taken to be type <type>numeric</>.  Constants that contain decimal
     points and/or exponents are always initially presumed to be type
     <type>numeric</>.
    </para>

    <para>
     The initially assigned data type of a numeric constant is just a
     starting point for the type resolution algorithms.  In most cases
     the constant will be automatically coerced to the most
     appropriate type depending on context.  When necessary, you can
     force a numeric value to be interpreted as a specific data type
     by casting it.<indexterm><primary>type cast</primary></indexterm>
     For example, you can force a numeric value to be treated as type
     <type>real</> (<type>float4</>) by writing:

<programlisting>
REAL '1.23'  -- string style
1.23::REAL   -- PostgreSQL (historical) style
</programlisting>

     These are actually just special cases of the general casting
     notations discussed next.
    </para>
   </sect3>

   <sect3 id="sql-syntax-constants-generic">
    <title>Constants of Other Types</title>

    <indexterm>
     <primary>data type</primary>
     <secondary>constant</secondary>
    </indexterm>

    <para>
     A constant of an <emphasis>arbitrary</emphasis> type can be
     entered using any one of the following notations:
<synopsis>
<replaceable>type</replaceable> '<replaceable>string</replaceable>'
'<replaceable>string</replaceable>'::<replaceable>type</replaceable>
CAST ( '<replaceable>string</replaceable>' AS <replaceable>type</replaceable> )
</synopsis>
     The string constant's text is passed to the input conversion
     routine for the type called <replaceable>type</replaceable>. The
     result is a constant of the indicated type.  The explicit type
     cast can be omitted if there is no ambiguity as to the type the
     constant must be (for example, when it is assigned directly to a
     table column), in which case it is automatically coerced.
    </para>

    <para>
     The string constant can be written using either regular SQL
     notation or dollar-quoting.
    </para>

    <para>
     It is also possible to specify a type coercion using a function-like
     syntax:
<synopsis>
<replaceable>typename</replaceable> ( '<replaceable>string</replaceable>' )
</synopsis>
     but not all type names can be used in this way; see <xref
     linkend="sql-syntax-type-casts"> for details.
    </para>

    <para>
     The <literal>::</literal>, <literal>CAST()</literal>, and
     function-call syntaxes can also be used to specify run-time type
     conversions of arbitrary expressions, as discussed in <xref
     linkend="sql-syntax-type-casts">.  To avoid syntactic ambiguity, the
     <literal><replaceable>type</> '<replaceable>string</>'</literal>
     syntax can only be used to specify the type of a simple literal constant.
     Another restriction on the
     <literal><replaceable>type</> '<replaceable>string</>'</literal>
     syntax is that it does not work for array types; use <literal>::</literal>
     or <literal>CAST()</literal> to specify the type of an array constant.
    </para>

    <para>
     The <literal>CAST()</> syntax conforms to SQL.  The
     <literal><replaceable>type</> '<replaceable>string</>'</literal>
     syntax is a generalization of the standard: SQL specifies this syntax only
     for a few data types, but <productname>PostgreSQL</productname> allows it
     for all types.  The syntax with
     <literal>::</literal> is historical <productname>PostgreSQL</productname>
     usage, as is the function-call syntax.
    </para>
   </sect3>
  </sect2>

  <sect2 id="sql-syntax-operators">
   <title>Operators</title>

   <indexterm zone="sql-syntax-operators">
    <primary>operator</primary>
    <secondary>syntax</secondary>
   </indexterm>

   <para>
    An operator name is a sequence of up to <symbol>NAMEDATALEN</symbol>-1
    (63 by default) characters from the following list:
<literallayout>
+ - * / &lt; &gt; = ~ ! @ # % ^ &amp; | ` ?
</literallayout>

    There are a few restrictions on operator names, however:
    <itemizedlist>
     <listitem>
      <para>
       <literal>--</literal> and <literal>/*</literal> cannot appear
       anywhere in an operator name, since they will be taken as the
       start of a comment.
      </para>
     </listitem>

     <listitem>
      <para>
       A multiple-character operator name cannot end in <literal>+</> or <literal>-</>,
       unless the name also contains at least one of these characters:
<literallayout>
~ ! @ # % ^ &amp; | ` ?
</literallayout>
       For example, <literal>@-</literal> is an allowed operator name,
       but <literal>*-</literal> is not.  This restriction allows
       <productname>PostgreSQL</productname> to parse SQL-compliant
       queries without requiring spaces between tokens.
      </para>
     </listitem>
    </itemizedlist>
   </para>

   <para>
    When working with non-SQL-standard operator names, you will usually
    need to separate adjacent operators with spaces to avoid ambiguity.
    For example, if you have defined a left unary operator named <literal>@</literal>,
    you cannot write <literal>X*@Y</literal>; you must write
    <literal>X* @Y</literal> to ensure that
    <productname>PostgreSQL</productname> reads it as two operator names
    not one.
   </para>
  </sect2>

  <sect2>
   <title>Special Characters</title>

  <para>
   Some characters that are not alphanumeric have a special meaning
   that is different from being an operator.  Details on the usage can
   be found at the location where the respective syntax element is
   described.  This section only exists to advise the existence and
   summarize the purposes of these characters.

   <itemizedlist>
    <listitem>
     <para>
      A dollar sign (<literal>$</literal>) followed by digits is used
      to represent a positional parameter in the body of a function
      definition or a prepared statement.  In other contexts the
      dollar sign can be part of an identifier or a dollar-quoted string
      constant.
     </para>
    </listitem>

    <listitem>
     <para>
      Parentheses (<literal>()</literal>) have their usual meaning to
      group expressions and enforce precedence.  In some cases
      parentheses are required as part of the fixed syntax of a
      particular SQL command.
     </para>
    </listitem>

    <listitem>
     <para>
      Brackets (<literal>[]</literal>) are used to select the elements
      of an array.  See <xref linkend="arrays"> for more information
      on arrays.
     </para>
    </listitem>

    <listitem>
     <para>
      Commas (<literal>,</literal>) are used in some syntactical
      constructs to separate the elements of a list.
     </para>
    </listitem>

    <listitem>
     <para>
      The semicolon (<literal>;</literal>) terminates an SQL command.
      It cannot appear anywhere within a command, except within a
      string constant or quoted identifier.
     </para>
    </listitem>

    <listitem>
     <para>
      The colon (<literal>:</literal>) is used to select
      <quote>slices</quote> from arrays. (See <xref
      linkend="arrays">.)  In certain SQL dialects (such as Embedded
      SQL), the colon is used to prefix variable names.
     </para>
    </listitem>

    <listitem>
     <para>
      The asterisk (<literal>*</literal>) is used in some contexts to denote
      all the fields of a table row or composite value.  It also
      has a special meaning when used as the argument of an
      aggregate function, namely that the aggregate does not require
      any explicit parameter.
     </para>
    </listitem>

    <listitem>
     <para>
      The period (<literal>.</literal>) is used in numeric
      constants, and to separate schema, table, and column names.
     </para>
    </listitem>
   </itemizedlist>

   </para>
  </sect2>

  <sect2 id="sql-syntax-comments">
   <title>Comments</title>

   <indexterm zone="sql-syntax-comments">
    <primary>comment</primary>
    <secondary sortas="SQL">in SQL</secondary>
   </indexterm>

   <para>
    A comment is an arbitrary sequence of characters beginning with
    double dashes and extending to the end of the line, e.g.:
<programlisting>
-- This is a standard SQL comment
</programlisting>
   </para>

   <para>
    Alternatively, C-style block comments can be used:
<programlisting>
/* multiline comment
 * with nesting: /* nested block comment */
 */
</programlisting>
    where the comment begins with <literal>/*</literal> and extends to
    the matching occurrence of <literal>*/</literal>. These block
    comments nest, as specified in the SQL standard but unlike C, so that one can
    comment out larger blocks of code that might contain existing block
    comments.
   </para>

   <para>
    A comment is removed from the input stream before further syntax
    analysis and is effectively replaced by whitespace.
   </para>
  </sect2>

  <sect2 id="sql-precedence">
   <title>Lexical Precedence</title>

   <indexterm zone="sql-precedence">
    <primary>operator</primary>
    <secondary>precedence</secondary>
   </indexterm>

   <para>
    <xref linkend="sql-precedence-table"> shows the precedence and
    associativity of the operators in <productname>PostgreSQL</>.
    Most operators have the same precedence and are left-associative.
    The precedence and associativity of the operators is hard-wired
    into the parser.  This can lead to non-intuitive behavior; for
    example the Boolean operators <literal>&lt;</> and
    <literal>&gt;</> have a different precedence than the Boolean
    operators <literal>&lt;=</> and <literal>&gt;=</>.  Also, you will
    sometimes need to add parentheses when using combinations of
    binary and unary operators.  For instance:
<programlisting>
SELECT 5 ! - 6;
</programlisting>
   will be parsed as:
<programlisting>
SELECT 5 ! (- 6);
</programlisting>
    because the parser has no idea &mdash; until it is too late
    &mdash; that <token>!</token> is defined as a postfix operator,
    not an infix one.  To get the desired behavior in this case, you
    must write:
<programlisting>
SELECT (5 !) - 6;
</programlisting>
    This is the price one pays for extensibility.
   </para>

   <table id="sql-precedence-table">
    <title>Operator Precedence (decreasing)</title>

    <tgroup cols="3">
     <thead>
      <row>
       <entry>Operator/Element</entry>
       <entry>Associativity</entry>
       <entry>Description</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry><token>.</token></entry>
       <entry>left</entry>
       <entry>table/column name separator</entry>
      </row>

      <row>
       <entry><token>::</token></entry>
       <entry>left</entry>
       <entry><productname>PostgreSQL</productname>-style typecast</entry>
      </row>

      <row>
       <entry><token>[</token> <token>]</token></entry>
       <entry>left</entry>
       <entry>array element selection</entry>
      </row>

      <row>
       <entry><token>-</token></entry>
       <entry>right</entry>
       <entry>unary minus</entry>
      </row>

      <row>
       <entry><token>^</token></entry>
       <entry>left</entry>
       <entry>exponentiation</entry>
      </row>

      <row>
       <entry><token>*</token> <token>/</token> <token>%</token></entry>
       <entry>left</entry>
       <entry>multiplication, division, modulo</entry>
      </row>

      <row>
       <entry><token>+</token> <token>-</token></entry>
       <entry>left</entry>
       <entry>addition, subtraction</entry>
      </row>

      <row>
       <entry><token>IS</token></entry>
       <entry></entry>
       <entry><literal>IS TRUE</>, <literal>IS FALSE</>, <literal>IS UNKNOWN</>, <literal>IS NULL</></entry>
      </row>

      <row>
       <entry><token>ISNULL</token></entry>
       <entry></entry>
       <entry>test for null</entry>
      </row>

      <row>
       <entry><token>NOTNULL</token></entry>
       <entry></entry>
       <entry>test for not null</entry>
      </row>

      <row>
       <entry>(any other)</entry>
       <entry>left</entry>
       <entry>all other native and user-defined operators</entry>
      </row>

      <row>
       <entry><token>IN</token></entry>
       <entry></entry>
       <entry>set membership</entry>
      </row>

      <row>
       <entry><token>BETWEEN</token></entry>
       <entry></entry>
       <entry>range containment</entry>
      </row>

      <row>
       <entry><token>OVERLAPS</token></entry>
       <entry></entry>
       <entry>time interval overlap</entry>
      </row>

      <row>
       <entry><token>LIKE</token> <token>ILIKE</token> <token>SIMILAR</token></entry>
       <entry></entry>
       <entry>string pattern matching</entry>
      </row>

      <row>
       <entry><token>&lt;</token> <token>&gt;</token></entry>
       <entry></entry>
       <entry>less than, greater than</entry>
      </row>

      <row>
       <entry><token>=</token></entry>
       <entry>right</entry>
       <entry>equality, assignment</entry>
      </row>

      <row>
       <entry><token>NOT</token></entry>
       <entry>right</entry>
       <entry>logical negation</entry>
      </row>

      <row>
       <entry><token>AND</token></entry>
       <entry>left</entry>
       <entry>logical conjunction</entry>
      </row>

      <row>
       <entry><token>OR</token></entry>
       <entry>left</entry>
       <entry>logical disjunction</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <para>
    Note that the operator precedence rules also apply to user-defined
    operators that have the same names as the built-in operators
    mentioned above.  For example, if you define a
    <quote>+</quote> operator for some custom data type it will have
    the same precedence as the built-in <quote>+</quote> operator, no
    matter what yours does.
   </para>

   <para>
    When a schema-qualified operator name is used in the
    <literal>OPERATOR</> syntax, as for example in:
<programlisting>
SELECT 3 OPERATOR(pg_catalog.+) 4;
</programlisting>
    the <literal>OPERATOR</> construct is taken to have the default precedence
    shown in <xref linkend="sql-precedence-table"> for <quote>any other</> operator.  This is true no matter
    which specific operator name appears inside <literal>OPERATOR()</>.
   </para>
  </sect2>
 </sect1>

 <sect1 id="sql-expressions">
  <title>Value Expressions</title>

  <indexterm zone="sql-expressions">
   <primary>expression</primary>
   <secondary>syntax</secondary>
  </indexterm>

  <indexterm zone="sql-expressions">
   <primary>value expression</primary>
  </indexterm>

  <indexterm>
   <primary>scalar</primary>
   <see>expression</see>
  </indexterm>

  <para>
   Value expressions are used in a variety of contexts, such
   as in the target list of the <command>SELECT</command> command, as
   new column values in <command>INSERT</command> or
   <command>UPDATE</command>, or in search conditions in a number of
   commands.  The result of a value expression is sometimes called a
   <firstterm>scalar</firstterm>, to distinguish it from the result of
   a table expression (which is a table).  Value expressions are
   therefore also called <firstterm>scalar expressions</firstterm> (or
   even simply <firstterm>expressions</firstterm>).  The expression
   syntax allows the calculation of values from primitive parts using
   arithmetic, logical, set, and other operations.
  </para>

  <para>
   A value expression is one of the following:

   <itemizedlist>
    <listitem>
     <para>
      A constant or literal value.
     </para>
    </listitem>

    <listitem>
     <para>
      A column reference.
     </para>
    </listitem>

    <listitem>
     <para>
      A positional parameter reference, in the body of a function definition
      or prepared statement.
     </para>
    </listitem>

    <listitem>
     <para>
      A subscripted expression.
     </para>
    </listitem>

    <listitem>
     <para>
      A field selection expression.
     </para>
    </listitem>

    <listitem>
     <para>
      An operator invocation.
     </para>
    </listitem>

    <listitem>
     <para>
      A function call.
     </para>
    </listitem>

    <listitem>
     <para>
      An aggregate expression.
     </para>
    </listitem>

    <listitem>
     <para>
      A type cast.
     </para>
    </listitem>

    <listitem>
     <para>
      A scalar subquery.
     </para>
    </listitem>

    <listitem>
     <para>
      An array constructor.
     </para>
    </listitem>

    <listitem>
     <para>
      A row constructor.
     </para>
    </listitem>

    <listitem>
     <para>
      Another value expression in parentheses, useful to group
      subexpressions and override
      precedence.<indexterm><primary>parenthesis</></>
     </para>
    </listitem>
   </itemizedlist>
  </para>

  <para>
   In addition to this list, there are a number of constructs that can
   be classified as an expression but do not follow any general syntax
   rules.  These generally have the semantics of a function or
   operator and are explained in the appropriate location in <xref
   linkend="functions">.  An example is the <literal>IS NULL</literal>
   clause.
  </para>

  <para>
   We have already discussed constants in <xref
   linkend="sql-syntax-constants">.  The following sections discuss
   the remaining options.
  </para>

  <sect2>
   <title>Column References</title>

   <indexterm>
    <primary>column reference</primary>
   </indexterm>

   <para>
    A column can be referenced in the form
<synopsis>
<replaceable>correlation</replaceable>.<replaceable>columnname</replaceable>
</synopsis>
   </para>

   <para>
    <replaceable>correlation</replaceable> is the name of a
    table (possibly qualified with a schema name), or an alias for a table
    defined by means of a <literal>FROM</literal> clause, or one of
    the key words <literal>NEW</literal> or <literal>OLD</literal>.
    (<literal>NEW</literal> and <literal>OLD</literal> can only appear in rewrite rules,
    while other correlation names can be used in any SQL statement.)
    The correlation name and separating dot can be omitted if the column name
    is unique across all the tables being used in the current query.  (See also <xref linkend="queries">.)
   </para>
  </sect2>

  <sect2>
   <title>Positional Parameters</title>

   <indexterm>
    <primary>parameter</primary>
    <secondary>syntax</secondary>
   </indexterm>

   <indexterm>
    <primary>$</primary>
   </indexterm>

   <para>
    A positional parameter reference is used to indicate a value
    that is supplied externally to an SQL statement.  Parameters are
    used in SQL function definitions and in prepared queries.  Some
    client libraries also support specifying data values separately
    from the SQL command string, in which case parameters are used to
    refer to the out-of-line data values.
    The form of a parameter reference is:
<synopsis>
$<replaceable>number</replaceable>
</synopsis>
   </para>

   <para>
    For example, consider the definition of a function,
    <function>dept</function>, as:

<programlisting>
CREATE FUNCTION dept(text) RETURNS dept
    AS $$ SELECT * FROM dept WHERE name = $1 $$
    LANGUAGE SQL;
</programlisting>

    Here the <literal>$1</literal> references the value of the first
    function argument whenever the function is invoked.
   </para>
  </sect2>

  <sect2>
   <title>Subscripts</title>

   <indexterm>
    <primary>subscript</primary>
   </indexterm>

   <para>
    If an expression yields a value of an array type, then a specific
    element of the array value can be extracted by writing
<synopsis>
<replaceable>expression</replaceable>[<replaceable>subscript</replaceable>]
</synopsis>
    or multiple adjacent elements (an <quote>array slice</>) can be extracted
    by writing
<synopsis>
<replaceable>expression</replaceable>[<replaceable>lower_subscript</replaceable>:<replaceable>upper_subscript</replaceable>]
</synopsis>
    (Here, the brackets <literal>[ ]</literal> are meant to appear literally.)
    Each <replaceable>subscript</replaceable> is itself an expression,
    which must yield an integer value.
   </para>

   <para>
    In general the array <replaceable>expression</replaceable> must be
    parenthesized, but the parentheses can be omitted when the expression
    to be subscripted is just a column reference or positional parameter.
    Also, multiple subscripts can be concatenated when the original array
    is multidimensional.
    For example:

<programlisting>
mytable.arraycolumn[4]
mytable.two_d_column[17][34]
$1[10:42]
(arrayfunction(a,b))[42]
</programlisting>

    The parentheses in the last example are required.
    See <xref linkend="arrays"> for more about arrays.
   </para>
  </sect2>

  <sect2>
   <title>Field Selection</title>

   <indexterm>
    <primary>field selection</primary>
   </indexterm>

   <para>
    If an expression yields a value of a composite type (row type), then a
    specific field of the row can be extracted by writing
<synopsis>
<replaceable>expression</replaceable>.<replaceable>fieldname</replaceable>
</synopsis>
   </para>

   <para>
    In general the row <replaceable>expression</replaceable> must be
    parenthesized, but the parentheses can be omitted when the expression
    to be selected from is just a table reference or positional parameter.
    For example:

<programlisting>
mytable.mycolumn
$1.somecolumn
(rowfunction(a,b)).col3
</programlisting>

    (Thus, a qualified column reference is actually just a special case
    of the field selection syntax.)
   </para>
  </sect2>

  <sect2>
   <title>Operator Invocations</title>

   <indexterm>
    <primary>operator</primary>
    <secondary>invocation</secondary>
   </indexterm>

   <para>
    There are three possible syntaxes for an operator invocation:
    <simplelist>
     <member><replaceable>expression</replaceable> <replaceable>operator</replaceable> <replaceable>expression</replaceable> (binary infix operator)</member>
     <member><replaceable>operator</replaceable> <replaceable>expression</replaceable> (unary prefix operator)</member>
     <member><replaceable>expression</replaceable> <replaceable>operator</replaceable> (unary postfix operator)</member>
    </simplelist>
    where the <replaceable>operator</replaceable> token follows the syntax
    rules of <xref linkend="sql-syntax-operators">, or is one of the
    key words <token>AND</token>, <token>OR</token>, and
    <token>NOT</token>, or is a qualified operator name in the form
<synopsis>
<literal>OPERATOR(</><replaceable>schema</><literal>.</><replaceable>operatorname</><literal>)</>
</synopsis>
    Which particular operators exist and whether
    they are unary or binary depends on what operators have been
    defined by the system or the user.  <xref linkend="functions">
    describes the built-in operators.
   </para>
  </sect2>

  <sect2>
   <title>Function Calls</title>

   <indexterm>
    <primary>function</primary>
    <secondary>invocation</secondary>
   </indexterm>

   <para>
    The syntax for a function call is the name of a function
    (possibly qualified with a schema name), followed by its argument list
    enclosed in parentheses:

<synopsis>
<replaceable>function</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional> )
</synopsis>
   </para>

   <para>
    For example, the following computes the square root of 2:
<programlisting>
sqrt(2)
</programlisting>
   </para>

   <para>
    The list of built-in functions is in <xref linkend="functions">.
    Other functions can be added by the user.
   </para>
  </sect2>

  <sect2 id="syntax-aggregates">
   <title>Aggregate Expressions</title>

   <indexterm zone="syntax-aggregates">
    <primary>aggregate function</primary>
    <secondary>invocation</secondary>
   </indexterm>

   <para>
    An <firstterm>aggregate expression</firstterm> represents the
    application of an aggregate function across the rows selected by a
    query.  An aggregate function reduces multiple inputs to a single
    output value, such as the sum or average of the inputs.  The
    syntax of an aggregate expression is one of the following:

<synopsis>
<replaceable>aggregate_name</replaceable> (<replaceable>expression</replaceable> [ , ... ] )
<replaceable>aggregate_name</replaceable> (ALL <replaceable>expression</replaceable> [ , ... ] )
<replaceable>aggregate_name</replaceable> (DISTINCT <replaceable>expression</replaceable> [ , ... ] )
<replaceable>aggregate_name</replaceable> ( * )
</synopsis>

    where <replaceable>aggregate_name</replaceable> is a previously
    defined aggregate (possibly qualified with a schema name), and
    <replaceable>expression</replaceable> is
    any value expression that does not itself contain an aggregate
    expression.
   </para>

   <para>
    The first form of aggregate expression invokes the aggregate
    across all input rows for which the given expression(s) yield
    non-null values.  (Actually, it is up to the aggregate function
    whether to ignore null values or not &mdash; but all the standard ones do.)
    The second form is the same as the first, since
    <literal>ALL</literal> is the default.  The third form invokes the
    aggregate for all distinct non-null values of the expressions found
    in the input rows.  The last form invokes the aggregate once for
    each input row regardless of null or non-null values; since no
    particular input value is specified, it is generally only useful
    for the <function>count(*)</function> aggregate function.
   </para>

   <para>
    For example, <literal>count(*)</literal> yields the total number
    of input rows; <literal>count(f1)</literal> yields the number of
    input rows in which <literal>f1</literal> is non-null;
    <literal>count(distinct f1)</literal> yields the number of
    distinct non-null values of <literal>f1</literal>.
   </para>

   <para>
    The predefined aggregate functions are described in <xref
    linkend="functions-aggregate">.  Other aggregate functions can be added
    by the user.
   </para>

   <para>
    An aggregate expression can only appear in the result list or
    <literal>HAVING</> clause of a <command>SELECT</> command.
    It is forbidden in other clauses, such as <literal>WHERE</>,
    because those clauses are logically evaluated before the results
    of aggregates are formed.
   </para>

   <para>
    When an aggregate expression appears in a subquery (see
    <xref linkend="sql-syntax-scalar-subqueries"> and
    <xref linkend="functions-subquery">), the aggregate is normally
    evaluated over the rows of the subquery.  But an exception occurs
    if the aggregate's arguments contain only outer-level variables:
    the aggregate then belongs to the nearest such outer level, and is
    evaluated over the rows of that query.  The aggregate expression
    as a whole is then an outer reference for the subquery it appears in,
    and acts as a constant over any one evaluation of that subquery.
    The restriction about
    appearing only in the result list or <literal>HAVING</> clause
    applies with respect to the query level that the aggregate belongs to.
   </para>

   <note>
    <para>
     <productname>PostgreSQL</productname> currently does not support
     <literal>DISTINCT</> with more than one input expression.
    </para>
   </note>
  </sect2>

  <sect2 id="sql-syntax-type-casts">
   <title>Type Casts</title>

   <indexterm>
    <primary>data type</primary>
    <secondary>type cast</secondary>
   </indexterm>

   <indexterm>
    <primary>type cast</primary>
   </indexterm>

   <para>
    A type cast specifies a conversion from one data type to another.
    <productname>PostgreSQL</productname> accepts two equivalent syntaxes
    for type casts:
<synopsis>
CAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> )
<replaceable>expression</replaceable>::<replaceable>type</replaceable>
</synopsis>
    The <literal>CAST</> syntax conforms to SQL; the syntax with
    <literal>::</literal> is historical <productname>PostgreSQL</productname>
    usage.
   </para>

   <para>
    When a cast is applied to a value expression of a known type, it
    represents a run-time type conversion.  The cast will succeed only
    if a suitable type conversion operation has been defined.  Notice that this
    is subtly different from the use of casts with constants, as shown in
    <xref linkend="sql-syntax-constants-generic">.  A cast applied to an
    unadorned string literal represents the initial assignment of a type
    to a literal constant value, and so it will succeed for any type
    (if the contents of the string literal are acceptable input syntax for the
    data type).
   </para>

   <para>
    An explicit type cast can usually be omitted if there is no ambiguity as
    to the type that a value expression must produce (for example, when it is
    assigned to a table column); the system will automatically apply a
    type cast in such cases.  However, automatic casting is only done for
    casts that are marked <quote>OK to apply implicitly</>
    in the system catalogs.  Other casts must be invoked with
    explicit casting syntax.  This restriction is intended to prevent
    surprising conversions from being applied silently.
   </para>

   <para>
    It is also possible to specify a type cast using a function-like
    syntax:
<synopsis>
<replaceable>typename</replaceable> ( <replaceable>expression</replaceable> )
</synopsis>
    However, this only works for types whose names are also valid as
    function names.  For example, <literal>double precision</literal>
    cannot be used this way, but the equivalent <literal>float8</literal>
    can.  Also, the names <literal>interval</>, <literal>time</>, and
    <literal>timestamp</> can only be used in this fashion if they are
    double-quoted, because of syntactic conflicts.  Therefore, the use of
    the function-like cast syntax leads to inconsistencies and should
    probably be avoided in new applications.
   </para>

   <note>
    <para>
     The function-like syntax is in fact just a function call.  When
     one of the two standard cast syntaxes is used to do a run-time
     conversion, it will internally invoke a registered function to
     perform the conversion.  By convention, these conversion functions
     have the same name as their output type, and thus the <quote>function-like
     syntax</> is nothing more than a direct invocation of the underlying
     conversion function.  Obviously, this is not something that a portable
     application should rely on.  For further details see
     <xref linkend="sql-createcast" endterm="sql-createcast-title">.
    </para>
   </note>
  </sect2>

  <sect2 id="sql-syntax-scalar-subqueries">
   <title>Scalar Subqueries</title>

   <indexterm>
    <primary>subquery</primary>
   </indexterm>

   <para>
    A scalar subquery is an ordinary
    <command>SELECT</command> query in parentheses that returns exactly one
    row with one column.  (See <xref linkend="queries"> for information about writing queries.)
    The <command>SELECT</command> query is executed
    and the single returned value is used in the surrounding value expression.
    It is an error to use a query that
    returns more than one row or more than one column as a scalar subquery.
    (But if, during a particular execution, the subquery returns no rows,
    there is no error; the scalar result is taken to be null.)
    The subquery can refer to variables from the surrounding query,
    which will act as constants during any one evaluation of the subquery.
    See also <xref linkend="functions-subquery"> for other expressions involving subqueries.
   </para>

   <para>
    For example, the following finds the largest city population in each
    state:
<programlisting>
SELECT name, (SELECT max(pop) FROM cities WHERE cities.state = states.name)
    FROM states;
</programlisting>
   </para>
  </sect2>

  <sect2 id="sql-syntax-array-constructors">
   <title>Array Constructors</title>

   <indexterm>
    <primary>array</primary>
    <secondary>constructor</secondary>
   </indexterm>

   <indexterm>
    <primary>ARRAY</primary>
   </indexterm>

   <para>
    An array constructor is an expression that builds an
    array value from values for its member elements.  A simple array
    constructor
    consists of the key word <literal>ARRAY</literal>, a left square bracket
    <literal>[</>, a list of expressions (separated by commas) for the
    array element values, and finally a right square bracket <literal>]</>.
    For example:
<programlisting>
SELECT ARRAY[1,2,3+4];
  array
---------
 {1,2,7}
(1 row)
</programlisting>
    By default,
    the array element type is the common type of the member expressions,
    determined using the same rules as for <literal>UNION</> or
    <literal>CASE</> constructs (see <xref linkend="typeconv-union-case">).
    You can override this by explicitly casting the array constructor to the
    desired type, for example:
<programlisting>
SELECT ARRAY[1,2,22.7]::integer[];
  array
----------
 {1,2,23}
(1 row)
</programlisting>
    This has the same effect as casting each expression to the array
    element type individually.
    For more on casting, see <xref linkend="sql-syntax-type-casts">.
   </para>

   <para>
    Multidimensional array values can be built by nesting array
    constructors.
    In the inner constructors, the key word <literal>ARRAY</literal> can
    be omitted.  For example, these produce the same result:

<programlisting>
SELECT ARRAY[ARRAY[1,2], ARRAY[3,4]];
     array
---------------
 {{1,2},{3,4}}
(1 row)

SELECT ARRAY[[1,2],[3,4]];
     array
---------------
 {{1,2},{3,4}}
(1 row)
</programlisting>

    Since multidimensional arrays must be rectangular, inner constructors
    at the same level must produce sub-arrays of identical dimensions.
    Any cast applied to the outer <literal>ARRAY</> constructor propagates
    automatically to all the inner constructors.
  </para>

  <para>
    Multidimensional array constructor elements can be anything yielding
    an array of the proper kind, not only a sub-<literal>ARRAY</> construct.
    For example:
<programlisting>
CREATE TABLE arr(f1 int[], f2 int[]);

INSERT INTO arr VALUES (ARRAY[[1,2],[3,4]], ARRAY[[5,6],[7,8]]);

SELECT ARRAY[f1, f2, '{{9,10},{11,12}}'::int[]] FROM arr;
                     array
------------------------------------------------
 {{{1,2},{3,4}},{{5,6},{7,8}},{{9,10},{11,12}}}
(1 row)
</programlisting>
  </para>

  <para>
   You can construct an empty array, but since it's impossible to have an
   array with no type, you must explicitly cast your empty array to the
   desired type.  For example:
<programlisting>
SELECT ARRAY[]::integer[];
 array
-------
 {}
(1 row)
</programlisting>
  </para>

  <para>
   It is also possible to construct an array from the results of a
   subquery.  In this form, the array constructor is written with the
   key word <literal>ARRAY</literal> followed by a parenthesized (not
   bracketed) subquery. For example:
<programlisting>
SELECT ARRAY(SELECT oid FROM pg_proc WHERE proname LIKE 'bytea%');
                          ?column?
-------------------------------------------------------------
 {2011,1954,1948,1952,1951,1244,1950,2005,1949,1953,2006,31}
(1 row)
</programlisting>
   The subquery must return a single column. The resulting
   one-dimensional array will have an element for each row in the
   subquery result, with an element type matching that of the
   subquery's output column.
  </para>

  <para>
   The subscripts of an array value built with <literal>ARRAY</literal>
   always begin with one.  For more information about arrays, see
   <xref linkend="arrays">.
  </para>

  </sect2>

  <sect2 id="sql-syntax-row-constructors">
   <title>Row Constructors</title>

   <indexterm>
    <primary>composite type</primary>
    <secondary>constructor</secondary>
   </indexterm>

   <indexterm>
    <primary>row type</primary>
    <secondary>constructor</secondary>
   </indexterm>

   <indexterm>
    <primary>ROW</primary>
   </indexterm>

   <para>
    A row constructor is an expression that builds a row value (also
    called a composite value) from values
    for its member fields.  A row constructor consists of the key word
    <literal>ROW</literal>, a left parenthesis, zero or more
    expressions (separated by commas) for the row field values, and finally
    a right parenthesis.  For example:
<programlisting>
SELECT ROW(1,2.5,'this is a test');
</programlisting>
    The key word <literal>ROW</> is optional when there is more than one
    expression in the list.
   </para>

   <para>
    A row constructor can include the syntax
    <replaceable>rowvalue</replaceable><literal>.*</literal>,
    which will be expanded to a list of the elements of the row value,
    just as occurs when the <literal>.*</> syntax is used at the top level
    of a <command>SELECT</> list.  For example, if table <literal>t</> has
    columns <literal>f1</> and <literal>f2</>, these are the same:
<programlisting>
SELECT ROW(t.*, 42) FROM t;
SELECT ROW(t.f1, t.f2, 42) FROM t;
</programlisting>
   </para>

   <note>
    <para>
     Before <productname>PostgreSQL</productname> 8.2, the
     <literal>.*</literal> syntax was not expanded, so that writing
     <literal>ROW(t.*, 42)</> created a two-field row whose first field
     was another row value.  The new behavior is usually more useful.
     If you need the old behavior of nested row values, write the inner
     row value without <literal>.*</literal>, for instance
     <literal>ROW(t, 42)</>.
    </para>
   </note>

   <para>
    By default, the value created by a <literal>ROW</> expression is of
    an anonymous record type.  If necessary, it can be cast to a named
    composite type &mdash; either the row type of a table, or a composite type
    created with <command>CREATE TYPE AS</>.  An explicit cast might be needed
    to avoid ambiguity.  For example:
<programlisting>
CREATE TABLE mytable(f1 int, f2 float, f3 text);

CREATE FUNCTION getf1(mytable) RETURNS int AS 'SELECT $1.f1' LANGUAGE SQL;

-- No cast needed since only one getf1() exists
SELECT getf1(ROW(1,2.5,'this is a test'));
 getf1
-------
     1
(1 row)

CREATE TYPE myrowtype AS (f1 int, f2 text, f3 numeric);

CREATE FUNCTION getf1(myrowtype) RETURNS int AS 'SELECT $1.f1' LANGUAGE SQL;

-- Now we need a cast to indicate which function to call:
SELECT getf1(ROW(1,2.5,'this is a test'));
ERROR:  function getf1(record) is not unique

SELECT getf1(ROW(1,2.5,'this is a test')::mytable);
 getf1
-------
     1
(1 row)

SELECT getf1(CAST(ROW(11,'this is a test',2.5) AS myrowtype));
 getf1
-------
    11
(1 row)
</programlisting>
  </para>

  <para>
   Row constructors can be used to build composite values to be stored
   in a composite-type table column, or to be passed to a function that
   accepts a composite parameter.  Also,
   it is possible to compare two row values or test a row with
   <literal>IS NULL</> or <literal>IS NOT NULL</>, for example:
<programlisting>
SELECT ROW(1,2.5,'this is a test') = ROW(1, 3, 'not the same');

SELECT ROW(table.*) IS NULL FROM table;  -- detect all-null rows
</programlisting>
   For more detail see <xref linkend="functions-comparisons">.
   Row constructors can also be used in connection with subqueries,
   as discussed in <xref linkend="functions-subquery">.
  </para>

  </sect2>

  <sect2 id="syntax-express-eval">
   <title>Expression Evaluation Rules</title>

   <indexterm>
    <primary>expression</primary>
    <secondary>order of evaluation</secondary>
   </indexterm>

   <para>
    The order of evaluation of subexpressions is not defined.  In
    particular, the inputs of an operator or function are not necessarily
    evaluated left-to-right or in any other fixed order.
   </para>

   <para>
    Furthermore, if the result of an expression can be determined by
    evaluating only some parts of it, then other subexpressions
    might not be evaluated at all.  For instance, if one wrote:
<programlisting>
SELECT true OR somefunc();
</programlisting>
    then <literal>somefunc()</literal> would (probably) not be called
    at all. The same would be the case if one wrote:
<programlisting>
SELECT somefunc() OR true;
</programlisting>
    Note that this is not the same as the left-to-right
    <quote>short-circuiting</quote> of Boolean operators that is found
    in some programming languages.
   </para>

   <para>
    As a consequence, it is unwise to use functions with side effects
    as part of complex expressions.  It is particularly dangerous to
    rely on side effects or evaluation order in <literal>WHERE</> and <literal>HAVING</> clauses,
    since those clauses are extensively reprocessed as part of
    developing an execution plan.  Boolean
    expressions (<literal>AND</>/<literal>OR</>/<literal>NOT</> combinations) in those clauses can be reorganized
    in any manner allowed by the laws of Boolean algebra.
   </para>

   <para>
    When it is essential to force evaluation order, a <literal>CASE</>
    construct (see <xref linkend="functions-conditional">) can be
    used.  For example, this is an untrustworthy way of trying to
    avoid division by zero in a <literal>WHERE</> clause:
<programlisting>
SELECT ... WHERE x &gt; 0 AND y/x &gt; 1.5;
</programlisting>
    But this is safe:
<programlisting>
SELECT ... WHERE CASE WHEN x &gt; 0 THEN y/x &gt; 1.5 ELSE false END;
</programlisting>
    A <literal>CASE</> construct used in this fashion will defeat optimization
    attempts, so it should only be done when necessary.  (In this particular
    example, it would be better to sidestep the problem by writing
    <literal>y &gt; 1.5*x</> instead.)
   </para>
  </sect2>
 </sect1>

</chapter>