Documentation
 
 
 

Chapter 3. SQL Syntax

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.

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 EnterpriseDB.

3.1. Lexical Structure

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

A token can be a key word, an identifier, a quoted identifier, a literal (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).

Additionally, comments can occur in SQL input. They are not tokens, they are effectively equivalent to whitespace.

For example, the following is (syntactically) valid SQL input:

SELECT * FROM EMP;
UPDATE EMP SET SAL = 500;
INSERT INTO EMP VALUES (7369, 'SMITH','CLERK',7902,'17-DEC-84',800,NULL,20);

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).

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 names, so in the above example we would usually speak of a "SELECT", an "UPDATE", and an "INSERT" command. For instance the UPDATE command always requires a SET token to appear in a certain position, and this particular variation of INSERT also requires a VALUES in order to be complete. The precise syntax rules for each command are described in Reference.

3.1.1. Identifiers and Key Words

Tokens such as SELECT, UPDATE, or VALUES in the example above are examples of key words, that is, words that have a fixed meaning in the SQL language. The tokens emp and dept are examples of identifiers. They identify names of tables, columns, or other database objects, depending on the command they are used in. Therefore they are sometimes simply called "names". 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.

SQL identifiers and key words must begin with a letter (a-z, but also letters with diacritical marks and non-Latin letters) or an underscore (_). Subsequent characters in an identifier or key word can be letters, underscores, digits (0-9), or dollar signs ($). Note that dollar signs are not allowed in identifiers according to the letter of the SQL standard, so their use may 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.

Identifier and key word names are case insensitive. Therefore

UPDATE EMP SET sal = 500;

can equivalently be written as

uPDaTE EmP SeT sAL = 500;

A convention often used is to write key words in upper case and names in lower case, e.g.,

UPDATE emp SET sal = 500;

There is a second kind of identifier: the delimited identifier or quoted identifier. It is formed by enclosing an arbitrary sequence of characters in double-quotes ("). A delimited identifier is always an identifier, never a key word. So "select" could be used to refer to a column or table named "select", whereas an unquoted select 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:

UPDATE "emp" SET "sal" = 500;

Quoted identifiers can contain any character other than a double quote itself. (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.

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

3.1.2. Constants

The following sub-sections discuss the constant types supported by EnterpriseDB:

3.1.2.1. String Constants

A string constant in SQL is an arbitrary sequence of characters bounded by single quotes ('), for example 'This is a string'. The standard-compliant way of writing a single-quote character within a string constant is to write two adjacent single quotes, e.g. 'Dianne''s horse'. EnterpriseDB also allows single quotes to be escaped with a backslash (\), so for example the same string could be written 'Dianne\'s horse'.

Another EnterpriseDB extension is that C-style backslash escapes are available: \b is a backspace, \f is a form feed, \n is a newline, \r is a carriage return, \t is a tab, and \xxx, where xxx is an octal number, is a byte with the corresponding code. (It is your responsibility that the byte sequences you create are valid characters in the server character set encoding.) Any other character following a backslash is taken literally. Thus, to include a backslash in a string constant, write two backslashes.

The character with the code zero cannot be in a string constant.

Two string constants that are only separated by whitespace with at least one newline are concatenated and effectively treated as if the string had been written in one constant. For example:

SELECT 'foo'
'bar';

is equivalent to

SELECT 'foobar';

but

SELECT 'foo'      'bar';

is not valid syntax. (This slightly bizarre behavior is specified by SQL; EnterpriseDB is following the standard.)

3.1.2.2. Numeric Constants

Numeric constants are accepted in these general forms:

digits
digits.[digits][e[+-]digits]
[digits].digits[e[+-]digits]
digitse[+-]digits

where digits 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 (e), if one is present. There may not 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.

These are some examples of valid numeric constants:

42
3.5
4.
.001
5e2
1.925e-3

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

You can read more details about Numeric Constants in Section 14.1.5

3.1.3. Operators

An operator name is a sequence of up to NAMEDATALEN-1 (63 by default) characters from the following list:

+ - * / < > = ~ ! @ # % ^ & | ` ?

There are a few restrictions on operator names, however:

  • -- and /* cannot appear anywhere in an operator name, since they will be taken as the start of a comment.

  • A multiple-character operator name cannot end in + or -, unless the name also contains at least one of these characters:

    ~ ! @ # % ^ & | ` ?

    For example, @- is an allowed operator name, but *- is not. This restriction allows EnterpriseDB to parse SQL-compliant queries without requiring spaces between tokens.

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 @, you cannot write X*@Y; you must write X* @Y to ensure that EnterpriseDB reads it as two operator names and not one.

3.1.4. Special Characters

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.

  • Parentheses (()) 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.

  • Brackets ([]) are used to select the elements of an array.

  • Commas (,) are used in some syntactical constructs to separate the elements of a list.

  • The semicolon (;) terminates an SQL command. It cannot appear anywhere within a command, except within a string constant or quoted identifier.

  • The asterisk (*) has a special meaning when used in the SELECT command or with the COUNT aggregate function.

  • The period (.) is used in numeric nconstants, and to separate schema, table, and column names.

3.1.5. Comments

A comment is an arbitrary sequence of characters beginning with double dashes and extending to the end of the line, e.g.:

-- This is a standard SQL comment

Alternatively, C-style block comments can be used:

/* multiline comment
 * with nesting: /* nested block comment */
 */

where the comment begins with /* and extends to the matching occurrence of */. These block comments nest, as specified in the SQL standard but unlike C, so that one can comment out larger blocks of code that may contain existing block comments.

The following statements contain many comments utilizing both of the above mentioned commenting styles.


 SELECT ename, sal + NVL(comm, 0), job, e.deptno
      /* Select all employees whose compensation is
      greater than that of Smith.*/
      FROM emp e, dept d
      /*The DEPARTMENTS table is used to get the department name.*/
      WHERE e.deptno = d.deptno
      AND sal + NVL(comm,0) > /* Subquery: */
      (SELECT sal + NVL(comm,0)
      /* total compensation is salary + comm */
      FROM emp
      WHERE ename = 'Smith');
      SELECT ename, -- select the name
      sal + NVL(comm, 0),-- total compensation
      job, -- job
      e.deptno -- and department
      FROM emp e, -- of all employees
      dept d
      WHERE e.deptno = d.deptno
      AND sal + NVL(comm, 0) > -- whose compensation
      -- is greater than
      (SELECT sal + NVL(comm,0) -- the compensation
      FROM emp
      WHERE ename = 'Smith')  -- of Smith
      ;
      

A comment is removed from the input stream before further syntax analysis and is effectively replaced by whitespace.

3.1.6. Lexical Precedence

Table 3-1 shows the precedence and associativity of the operators in EnterpriseDB. Most operators have the same precedence and are left-associative. The precedence and associativity of the operators is hard-wired into the parser. This may lead to non-intuitive behavior; for example the Boolean operators < and > have a different precedence than the Boolean operators <= and >=. Also, you will sometimes need to add parentheses when using combinations of binary and unary operators. For instance

SELECT 5 ! - 6;

will be parsed as

SELECT 5 ! (- 6);

because the parser has no idea - until it is too late - that ! is defined as a postfix operator, not an infix one. To get the desired behavior in this case, you must write

SELECT (5 !) - 6;

This is the price one pays for extensibility.

Table 3-1. Operator Precedence (decreasing)

Operator/ElementAssociativityDescription
.lefttable/column name separator
-rightunary minus
^leftexponentiation
* / %leftmultiplication, division, modulo
+ -leftaddition, subtraction
IS IS TRUE, IS FALSE, IS UNKNOWN, IS NULL
ISNULL test for null
NOTNULL test for not null
(any other)leftall other native and user-defined operators
IN set membership
BETWEEN containment
LIKE ILIKE SIMILAR string pattern matching
< > less than, greater than
=rightequality, assignment
NOTrightlogical negation
ANDleftlogical conjunction
ORleftlogical disjunction

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 "+" operator for some custom data type it will have the same precedence as the built-in "+" operator, no matter what yours does.

 
 ©2004-2007 EnterpriseDB All Rights Reserved