Previous Page | Next Page

Programming with the SQL Procedure

Accessing a DBMS with SAS/ACCESS Software

SAS/ACCESS software for relational databases provides an interface between SAS software and data in other vendors' database management systems (DBMSs). SAS/ACCESS software provides dynamic access to DBMS data through the SAS/ACCESS LIBNAME statement and the PROC SQL Pass-Through Facility. The LIBNAME statement enables you to assign SAS librefs to DBMS objects such as schemas and databases. The Pass-Through Facility enables you to interact with a DBMS by using its SQL syntax without leaving your SAS session.

It is recommended that you use the SAS/ACCESS LIBNAME statement to access your DBMS data because it is usually the fastest and most direct method of accessing DBMS data. The LIBNAME statement offers the following advantages:

An exception to this recommendation occurs when you need to use SQL that does not conform to the ANSI standard. The SAS/ACCESS LIBNAME statement accepts only ANSI-standard SQL, but the PROC SQL Pass-Through Facility accepts all the extensions to SQL that are provided by your DBMS. Another advantage of this access method is that Pass-Through Facility statements enable the DBMS to optimize queries when the queries have summary functions (such as AVG and COUNT), GROUP BY clauses, or columns that were created by expressions (such as the COMPUTED function).

For more information about SAS/ACCESS software, see SAS/ACCESS for Relational Databases: Reference.


Connecting to a DBMS by Using the LIBNAME Statement

Use the LIBNAME statement to read from and write to a DBMS object as if it were a SAS data set. After connecting to a DBMS table or view by using the LIBNAME statement, you can use PROC SQL to interact with the DBMS data.

For many DBMSs, you can directly access DBMS data by assigning a libref to the DBMS by using the SAS/ACCESS LIBNAME statement. Once you have associated a libref with the DBMS, you can specify a DBMS table in a two-level SAS name and work with the table like any SAS data set. You can also embed the LIBNAME statement in a PROC SQL view (see the "CREATE VIEW Statement in the Base SAS Procedures Guide).

PROC SQL takes advantage of the capabilities of a DBMS by passing it certain operations whenever possible. For example, before implementing a join, PROC SQL checks to determine whether the DBMS can perform the join. If it can, then PROC SQL passes the join to the DBMS, which enhances performance by reducing data movement and translation. If the DBMS cannot perform the join, then PROC SQL processes the join. Using the SAS/ACCESS LIBNAME statement can often provide you with the performance benefits of the SQL Procedure Pass-Through Facility without writing DBMS-specific code.

Note:   You can use the DBIDIRECTEXEC system option to send a PROC SQL CREATE TABLE AS SELECT statement or a DELETE statement directly to the database for execution, which could result in CPU and I/O performance improvement. For more information, see the SAS/ACCESS documentation for your DBMS.  [cautionend]

To use the SAS/ACCESS LIBNAME statement, you must have SAS/ACCESS software installed for your DBMS. For more information about the SAS/ACCESS LIBNAME statement, see the SAS/ACCESS documentation for your DBMS.


Querying a DBMS Table

This example uses PROC SQL to query the ORACLE table PAYROLL. The PROC SQL query retrieves all job codes and provides a total salary amount for each job code.

libname mydblib oracle user=user-id password=password
        path=path-name schema=schema-name;

proc sql;
   select jobcode label='Jobcode',
          sum(salary) as total 
          label='Total for Group' 
          format=dollar11.2
      from mydblib.payroll
      group by jobcode;
quit;

Output from Querying a DBMS Table

                     
                                Total for
                 Jobcode            Group

                     BCK      $232,148.00
                     FA1      $253,433.00
                     FA2      $447,790.00
                     FA3      $230,537.00
                     ME1      $228,002.00
                     ME2      $498,076.00
                     ME3      $296,875.00
                     NA1      $210,161.00
                     NA2      $157,149.00
                     PT1      $543,264.00
                     PT2      $879,252.00
                     PT3       $21,009.00
                     SCP      $128,162.00
                     TA1      $249,492.00
                     TA2      $671,499.00
                     TA3      $476,155.00

Creating a PROC SQL View of a DBMS Table

PROC SQL views are stored query expressions that read data values from their underlying files, which can include SAS/ACCESS views of DBMS data. While DATA step views of DBMS data can be used only to read the data, PROC SQL views of DBMS data can be used to update the underlying data if the following conditions are met:

The following example uses the LIBNAME statement to connect to an ORACLE database, create a temporary PROC SQL view of the ORACLE table SCHEDULE, and print the view by using the PRINT procedure. The LIBNAME engine optimizes the processing of joins and WHERE clauses by passing these operations directly to the DBMS to take advantage of DBMS indexing and processing capabilities.

libname mydblib oracle user=user-id password=password
proc sql; 
   create view LON as 
   select flight, dates, idnum
      from mydblib.schedule 
      where dest='LON';
quit;

proc print data=work.LON noobs;
run;

Output from the PRINT Procedure

 FLIGHT                   DATES    IDNUM

   219        04MAR1998:00:00:00    1739
   219        04MAR1998:00:00:00    1478
   219        04MAR1998:00:00:00    1130
   219        04MAR1998:00:00:00    1125
   219        04MAR1998:00:00:00    1983
   219        04MAR1998:00:00:00    1332
   219        05MAR1998:00:00:00    1428
   219        05MAR1998:00:00:00    1442
   219        05MAR1998:00:00:00    1422
   219        05MAR1998:00:00:00    1413
   219        05MAR1998:00:00:00    1574
   219        05MAR1998:00:00:00    1332
   219        06MAR1998:00:00:00    1106
   219        06MAR1998:00:00:00    1118
   219        06MAR1998:00:00:00    1425
   219        06MAR1998:00:00:00    1434
   219        06MAR1998:00:00:00    1555
   219        06MAR1998:00:00:00    1332

Connecting to a DBMS by Using the SQL Procedure Pass-Through Facility


What Is the Pass-Through Facility?

The SQL Procedure Pass-Through Facility enables you to send DBMS-specific SQL statements directly to a DBMS for execution. The Pass-Through Facility uses a SAS/ACCESS interface engine to connect to the DBMS. Therefore, you must have SAS/ACCESS software installed for your DBMS.

You submit SQL statements that are DBMS-specific. For example, you pass Transact-SQL statements to a Sybase database. The Pass-Through Facility's basic syntax is the same for all the DBMSs. Only the statements that are used to connect to the DBMS and the SQL statements are DBMS-specific.

With the Pass-Through Facility, you can perform the following tasks:

You can use the Pass-Through Facility statements in a query, or you can store them in a PROC SQL view. When a view is stored, any options that are specified in the corresponding CONNECT statement are also stored. Thus, when the PROC SQL view is used in a SAS program, SAS can automatically establish the appropriate connection to the DBMS.

For more information, see the CONNECT statement, the DISCONNECT statement, the EXECUTE statement, and the CONNECTION TO statement in the Base SAS Procedures Guide, and The Pass-Through Facility for Relational Databases in SAS/ACCESS for Relational Databases: Reference.

Note:   SAS procedures that perform multipass processing cannot operate on PROC SQL views that store Pass-Through Facility statements, because the Pass-Through Facility does not allow reopening of a table after the first record has been retrieved. To work around this limitation, create a SAS data set from the view and use the SAS data set as the input data set.  [cautionend]


Return Codes

As you use PROC SQL statements that are available in the Pass-Through Facility, any errors are written to the SAS log. The return codes and messages that are generated by the Pass-Through Facility are available to you through the SQLXRC and SQLXMSG macro variables. Both macro variables are described in Using the PROC SQL Automatic Macro Variables.


Pass-Through Example

In this example, SAS/ACCESS connects to an ORACLE database by using the alias ora2 , selects all rows in the STAFF table, and displays the first 15 rows of data by using PROC SQL.

proc sql outobs=15;
   connect to oracle as ora2 (user=user-id password=password);
   select * from connection to ora2 (select lname, fname, state from staff);
   disconnect from ora2;
quit;

Output from the Pass-Through Facility Example

 LNAME            FNAME          STATE
---------------------------------------
ADAMS            GERALD           CT
ALIBRANDI        MARIA            CT
ALHERTANI        ABDULLAH         NY
ALVAREZ          MERCEDES         NY
ALVAREZ          CARLOS           NJ
BAREFOOT         JOSEPH           NJ
BAUCOM           WALTER           NY
BANADYGA         JUSTIN           CT
BLALOCK          RALPH            NY
BALLETTI         MARIE            NY
BOWDEN           EARL             CT
BRANCACCIO       JOSEPH           NY
BREUHAUS         JEREMY           NY
BRADY            CHRISTINE        CT
BREWCZAK         JAKOB            CT

Updating PROC SQL and SAS/ACCESS Views

You can update PROC SQL and SAS/ACCESS views by using the INSERT, DELETE, and UPDATE statements, under the following conditions:

Note:   Beginning with SAS 9, PROC SQL views, the Pass-Through Facility, and the SAS/ACCESS LIBNAME statement are the preferred ways to access relational DBMS data. SAS/ACCESS views are no longer recommended. You can convert existing SAS/ACCESS views to PROC SQL views by using the CV2VIEW procedure. For more information, see the CV2VIEW Procedure in SAS/ACCESS for Relational Databases: Reference.  [cautionend]

Previous Page | Next Page | Top of Page