Specifying Database Tables 

The FROM clause determines the database tables from which the data specified in the SELECT clause is read. You can specify either a single table or more than one table, linked using inner or outer joins. The names of database tables may be specified statically or dynamically, and you can use alias names. You can also use the FROM clause to bypass the SAP buffer and restrict the number of lines to be read from the database.

"Database table" can equally mean an ABAP Dictionary view. A view links two or more database tables in the ABAP Dictionary, providing a static join that is available systemwide. You can specify the name of a view wherever the name of a database table may occur in the FROM clause.

The FROM clause has two parts - one for specifying database tables, and one for other additions:

SELECT ... FROM <tables> <options> ...

In <tables>, you specify the names of database tables and define joins. <options> allows you to specify further additions that control the database access.

Specifying Database Tables Statically

To specify the name of a database table statically, use the following:

SELECT ... FROM <dbtab> [AS <alias>] <options> ...

The database table <dbtab> must exist in the ABAP Dictionary. The AS addition allows you to specify an alternative name <alias> that you can then use in the SELECT; FROM, WHERE, and GROUP BY clauses. This can eliminate ambiguity when you use more than one database table, especially when you use a single database table more than once in a join. Once you have defined an alias, you may no longer use the real name of the database table

Specifying Database Tables Dynamically

To specify the name of a database table dynamically, use the following:

SELECT ... FROM (<name>) <options> ...

The field <name> must contain the name of a database table in the ABAP Dictionary. The table name must be written in uppercase. When you specify the name of a database table dynamically, you cannot use an empty INTO clause to read all of the columns into the work area <dbtab>. It is also not possible to use alternative table names.

Specifying Two or More Database Tables as an Inner Join

In a relational database, you normally need to read data simultaneously from more than one database table into an application program. You can read from more than one table in a single SELECT statement, such that the data in the tables all has to meet the same conditions, using the following join expression:

SELECT ...
...
FROM
<tab> [INNER] JOIN <dbtab> [AS <alias>] ON <cond> <options>
...

where <dbtab> is a single database table and <tab> is either a table or another join expression. The database tables can be specified statically or dynamically as described above. You may also use aliases. You can enclose each join expression in parentheses. The INNER addition is optional.

A join expression links each line of <tab> with the lines in <dbtab> that meet the condition <cond>. This means that there is always one or more lines from the right-hand table that is linked to each line from the left-hand table by the join. If <dbtab> does not contain any lines that meet the condition <cond>, the line from <tab> is not included in the selection.

The syntax of the <cond> condition is like that of the WHERE clause, although individual comparisons can only be linked using AND. Furthermore, each comparison must contain a column from the right-hand table <dbtab>. It does not matter on which side of the comparison it occurs. For the column names in the comparison, you can use the same names that occur in the SELECT clause, to differentiate columns from different database tables that have the same names.

The comparisons in the condition <cond> can appear in the WHERE clause instead of the ON clause, since both clauses are applied equally to the temporary table containing all of the lines resulting from the join. However, each join must contain at least one comparison in the condition <cond>.

Specifying Two or More Database Tables as a Left Outer Join

In an inner join, a line from the left-hand database table or join is only included in the selection if there is one or more lines in the right-hand database table that meet the ON condition <cond>. The left outer join, on the other hand, reads lines from the left-hand database table or join even if there is no corresponding line in the right-hand table.

SELECT ...
...
FROM
<tab> LEFT [OUTER] JOIN <dbtab> [AS <alias>] ON <cond> <options>
...

<tab> and <dbtab> are subject to the same rules and conditions as in an inner join. The OUTER addition is optional. The tables are linked in the same way as the inner join with the one exception that all lines selected from <tab> are included in the final selection. If <dbtab> does not contain any lines that meet the condition <cond>, the system includes a single line in the selection whose columns from <dbtab> are filled with null values.

In the left outer join, more restrictions apply to the condition <cond> than in the inner join. In addition to the above restrictions:

Client Handling

As already mentioned, you can switch off the automatic client handling in Open SQL statements using a special addition. In the SELECT statement, the addition comes after the options in the FROM clause:

SELECT ... FROM <tables> CLIENT SPECIFIED ...

If you use this addition, you can then address the client fields in the individual clauses of the SELECT statement.

Disabling Data Buffering

If buffering is allowed for a table in the ABAP Dictionary, the SELECT statement always reads the data from the buffer in the database interface of the current application server. To read data directly from the database table instead of from the buffer, use the following:

SELECT ... FROM <tables> BYPASSING BUFFER ...

This addition guarantees that the data you read is the most up to date. However, as a rule, only data that does not change frequently should be buffered, and using the buffer where appropriate improves performance. You should therefore only use this option where really necessary.

Restricting the Number of Lines

To restrict the absolute number of lines included in the selection, use the following:

SELECT ... FROM <tables> UP TO <n> ROWS ...

If <n> is a positive integer, the system reads a maximum of <n> lines. If <n> is zero, the system reads all lines that meet the selection criteria. If you use the ORDER BY clause as well, the system reads all lines belonging to the selection, sorts them, and then places the first <n> lines in the selection set.

Examples

Specifying a database table statically:

DATA WA TYPE SCARR.

SELECT *
INTO   WA
FROM   SCARR UP TO 4 ROWS.

  WRITE: / WA-CARRID, WA-CARRNAME.

ENDSELECT.

The output is:

The system reads four lines from the database table SCARR.

Specifying a database table dynamically:

DATA WA TYPE SCARR.

DATA NAME(10) VALUE 'SCARR'.

SELECT *
INTO   WA
FROM   (NAME) CLIENT SPECIFIED
WHERE  MANDT = '000'.

  WRITE: / WA-CARRID, WA-CARRNAME.

ENDSELECT.

A condition for the MANDT field is allowed, since the example uses the CLIENT SPECIFIED option. If NAME had contained the value ‘scarr’ instead of ‘SCARR’, a runtime error would have occurred.

Inner join:

DATA: BEGIN OF WA,
        CARRID TYPE SPFLI-CARRID,
        CONNID TYPE SPFLI-CONNID,
        FLDATE TYPE SFLIGHT-FLDATE,
        BOOKID TYPE SBOOK-BOOKID,
      END OF WA,
      ITAB LIKE SORTED TABLE OF WA
                WITH UNIQUE KEY CARRID CONNID FLDATE BOOKID.

SELECT P~CARRID P~CONNID F~FLDATE B~BOOKID
INTO   CORRESPONDING FIELDS OF TABLE ITAB
FROM   ( ( SPFLI AS P
           INNER JOIN SFLIGHT AS F ON P~CARRID = F~CARRID AND
                                      P~CONNID = F~CONNID      )
           INNER JOIN SBOOK   AS B ON B~CARRID = F~CARRID AND
                                      B~CONNID = F~CONNID AND
                                      B~FLDATE = F~FLDATE      )
WHERE P~CITYFROM = 'FRANKFURT' AND
      P~CITYTO   = 'NEW YORK'  AND
      F~SEATSMAX > F~SEATSOCC.

LOOP AT ITAB INTO WA.
  AT NEW FLDATE.
    WRITE: / WA-CARRID, WA-CONNID, WA-FLDATE.
  ENDAT.
  WRITE / WA-BOOKID.
ENDLOOP.

This example links the columns CARRID, CONNID, FLDATE, and BOOKID of the table SPFLI, SFLIGHT, and SBOOK, and creates a list of booking numbers for all flights from Frankfurt to New York that are not fully booked. An alias name is assigned to each table.

Left outer join:

DATA: BEGIN OF WA,
        CARRID   TYPE SCARR-CARRID,
        CARRNAME TYPE SCARR-CARRNAME,
        CONNID   TYPE SPFLI-CONNID,
      END OF WA,
      ITAB LIKE SORTED TABLE OF WA
                WITH NON-UNIQUE KEY CARRID.

SELECT S~CARRID S~CARRNAME P~CONNID
INTO   CORRESPONDING FIELDS OF TABLE ITAB
FROM   SCARR AS S
       LEFT OUTER JOIN SPFLI AS P ON S~CARRID   =  P~CARRID AND
                                     P~CITYFROM = 'FRANKFURT'.

LOOP AT ITAB INTO WA.
  WRITE: / WA-CARRID, WA-CARRNAME, WA-CONNID.
ENDLOOP.

The output might look like this:

The example links the columns CARRID, CARRNAME, and CONNID of the tables SCARR and SPFLI using the condition in the left outer join that the airline must fly from Frankfurt. All other airlines have a null value in the CONNID column in the selection.

If the left outer join is replaced with an inner join, the list looks like this:

Only lines that fulfill the ON condition are included in the selection.