SQL
  
   
    This chapter introduces the mathematical concepts behind
    relational databases. It is not required reading, so if you bog
    down or want to get straight to some simple examples feel free to
    jump ahead to the next chapter and come back when you have more
    time and patience. This stuff is supposed to be fun!
   
   
    This material originally appeared as a part of
    Stefan Simkovics' Master's Thesis
    ().
   
  
  
   SQL has become the most popular relational query
   language.
   The name SQL
 is an abbreviation for
   Structured Query Language.
   In 1974 Donald Chamberlin and others defined the
   language SEQUEL (Structured English Query
    Language) at IBM
   Research. This language was first implemented in an IBM
   prototype called SEQUEL-XRM in 1974-75. In 1976-77 a revised version
   of SEQUEL called SEQUEL/2 was defined and the name was changed to
   SQL
   subsequently.
  
  
   A new prototype called System R was developed by IBM in 1977. System R
   implemented a large subset of SEQUEL/2 (now SQL)
   and a number of
   changes were made to SQL during the project.
   System R was installed in
   a number of user sites, both internal IBM sites and also some selected
   customer sites. Thanks to the success and acceptance of System R at
   those user sites IBM started to develop commercial products that
   implemented the SQL language based on the System
   R technology.
  
  
   Over the next years IBM and also a number of other vendors announced
   SQL products such as
   SQL/DS (IBM),
   DB2 (IBM),
   ORACLE (Oracle Corp.),
   DG/SQL (Data General Corp.),
   and SYBASE (Sybase Inc.).
  
  
   SQL is also an official standard now. In 1982
   the American National
   Standards Institute (ANSI) chartered its
   Database Committee X3H2 to
   develop a proposal for a standard relational language. This proposal
   was ratified in 1986 and consisted essentially of the IBM dialect of
   SQL. In 1987 this ANSI
   standard was also accepted as an international
   standard by the International Organization for Standardization
   (ISO).
   This original standard version of SQL is often
   referred to,
   informally, as SQL/86
. In 1989 the original
   standard was extended
   and this new standard is often, again informally, referred to as
   SQL/89
. Also in 1989, a related standard called
   Database Language Embedded SQL
   (ESQL) was developed.
  
  
   The ISO and ANSI committees
   have been working for many years on the
   definition of a greatly expanded version of the original standard,
   referred to informally as SQL2
   or SQL/92. This version became a
   ratified standard - International Standard ISO/IEC 9075:1992,
   Database Language SQL
 - in late 1992.
   SQL/92 is the version
   normally meant when people refer to the SQL
   standard
. A detailed
   description of SQL/92 is given in
   . At the time of
   writing this document a new standard informally referred to
   as SQL3
   is under development. It is planned to make SQL
   a Turing-complete
   language, i.e., all computable queries (e.g., recursive queries) will be
   possible. This has now been completed as SQL:2003.
  
  
   The Relational Data Model
  
    As mentioned before, SQL is a relational
    language. That means it is
    based on the relational data model
    first published by E.F. Codd in
    1970. We will give a formal description of the relational model
    later (in
    )
    but first we want to have a look at it from a more intuitive
    point of view.
  
  
    A relational database is a database that is
    perceived by its
    users as a collection of tables (and
    nothing else but tables).
    A table consists of rows and columns where each row represents a
    record and each column represents an attribute of the records
    contained in the table.
    
    shows an example of a database consisting of three tables:
    
     
      
       SUPPLIER is a table storing the number
       (SNO), the name (SNAME) and the city (CITY) of a supplier.
      
     
     
      
       PART is a table storing the number (PNO) the name (PNAME) and
       the price (PRICE) of a part.
      
     
     
      
       SELLS stores information about which part (PNO) is sold by which
       supplier (SNO).
       It serves in a sense to connect the other two tables together.
      
     
    
    
     The Suppliers and Parts Database
SUPPLIER:                   SELLS:
 SNO |  SNAME  |  CITY       SNO | PNO
----+---------+--------     -----+-----
 1  |  Smith  | London        1  |  1
 2  |  Jones  | Paris         1  |  2
 3  |  Adams  | Vienna        2  |  4
 4  |  Blake  | Rome          3  |  1
                              3  |  3
                              4  |  2
PART:                         4  |  3
 PNO |  PNAME  |  PRICE       4  |  4
----+---------+---------
 1  |  Screw  |   10
 2  |  Nut    |    8
 3  |  Bolt   |   15
 4  |  Cam    |   25
    
   
   
    The tables PART and SUPPLIER can be regarded as
    entities and
    SELLS can be regarded as a relationship
    between a particular
    part and a particular supplier.
   
   
    As we will see later, SQL operates on tables
    like the ones just
    defined but before that we will study the theory of the relational
    model.
   
  
  
   Relational Data Model Formalities
   
    The mathematical concept underlying the relational model is the
    set-theoretic relation which is a subset of
    the Cartesian
    product of a list of domains. This set-theoretic relation gives
    the model its name (do not confuse it with the relationship from the
    Entity-Relationship model).
    Formally a domain is simply a set of
    values. For example the set of integers is a domain. Also the set of
    character strings of length 20 and the real numbers are examples of
    domains.
   
   
    The Cartesian product of domains
    D1,
    D2,
    ...
    Dk,
    written
    D1 ×
    D2 ×
    ... ×
    Dk
    is the set of all k-tuples
    v1,
    v2,
    ...
    vk,
    such that
    v1 ∈
    D1,
    v2 ∈
    D2,
    ...
    vk ∈
    Dk.
   
   
    For example, when we have
    k=2,
    D1={0,1} and
    D2={a,b,c} then
    D1 ×
    D2 is
    {(0,a),(0,b),(0,c),(1,a),(1,b),(1,c)}.
   
   
    A Relation is any subset of the Cartesian product of one or more
    domains: R ⊆
    D1 ×
    D2 ×
    ... ×
    Dk.
   
   
    For example {(0,a),(0,b),(1,a)} is a relation;
    it is in fact a subset of
    D1 ×
    D2
    mentioned above.
   
   
    The members of a relation are called tuples. Each relation of some
    Cartesian product
    D1 ×
    D2 ×
    ... ×
    Dk
    is said to have arity k and is therefore a set
    of k-tuples.
   
   
    A relation can be viewed as a table (as we already did, remember
     where
    every tuple is represented by a row and every column corresponds to
    one component of a tuple. Giving names (called attributes) to the
    columns leads to the definition of a
    relation scheme.
   
   
    A relation scheme R is a
    finite set of attributes
    A1,
    A2,
    ...
    Ak.
    There is a domain
    Di,
    for each attribute
    Ai,
    1 <= i <= k,
    where the values of the attributes are taken from. We often write
    a relation scheme as
    R(A1,
    A2,
    ...
    Ak).
    
     
      A relation scheme is just a kind of template
      whereas a relation is an instance of a
      relation
       scheme. The relation consists of tuples (and can
      therefore be
      viewed as a table); not so the relation scheme.
     
    
   
   
    Domains vs. Data Types
    
     We often talked about domains
     in the last section. Recall that a
     domain is, formally, just a set of values (e.g., the set of integers or
     the real numbers). In terms of database systems we often talk of
     data types instead of domains.
     When we define a table we have to make
     a decision about which attributes to include. Additionally we
     have to decide which kind of data is going to be stored as
     attribute values. For example the values of
     SNAME from the table
     SUPPLIER will be character strings,
     whereas SNO will store
     integers. We define this by assigning a data type to each
     attribute. The type of SNAME will be
     VARCHAR(20) (this is the SQL type
     for character strings of length <= 20),
     the type of SNO will be
     INTEGER. With the assignment of a data type we also
     have selected
     a domain for an attribute. The domain of
     SNAME is the set of all
     character strings of length <= 20,
     the domain of SNO is the set of
     all integer numbers.
    
   
  
  
   Operations in the Relational Data Model
   
    In the previous section
    ()
    we defined the mathematical notion of
    the relational model. Now we know how the data can be stored using a
    relational data model but we do not know what to do with all these
    tables to retrieve something from the database yet. For example somebody
    could ask for the names of all suppliers that sell the part
    'Screw'. Therefore two rather different kinds of notations for
    expressing operations on relations have been defined:
    
     
      
       The Relational Algebra which is an
       algebraic notation,
       where queries are expressed by applying specialized operators to the
       relations.
      
     
     
      
       The Relational Calculus which is a
       logical notation,
       where queries are expressed by formulating some logical restrictions
       that the tuples in the answer must satisfy.
      
    
    
   
   
    Relational Algebra
    
     The Relational Algebra was introduced by
     E. F. Codd in 1972. It consists of a set of operations on relations:
     
      
       
        SELECT (σ): extracts tuples from
        a relation that
        satisfy a given restriction. Let R be a
        table that contains an attribute
        A.
σA=a(R) = {t ∈ R ∣ t(A) = a}
        where t denotes a
        tuple of R and t(A)
        denotes the value of attribute A of
        tuple t.
       
      
      
       
        PROJECT (π): extracts specified
        attributes (columns) from a
        relation. Let R be a relation
        that contains an attribute X.
        πX(R) = {t(X) ∣ t ∈ R},
        where t(X) denotes the value of
        attribute X of tuple t.
       
      
      
       
        PRODUCT (×): builds the Cartesian product of two
        relations. Let R be a table with arity
        k1 and let
        S be a table with
        arity k2.
        R × S
        is the set of all
        k1
        + k2-tuples
        whose first k1
        components form a tuple in R and whose last
        k2 components form a
        tuple in S.
       
      
      
       
        UNION (∪): builds the set-theoretic union of two
        tables. Given the tables R and
        S (both must have the same arity),
        the union R ∪ S
        is the set of tuples that are in R
        or S or both.
       
      
      
       
        INTERSECT (∩): builds the set-theoretic intersection of two
        tables. Given the tables R and
        S,
        R ∩ S is the
        set of tuples
        that are in R and in
        S.
        We again require that R and
        S have the
        same arity.
       
      
      
       
        DIFFERENCE (− or ∖): builds the set difference of
        two tables. Let R and S
        again be two tables with the same
        arity. R - S
        is the set of tuples in R but not in
        S.
       
      
      
       
        JOIN (∏): connects two tables by their common
        attributes. Let R be a table with the
        attributes A,B
        and C and
        let S be a table with the attributes
        C,D
        and E. There is one
        attribute common to both relations,
        the attribute C.
        R ∏ S = πR.A,R.B,R.C,S.D,S.E(σR.C=S.C(R × S)).
        What are we doing here? We first calculate the Cartesian
        product
        R × S.
        Then we select those tuples whose values for the common
        attribute C are equal
        (σR.C = S.C).
        Now we have a table
        that contains the attribute C
        two times and we correct this by
        projecting out the duplicate column.
       
       
        An Inner Join
        
         Let's have a look at the tables that are produced by evaluating the steps
         necessary for a join.
         Let the following two tables be given:
R:                 S:
 A | B | C          C | D | E
---+---+---        ---+---+---
 1 | 2 | 3          3 | a | b
 4 | 5 | 6          6 | c | d
 7 | 8 | 9
        
       
       
        First we calculate the Cartesian product
        R × S and
        get:
R x S:
 A | B | R.C | S.C | D | E
---+---+-----+-----+---+---
 1 | 2 |  3  |  3  | a | b
 1 | 2 |  3  |  6  | c | d
 4 | 5 |  6  |  3  | a | b
 4 | 5 |  6  |  6  | c | d
 7 | 8 |  9  |  3  | a | b
 7 | 8 |  9  |  6  | c | d
       
       
        After the selection
        σR.C=S.C(R × S)
        we get:
 A | B | R.C | S.C | D | E
---+---+-----+-----+---+---
 1 | 2 |  3  |  3  | a | b
 4 | 5 |  6  |  6  | c | d
       
       
        To remove the duplicate column
        S.C
        we project it out by the following operation:
        πR.A,R.B,R.C,S.D,S.E(σR.C=S.C(R × S))
        and get:
 A | B | C | D | E
---+---+---+---+---
 1 | 2 | 3 | a | b
 4 | 5 | 6 | c | d
       
      
      
       
        DIVIDE (÷): Let R be a table
        with the attributes A, B, C, and D and let
        S be a table with the attributes
        C and D.
        Then we define the division as:
R ÷ S = {t ∣ ∀ ts ∈ S ∃ tr ∈ R
        such that
tr(A,B)=t∧tr(C,D)=ts}
        where
        tr(x,y)
        denotes a
        tuple of table R that consists only of
        the components x and y.
        Note that the tuple t only consists of the
        components A and
        B of relation R.
       
       
        Given the following tables
R:                    S:
 A | B | C | D         C | D
---+---+---+---       ---+---
 a | b | c | d         c | d
 a | b | e | f         e | f
 b | c | e | f
 e | d | c | d
 e | d | e | f
 a | b | d | e
        R ÷ S
        is derived as
 A | B
---+---
 a | b
 e | d
       
      
     
    
    
     For a more detailed description and definition of the relational
     algebra refer to [] or
     [].
    
    
     A Query Using Relational Algebra
     
      Recall that we formulated all those relational operators to be able to
      retrieve data from the database. Let's return to our example from
      the previous
      section ()
      where someone wanted to know the names of all
      suppliers that sell the part Screw.
      This question can be answered
      using relational algebra by the following operation:
πSUPPLIER.SNAME(σPART.PNAME='Screw'(SUPPLIER ∏ SELLS ∏ PART))
     
     
      We call such an operation a query. If we evaluate the above query
      against the our example tables
      ()
      we will obtain the following result:
 SNAME
-------
 Smith
 Adams
     
    
   
   
    Relational Calculus
    
     The relational calculus is based on the
     first order logic. There are
     two variants of the relational calculus:
     
      
       
        The Domain Relational Calculus
        (DRC), where variables
        stand for components (attributes) of the tuples.
       
      
      
       
        The Tuple Relational Calculus
        (TRC), where variables stand for tuples.
       
      
     
    
    
     We want to discuss the tuple relational calculus only because it is
     the one underlying the most relational languages. For a detailed
     discussion on DRC (and also
     TRC) see
     
     or
     .
    
   
   
    Tuple Relational Calculus
    
     The queries used in TRC are of the following
     form:
x(A) ∣ F(x)
     where x is a tuple variable
     A is a set of attributes and F is a
     formula. The resulting relation consists of all tuples
     t(A) that satisfy F(t).
    
    
     If we want to answer the question from example
     
     using TRC we formulate the following query:
{x(SNAME) ∣ x ∈ SUPPLIER ∧
    ∃ y ∈ SELLS ∃ z ∈ PART (y(SNO)=x(SNO) ∧
    z(PNO)=y(PNO) ∧
    z(PNAME)='Screw')}
    
    
     Evaluating the query against the tables from
     
     again leads to the same result
     as in
     .
    
   
   
    Relational Algebra vs. Relational Calculus
    
     The relational algebra and the relational calculus have the same
     expressive power; i.e., all queries that
     can be formulated using relational algebra can also be formulated
     using the relational calculus and vice versa.
     This was first proved by E. F. Codd in
     1972. This proof is based on an algorithm (Codd's reduction
     algorithm
) by which an arbitrary expression of the relational
     calculus can be reduced to a semantically equivalent expression of
     relational algebra. For a more detailed discussion on that refer to
     
     and
     .
    
    
     It is sometimes said that languages based on the relational
     calculus are higher level
 or more
     declarative
 than languages based on relational algebra
     because the algebra (partially) specifies the order of operations
     while the calculus leaves it to a compiler or interpreter to
     determine the most efficient order of evaluation.
    
   
  
  
   The SQL Language
   
    As is the case with most modern relational languages,
    SQL is based on the tuple
    relational calculus. As a result every query that can be formulated
    using the tuple relational calculus (or equivalently, relational
    algebra) can also be formulated using
    SQL. There are, however,
    capabilities beyond the scope of relational algebra or calculus. Here
    is a list of some additional features provided by
    SQL that are not
    part of relational algebra or calculus:
    
     
      
       Commands for insertion, deletion or modification of data.
      
     
     
      
       Arithmetic capability: In SQL it is possible
       to involve
       arithmetic operations as well as comparisons, e.g.:
A < B + 3.
       Note
       that + or other arithmetic operators appear neither in relational
       algebra nor in relational calculus.
      
     
     
      
       Assignment and Print Commands: It is possible to print a
       relation constructed by a query and to assign a computed relation to a
       relation name.
      
     
     
      
       Aggregate Functions: Operations such as
       average, sum,
       max, etc. can be applied to columns of a
       relation to
       obtain a single quantity.
      
     
    
   
   
    Select
    
     The most often used command in SQL is the
     SELECT statement,
     used to retrieve data. The syntax is:
SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
    * | expression [ [ AS ] output_name ] [, ...]
    [ INTO [ TEMPORARY | TEMP ] [ TABLE ] new_table ]
    [ FROM from_item [, ...] ]
    [ WHERE condition ]
    [ GROUP BY expression [, ...] ]
    [ HAVING condition [, ...] ]
    [ { UNION | INTERSECT | EXCEPT } [ ALL ] select ]
    [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ]
    [ LIMIT { count | ALL } ]
    [ OFFSET start ]
    [ FOR { UPDATE | SHARE } [ OF table_name [, ...] ] [ NOWAIT ] [...] ]
    
    
     Now we will illustrate the complex syntax of the
     SELECT statement with various examples. The
     tables used for the examples are defined in .
    
    
     Simple Selects
     
      Here are some simple examples using a SELECT statement:
      
       Simple Query with Qualification
       
        To retrieve all tuples from table PART where the attribute PRICE is
        greater than 10 we formulate the following query:
SELECT * FROM PART
    WHERE PRICE > 10;
        and get the table:
 PNO |  PNAME  |  PRICE
-----+---------+--------
  3  |  Bolt   |   15
  4  |  Cam    |   25
       
       
        Using *
 in the SELECT statement
        will deliver all attributes from the table. If we want to retrieve
        only the attributes PNAME and PRICE from table PART we use the
        statement:
SELECT PNAME, PRICE
    FROM PART
    WHERE PRICE > 10;
        In this case the result is:
                      PNAME  |  PRICE
                     --------+--------
                      Bolt   |   15
                      Cam    |   25
        Note that the SQL SELECT
        corresponds to the projection
 in relational algebra
        not to the selection
 (see  for more details).
       
       
        The qualifications in the WHERE clause can also be logically connected
        using the keywords OR, AND, and NOT:
SELECT PNAME, PRICE
    FROM PART
    WHERE PNAME = 'Bolt' AND
         (PRICE = 0 OR PRICE <= 15);
        will lead to the result:
 PNAME  |  PRICE
--------+--------
 Bolt   |   15
       
       
        Arithmetic operations can be used in the target list and in the WHERE
        clause. For example if we want to know how much it would cost if we
        take two pieces of a part we could use the following query:
SELECT PNAME, PRICE * 2 AS DOUBLE
    FROM PART
    WHERE PRICE * 2 < 50;
        and we get:
 PNAME  |  DOUBLE
--------+---------
 Screw  |    20
 Nut    |    16
 Bolt   |    30
        Note that the word DOUBLE after the keyword AS is the new title of the
        second column. This technique can be used for every element of the
        target list to assign a new title to the resulting
        column. This new title
        is often referred to as alias. The alias cannot be used throughout the
        rest of the query.
       
      
     
    
    
     Joins
     
      The following example shows how joins are
      realized in SQL.
     
     
      To join the three tables SUPPLIER, PART and SELLS over their common
      attributes we formulate the following statement:
SELECT S.SNAME, P.PNAME
    FROM SUPPLIER S, PART P, SELLS SE
    WHERE S.SNO = SE.SNO AND
          P.PNO = SE.PNO;
      and get the following table as a result:
 SNAME | PNAME
-------+-------
 Smith | Screw
 Smith | Nut
 Jones | Cam
 Adams | Screw
 Adams | Bolt
 Blake | Nut
 Blake | Bolt
 Blake | Cam
     
     
      In the FROM clause we introduced an alias name for every relation
      because there are common named attributes (SNO and PNO) among the
      relations. Now we can distinguish between the common named attributes
      by simply prefixing the attribute name with the alias name followed by
      a dot. The join is calculated in the same way as shown in
      .
      First the Cartesian product
      SUPPLIER × PART × SELLS
      is derived. Now only those tuples satisfying the
      conditions given in the WHERE clause are selected (i.e., the common
      named attributes have to be equal). Finally we project out all
      columns but S.SNAME and P.PNAME.
     
     
     Another way to perform joins is to use the SQL JOIN syntax as follows:
SELECT sname, pname from supplier
    JOIN sells USING (sno)
    JOIN part USING (pno);
    giving again:
 sname | pname
-------+-------
 Smith | Screw
 Adams | Screw
 Smith | Nut
 Blake | Nut
 Adams | Bolt
 Blake | Bolt
 Jones | Cam
 Blake | Cam
(8 rows)
     
     
     A joined table, created using JOIN syntax, is a table reference list
     item that occurs in a FROM clause and before any WHERE, GROUP BY,
     or HAVING clause.  Other table references, including table names or
     other JOIN clauses, can be included in the FROM clause if separated
     by commas.  JOINed tables are logically like any other
     table listed in the FROM clause.
     
     
      SQL JOINs come in two main types, CROSS JOINs (unqualified joins)
      and qualified JOINs>.  Qualified joins can be further
      subdivided based on the way in which the join condition>
      is specified (ON, USING, or NATURAL) and the way in which it is
      applied (INNER or OUTER join).
     
    
        Join Types
        
            CROSS JOIN
            
            
                 T1 
                 CROSS JOIN 
                 T2 
            
            
            A cross join takes two tables T1 and T2 having N and M rows
            respectively, and returns a joined table containing all
            N*M possible joined rows. For each row R1 of T1, each row
            R2 of T2 is joined with R1 to yield a joined table row JR
            consisting of all fields in R1 and R2. A CROSS JOIN is
            equivalent to an INNER JOIN ON TRUE.
            
            
        
        
            Qualified JOINs
            
            
             T1 
             NATURAL 
            
                 INNER 
                
                
                     LEFT 
                     RIGHT 
                     FULL 
                
                 OUTER 
                    
                
             JOIN 
             T2 
            
                 ON search condition
                 USING ( join column list ) 
            
            
            
            A qualified JOIN must specify its join condition
            by providing one (and only one) of NATURAL, ON, or
            USING.  The ON clause
            takes a search condition,
            which is the same as in a WHERE clause.  The USING
            clause takes a comma-separated list of column names,
            which the joined tables must have in common, and joins
            the tables on equality of those columns.  NATURAL is
            shorthand for a USING clause that lists all the common
            column names of the two tables.  A side-effect of both
            USING and NATURAL is that only one copy of each joined
            column is emitted into the result table (compare the
            relational-algebra definition of JOIN, shown earlier).
            
            
            
            
                
                    
                         INNER 
                         JOIN 
                    
                
                
                
                For each row R1 of T1, the joined table has a row for each row
                in T2 that satisfies the join condition with R1.
                
                
                
                    The words INNER and OUTER are optional for all JOINs.
                    INNER is the default.  LEFT, RIGHT, and FULL imply an
                    OUTER JOIN.
                    
                
                
            
            
                
                    
                         LEFT 
                         OUTER 
                         JOIN 
                    
                
                
                
                First, an INNER JOIN is performed.
                Then, for each row in T1 that does not satisfy the join
                condition with any row in T2, an additional joined row is
                returned with null fields in the columns from T2.
                
                
                    
                    The joined table unconditionally has a row for each row in T1.
                    
                
                
            
            
                
                    
                         RIGHT 
                         OUTER 
                         JOIN 
                    
                
                
                
                First, an INNER JOIN is performed.
                Then, for each row in T2 that does not satisfy the join
                condition with any row in T1, an additional joined row is
                returned with null fields in the columns from T1.
                
                
                    
                    The joined table unconditionally has a row for each row in T2.
                    
                
                
            
            
                
                    
                         FULL 
                         OUTER 
                         JOIN 
                    
                
                
                
                First, an INNER JOIN is performed.
                Then, for each row in T1 that does not satisfy the join
                condition with any row in T2, an additional joined row is
                returned with null fields in the columns from T2.
                Also, for each row in T2 that does not satisfy the join
                condition with any row in T1, an additional joined row is
                returned with null fields in the columns from T1.
                
                
                    
                    The joined table unconditionally has a row for every row of T1
                    and a row for every row of T2.
                    
                
                
            
            
            
            
        
     
     
     JOINs of all types can be chained together or nested where either or both of
     T1 and
     T2 can be JOINed tables.
     Parenthesis can be used around JOIN clauses to control the order
     of JOINs which are otherwise processed left to right.
     
    
    
     Aggregate Functions
     
      SQL provides aggregate functions such as AVG,
      COUNT, SUM, MIN, and MAX.  The argument(s) of an aggregate function
      are evaluated at each row that satisfies the WHERE
      clause, and the aggregate function is calculated over this set
      of input values.  Normally, an aggregate delivers a single
      result for a whole SELECT statement.  But if
      grouping is specified in the query, then a separate calculation
      is done over the rows of each group, and an aggregate result is
      delivered per group (see next section).
      
       Aggregates
       
        If we want to know the average cost of all parts in table PART we use
        the following query:
SELECT AVG(PRICE) AS AVG_PRICE
    FROM PART;
       
       
        The result is:
 AVG_PRICE
-----------
   14.5
       
       
        If we want to know how many parts are defined in table PART we use
        the statement:
SELECT COUNT(PNO)
    FROM PART;
        and get:
 COUNT
-------
   4
       
      
     
    
    
     Aggregation by Groups
     
      SQL allows one to partition the tuples of a table
      into groups. Then the
      aggregate functions described above can be applied to the groups —
      i.e., the value of the aggregate function is no longer calculated over
      all the values of the specified column but over all values of a
      group. Thus the aggregate function is evaluated separately for every
      group.
     
     
      The partitioning of the tuples into groups is done by using the
      keywords GROUP BY followed by a list of
      attributes that define the
      groups. If we have
      GROUP BY A1, ⃛, Ak
      we partition
      the relation into groups, such that two tuples are in the same group
      if and only if they agree on all the attributes
      A1, ⃛, Ak.
      
       Aggregates
       
        If we want to know how many parts are sold by every supplier we
        formulate the query:
SELECT S.SNO, S.SNAME, COUNT(SE.PNO)
    FROM SUPPLIER S, SELLS SE
    WHERE S.SNO = SE.SNO
    GROUP BY S.SNO, S.SNAME;
        and get:
 SNO | SNAME | COUNT
-----+-------+-------
  1  | Smith |   2
  2  | Jones |   1
  3  | Adams |   2
  4  | Blake |   3
       
       
        Now let's have a look of what is happening here.
        First the join of the
        tables SUPPLIER and SELLS is derived:
 S.SNO | S.SNAME | SE.PNO
-------+---------+--------
   1   |  Smith  |   1
   1   |  Smith  |   2
   2   |  Jones  |   4
   3   |  Adams  |   1
   3   |  Adams  |   3
   4   |  Blake  |   2
   4   |  Blake  |   3
   4   |  Blake  |   4
       
       
        Next we partition the tuples into groups by putting all tuples
        together that agree on both attributes S.SNO and S.SNAME:
 S.SNO | S.SNAME | SE.PNO
-------+---------+--------
   1   |  Smith  |   1
                 |   2
--------------------------
   2   |  Jones  |   4
--------------------------
   3   |  Adams  |   1
                 |   3
--------------------------
   4   |  Blake  |   2
                 |   3
                 |   4
       
       
        In our example we got four groups and now we can apply the aggregate
        function COUNT to every group leading to the final result of the query
        given above.
       
      
     
     
      Note that for a query using GROUP BY and aggregate
      functions to make sense, the target list can only refer directly to
      the attributes being grouped by.  Other attributes can only be used
      inside the arguments of aggregate functions.  Otherwise there would
      not be a unique value to associate with the other attributes.
     
     
      Also observe that it makes no sense to ask for an aggregate of
      an aggregate, e.g., AVG(MAX(sno)), because a
      SELECT only does one pass of grouping and
      aggregation.  You can get a result of this kind by using a
      temporary table or a sub-SELECT in the FROM clause to do the
      first level of aggregation.
     
    
    
     Having
     
      The HAVING clause works much like the WHERE clause and is used to
      consider only those groups satisfying the qualification given in the
      HAVING clause.  Essentially, WHERE filters out unwanted input rows
      before grouping and aggregation are done, whereas HAVING filters out
      unwanted group rows post-GROUP.  Therefore, WHERE cannot refer to the
      results of aggregate functions.  On the other hand, there's no point
      in writing a HAVING condition that doesn't involve an aggregate
      function!  If your condition doesn't involve aggregates, you might
      as well write it in WHERE, and thereby avoid the computation of
      aggregates for groups that you're just going to throw away anyway.
      
       Having
       
        If we want only those suppliers selling more than one part we use the
        query:
SELECT S.SNO, S.SNAME, COUNT(SE.PNO)
    FROM SUPPLIER S, SELLS SE
    WHERE S.SNO = SE.SNO
    GROUP BY S.SNO, S.SNAME
    HAVING COUNT(SE.PNO) > 1;
        and get:
 SNO | SNAME | COUNT
-----+-------+-------
  1  | Smith |   2
  3  | Adams |   2
  4  | Blake |   3
       
      
     
    
    
     Subqueries
     
      In the WHERE and HAVING clauses the use of subqueries (subselects) is
      allowed in every place where a value is expected. In this case the
      value must be derived by evaluating the subquery first. The usage of
      subqueries extends the expressive power of
      SQL.
      
       Subselect
       
        If we want to know all parts having a greater price than the part
        named 'Screw' we use the query:
SELECT *
    FROM PART
    WHERE PRICE > (SELECT PRICE FROM PART
                   WHERE PNAME='Screw');
       
       
        The result is:
 PNO |  PNAME  |  PRICE
-----+---------+--------
  3  |  Bolt   |   15
  4  |  Cam    |   25
       
       
        When we look at the above query we can see the keyword
        SELECT two times. The first one at the
        beginning of the query - we will refer to it as outer
        SELECT - and the one in the WHERE clause which
        begins a nested query - we will refer to it as inner
        SELECT. For every tuple of the outer
        SELECT the inner SELECT has
        to be evaluated. After every evaluation we know the price of the
        tuple named 'Screw' and we can check if the price of the actual
        tuple is greater.  (Actually, in this example the inner query need
        only be evaluated once, since it does not depend on the state of
        the outer query.)
       
       
        If we want to know all suppliers that do not sell any part
        (e.g., to be able to remove these suppliers from the database) we use:
SELECT *
    FROM SUPPLIER S
    WHERE NOT EXISTS
        (SELECT * FROM SELLS SE
         WHERE SE.SNO = S.SNO);
       
       
        In our example the result will be empty because every supplier
        sells at least one part. Note that we use S.SNO from the outer
        SELECT within the WHERE clause of the inner
        SELECT. Here the subquery must be evaluated
        afresh for each tuple from the outer query, i.e., the value for
        S.SNO is always taken from the current tuple of the outer
        SELECT.
       
      
     
    
    
     Subqueries in FROM
     
      A somewhat different way of using subqueries is to put them in the
      FROM clause.  This is a useful feature because a subquery of this
      kind can output multiple columns and rows, whereas a subquery used
      in an expression must deliver just a single result.  It also lets
      us get more than one round of grouping/aggregation without resorting
      to a temporary table.
      
       Subselect in FROM
       
        If we want to know the highest average part price among all our
        suppliers, we cannot write MAX(AVG(PRICE)), but we can write:
SELECT MAX(subtable.avgprice)
    FROM (SELECT AVG(P.PRICE) AS avgprice
          FROM SUPPLIER S, PART P, SELLS SE
          WHERE S.SNO = SE.SNO AND
                P.PNO = SE.PNO
          GROUP BY S.SNO) subtable;
        The subquery returns one row per supplier (because of its GROUP BY)
        and then we aggregate over those rows in the outer query.
       
      
     
    
    
     Union, Intersect, Except
     
      These operations calculate the union, intersection and set theoretic
      difference of the tuples derived by two subqueries.
      
       Union, Intersect, Except
       
        The following query is an example for UNION:
SELECT S.SNO, S.SNAME, S.CITY
    FROM SUPPLIER S
    WHERE S.SNAME = 'Jones'
UNION
    SELECT S.SNO, S.SNAME, S.CITY
    FROM SUPPLIER S
    WHERE S.SNAME = 'Adams';
gives the result:
 SNO | SNAME |  CITY
-----+-------+--------
  2  | Jones | Paris
  3  | Adams | Vienna
       
       
        Here is an example for INTERSECT:
SELECT S.SNO, S.SNAME, S.CITY
    FROM SUPPLIER S
    WHERE S.SNO > 1
INTERSECT
    SELECT S.SNO, S.SNAME, S.CITY
    FROM SUPPLIER S
    WHERE S.SNO < 3;
        gives the result:
 SNO | SNAME |  CITY
-----+-------+--------
  2  | Jones | Paris
        The only tuple returned by both parts of the query is the one having SNO=2.
       
       
        Finally an example for EXCEPT:
SELECT S.SNO, S.SNAME, S.CITY
    FROM SUPPLIER S
    WHERE S.SNO > 1
EXCEPT
    SELECT S.SNO, S.SNAME, S.CITY
    FROM SUPPLIER S
    WHERE S.SNO > 3;
        gives the result:
 SNO | SNAME |  CITY
-----+-------+--------
  2  | Jones | Paris
  3  | Adams | Vienna
       
      
     
    
   
   
    Data Definition
    
     There is a set of commands used for data definition included in the
     SQL language.
    
    
     Create Table
     
      The most fundamental command for data definition is the
      one that creates a new relation (a new table). The syntax of the
      CREATE TABLE command is:
CREATE TABLE table_name
    (name_of_attr_1 type_of_attr_1
     [, name_of_attr_2 type_of_attr_2
     [, ...]]);
      
       Table Creation
       
        To create the tables defined in
         the
        following SQL statements are used:
CREATE TABLE SUPPLIER
    (SNO   INTEGER,
     SNAME VARCHAR(20),
     CITY  VARCHAR(20));
CREATE TABLE PART
    (PNO   INTEGER,
     PNAME VARCHAR(20),
     PRICE DECIMAL(4 , 2));
CREATE TABLE SELLS
    (SNO INTEGER,
     PNO INTEGER);
       
      
     
    
    
     Data Types in SQL
     
      The following is a list of some data types that are supported by
      SQL:
      
       
        
         INTEGER: signed fullword binary integer (31 bits precision).
        
       
       
        
         SMALLINT: signed halfword binary integer (15 bits precision).
        
       
       
        
         DECIMAL (p[,q]):
         signed packed decimal number of up to
         p
         digits, with
         q
         digits to the right of the decimal point.
         If q
         is omitted it is assumed to be 0.
        
       
       
        
         FLOAT: signed doubleword floating point number.
        
       
       
        
         VARCHAR(n):
         varying length character string of maximum length
         n.
        
       
       
        
         CHAR(n):
         fixed length character string of length
         n.
        
       
      
     
    
    
     Create Index
     
      Indexes are used to speed up access to a relation. If a relation R
      has an index on attribute A then we can
      retrieve all tuples t
      having
      t(A) = a
      in time roughly proportional to the number of such
      tuples t
      rather than in time proportional to the size of R.
     
     
      To create an index in SQL
      the CREATE INDEX command is used. The syntax is:
CREATE INDEX index_name
    ON table_name ( name_of_attribute );
     
     
      
       Create Index
       
        To create an index named I on attribute SNAME of relation SUPPLIER
        we use the following statement:
CREATE INDEX I ON SUPPLIER (SNAME);
     
       
        The created index is maintained automatically, i.e., whenever a new
        tuple is inserted into the relation SUPPLIER the index I is
        adapted. Note that the only changes a user can perceive when an
        index is present are increased speed for SELECT
        and decreases in speed of updates.
       
      
     
    
    
     Create View
     
      A view can be regarded as a virtual table,
      i.e., a table that
      does not physically exist in the database
      but looks to the user
      as if it does. By contrast, when we talk of a
      base table there is
      really a physically stored counterpart of each row of the table
      somewhere in the physical storage.
     
     
      Views do not have their own, physically separate, distinguishable
      stored data. Instead, the system stores the definition of the
      view (i.e., the rules about how to access physically stored base
      tables in order to materialize the view) somewhere in the system
      catalogs (see
      ). For a
      discussion on different techniques to implement views refer to
      SIM98.
     
     
      In SQL the CREATE VIEW
      command is used to define a view. The syntax
      is:
CREATE VIEW view_name
    AS select_stmt
      where select_stmt
      is a valid select statement as defined
      in .
      Note that select_stmt is
      not executed when the view is created. It is just stored in the
      system catalogs
      and is executed whenever a query against the view is made.
     
     
      Let the following view definition be given (we use
      the tables from
       again):
CREATE VIEW London_Suppliers
    AS SELECT S.SNAME, P.PNAME
        FROM SUPPLIER S, PART P, SELLS SE
        WHERE S.SNO = SE.SNO AND
              P.PNO = SE.PNO AND
              S.CITY = 'London';
     
     
      Now we can use this virtual relation
      London_Suppliers as
      if it were another base table:
SELECT * FROM London_Suppliers
    WHERE PNAME = 'Screw';
      which will return the following table:
 SNAME | PNAME
-------+-------
 Smith | Screw                 
     
     
      To calculate this result the database system has to do a
      hidden
      access to the base tables SUPPLIER, SELLS and PART first. It
      does so by executing the query given in the view definition against
      those base tables. After that the additional qualifications
      (given in the
      query against the view) can be applied to obtain the resulting
      table.
     
    
    
     Drop Table, Drop Index, Drop View
     
      To destroy a table (including all tuples stored in that table) the
      DROP TABLE command is used:
DROP TABLE table_name;
      
     
      To destroy the SUPPLIER table use the following statement:
DROP TABLE SUPPLIER;
     
     
      The DROP INDEX command is used to destroy an index:
DROP INDEX index_name;
     
     
      Finally to destroy a given view use the command DROP
      VIEW:
DROP VIEW view_name;
     
    
   
   
    Data Manipulation
    
     Insert Into
     
      Once a table is created (see
      ), it can be filled
      with tuples using the command INSERT INTO.
      The syntax is:
INSERT INTO table_name (name_of_attr_1
    [, name_of_attr_2 [, ...]])
    VALUES (val_attr_1 [, val_attr_2 [, ...]]);
     
     
      To insert the first tuple into the relation SUPPLIER (from
      ) we use the
      following statement:
INSERT INTO SUPPLIER (SNO, SNAME, CITY)
    VALUES (1, 'Smith', 'London');
     
     
      To insert the first tuple into the relation SELLS we use:
INSERT INTO SELLS (SNO, PNO)
    VALUES (1, 1);
     
    
    
     Update
     
      To change one or more attribute values of tuples in a relation the
      UPDATE command is used. The syntax is:
UPDATE table_name
    SET name_of_attr_1 = value_1
        [, ... [, name_of_attr_k = value_k]]
    WHERE condition;
     
     
      To change the value of attribute PRICE of the part 'Screw' in the
      relation PART we use:
UPDATE PART
    SET PRICE = 15
    WHERE PNAME = 'Screw';
     
     
      The new value of attribute PRICE of the tuple whose name is 'Screw' is
      now 15.
     
    
    
     Delete
     
      To delete a tuple from a particular table use the command DELETE
      FROM. The syntax is:
DELETE FROM table_name
    WHERE condition;
     
     
      To delete the supplier called 'Smith' of the table SUPPLIER the
      following statement is used:
DELETE FROM SUPPLIER
    WHERE SNAME = 'Smith';
     
    
   
   
    System Catalogs
    
     In every SQL database system
     system catalogs are used to keep
     track of which tables, views indexes etc. are defined in the
     database. These system catalogs can be queried as if they were normal
     relations. For example there is one catalog used for the definition of
     views. This catalog stores the query from the view definition. Whenever
     a query against a view is made, the system first gets the
     view definition query out of the catalog
     and materializes the view
     before proceeding with the user query (see
     
     for a more detailed
     description). For more information about system catalogs refer to
     .
    
   
   
    Embedded SQL
    
     In this section we will sketch how SQL can be
     embedded into a host language (e.g., C).
     There are two main reasons why we want to use SQL
     from a host language:
     
      
       
        There are queries that cannot be formulated using pure SQL
        (i.e., recursive queries). To be able to perform such queries we need a
        host language with a greater expressive power than
        SQL.
       
      
      
       
        We simply want to access a database from some application that
        is written in the host language (e.g., a ticket reservation system
        with a graphical user interface is written in C and the information
        about which tickets are still left is stored in a database that can be
        accessed using embedded SQL).
       
      
     
    
    
     A program using embedded SQL
     in a host language consists of statements
     of the host language and of
     embedded SQL
     (ESQL) statements. Every ESQL
     statement begins with the keywords EXEC SQL.
     The ESQL statements are
     transformed to statements of the host language
     by a precompiler
     (which usually inserts
     calls to library routines that perform the various SQL
     commands).
    
    
     When we look at the examples throughout
      we
     realize that the result of the queries is very often a set of
     tuples. Most host languages are not designed to operate on sets so we
     need a mechanism to access every single tuple of the set of tuples
     returned by a SELECT statement. This mechanism can be provided by
     declaring a cursor.
     After that we can use the FETCH command to
     retrieve a tuple and set the cursor to the next tuple.
    
    
     For a detailed discussion on embedded SQL
     refer to
     ,
     ,
     or
     .