Home > Articles > Data > Oracle

SQL in PL/SQL

In this chapter from Oracle PL/SQL by Example, 5th Edition, learn how to make use of variables and the various ways to populate variables. This chapter also covers transactional control in PL/SQL by explaining what it means to commit data as well as how SAVEPOINTs are used.
This chapter is from the book

This chapter is a collection of some fundamental elements of using SQL statements in PL/SQL blocks. In the previous chapter, you initialized variables with the “:=” syntax; in this chapter, we will introduce the method of using a SQL select statement to update the value of a variable. These variables can then be used in DML statements (insert, delete, or update). Additionally, we will demonstrate how you can use a sequence in your DML statements within a PL/SQL block much as you would in a stand-alone SQL statement.

A transaction in Oracle is a series of SQL statements that have been grouped together into a logical unit by the programmer. A programmer chooses to do this to maintain data integrity. Each application (SQL*Plus, SQL Developer, and various third-party PL/SQL tools) maintains a single database session for each instance of a user login. The changes to the database that have been executed by a single application session are not actually “saved” into the database until a commit occurs. Work within a transaction up to and just prior to the commit can be rolled back; once a commit has been issued, however, work within that transaction cannot be rolled back. Note that those SQL statements should be either committed or rejected as a group.

To exert transaction control, a SAVEPOINT statement can be used to break down large PL/SQL statements into individual units that are easier to manage. In this chapter, we will cover the basic elements of transaction control so you will know how to manage your PL/SQL code through use of the COMMIT, ROLLBACK, and (principally) SAVEPOINT statement.

Lab 3.1: DML Statements in PL/SQL

Initialize Variables with SELECT INTO

In PL/SQL, there are two main methods of giving values to variables in a PL/SQL block. The first one, which you learned in Chapter 1, is initialization with the “:=” syntax. In this lab we will learn how to initialize a variable with a select statement by making use of the SELECT INTO syntax.

A variable that has been declared in the declaration section of the PL/SQL block can later be given a value with a select statement. The correct syntax is as follows:

SELECT item_name 
INTO variable_name 
FROM table_name; 

Note that any single row function can be performed on the item to give the variable a calculated value.

For Example ch03_1a.sql

SET SERVEROUTPUT ON 
DECLARE 
  v_average_cost VARCHAR2(10);
BEGIN 
  SELECT TO_CHAR(AVG(cost), '$9,999.99')
    INTO v_average_cost
    FROM course;
  DBMS_OUTPUT.PUT_LINE('The average cost of a '||
    'course in the CTA program is '||
    v_average_cost); 
END;

In this example, a variable is given the value of the average cost of a course in the course table. First, the variable must be declared in the declaration section of the PL/SQL block. In this example, the variable is given the data type of VARCHAR2(10) because of the functions used on the data. The select statement that would produce this outcome in SQL*Plus would be

SELECT TO_CHAR(AVG(cost), '$9,999.99') 
FROM course;

The TO_CHAR function is used to format the cost; in doing this, the number data type is converted to a character data type. Once the variable has a value, it can be displayed to the screen using the PUT_LINE procedure of the DBMS_OUTPUT package. The output of this PL/SQL block would be:

The average cost of a course in the CTA program 
is $1,198.33 
PL/SQL procedure successfully completed.

In the declaration section of the PL/SQL block, the variable v_average_cost is declared as a varchar2. In the executable section of the block, this variable is given the value of the average cost from the course table by means of the SELECT INTO syntax. The SQL function TO_CHAR is issued to format the number. The DBMS_OUTPUT package is then used to show the result to the screen.

Using the SELECT INTO Syntax for Variable Initialization

The previous PL/SQL block may be rearranged so the DBMS_OUTPUT section is placed before the SELECT INTO statement.

For Example ch03_1a.sql

SET SERVEROUTPUT ON 
DECLARE 
  v_average_cost VARCHAR2(10);
BEGIN
 DBMS_OUTPUT.PUT_LINE('The average cost of a '||
   'course in the CTA program is '||
   v_average_cost);
 SELECT TO_CHAR(AVG(cost), '$9,999.99')
   INTO v_average_cost
   FROM course; 
END;

You will then see the following result:

The average cost of a course in the CTA program is 
PL/SQL procedure successfully completed.

The variable v_average_cost will be set to NULL when it is first declared. Because the DBMS_OUTPUT section precedes the point at which the variable is given a value, the output for the variable will be NULL. After the SELECT INTO statement, the variable will be given the same value as in the original block, but it will not be displayed because there is not another DBMS_OUTPUT line in the PL/SQL block.

Data Definition Language (DDL) statements are not valid in a simple PL/SQL block (more advanced techniques such as procedures in the DBMS_SQL package will enable you to make use of DDL), yet data manipulation (using Data Manipulation Language [DML]) is easily achieved either by using variables or by simply putting a DML statement into a PL/SQL block. Here is an example of a PL/SQL block that updates an existing entry in the zipcode table.

For Example ch03_2a.sql

SET SERVEROUTPUT ON 
DECLARE 
  v_city zipcode.city%TYPE; 
BEGIN
  SELECT 'COLUMBUS'
    INTO v_city
    FROM dual;
  UPDATE zipcode
     SET city = v_city 
  WHERE ZIP = 43224; 
END;

It is also possible to insert data into a database table in a PL/SQL block, as shown in the following example.

For Example ch03_3a.sql

DECLARE 
   v_zip zipcode.zip%TYPE; 
   v_user zipcode.created_by%TYPE; 
   v_date zipcode.created_date%TYPE;
BEGIN 
   SELECT 43438, USER, SYSDATE
     INTO v_zip, v_user, v_date
     FROM dual;
   INSERT INTO zipcode
     (ZIP, CREATED_BY ,CREATED_DATE, MODIFIED_BY,
      MODIFIED_DATE
     )
      VALUES(v_zip, v_user, v_date, v_user, v_date); 
END;

Using DML in a PL/SQL Block

This section demonstrates how DML is used in PL/SQL. The following PL/SQL block inserts a new student into the student table.

For Example ch03_4a.sql

BEGIN
  SELECT MAX(student_id)
    INTO v_max_id
    FROM student;
  INSERT into student
    (student_id, last_name, zip,
     created_by, created_date,
     modified_by, modified_date,
     registration_date
    )
  VALUES (v_max_id + 1, 'Rosenzweig',
         11238, 'BROSENZ ', '01-JAN-2014',
         'BROSENZ', '10-JAN-2014', '15-FEB-2014'
         ); 
END;

To generate a unique ID, the maximum student_id is selected into a variable and then incremented by 1. In this example, there is a foreign key on the zip item in the student table, which means that the ZIP code you choose to enter must be in the zipcode table.

Using an Oracle Sequence

An Oracle sequence is an Oracle database object that can be used to generate unique numbers. You can use sequences to generate primary key values automatically.

Accessing and Incrementing Sequence Values

Once a sequence is created, you can access its values in SQL statements with these pseudocolumns:

  • CURRVAL: Returns the current value of the sequence.
  • NEXTVAL: Increments the sequence and returns the new value.

The following example creates the sequence eseq.

For Example

CREATE SEQUENCE eseq
   INCREMENT BY 10

The first reference to ESEQ.NEXTVAL returns 1. The second returns 11. Each subsequent reference will return a value 10 greater than the one previous.

(Even though you will be guaranteed unique numbers, you are not guaranteed contiguous numbers. In some systems this may be a problem—for example, when generating invoice numbers.)

Drawing Numbers from a Sequence

A sequence value can be inserted directly into a table without first selecting it. (In very old versions of Oracle prior to Oracle 7.3, it was necessary to use the SELECT INTO syntax and put the new sequence number into a variable; you could then insert the variable.)

For this example, a table called test01 will be used. The table test01 is first created, followed by the sequence test_seq. Then the sequence is used to populate the table.

For Example ch03_5a.sql

CREATE TABLE test01 (col1 number); 
CREATE SEQUENCE test_seq
   INCREMENT BY 5; 
BEGIN
   INSERT INTO test01
     VALUES (test_seq.NEXTVAL); 
END;
/
Select * FROM test01;

Using a Sequence in a PL/SQL Block

In this example, a PL/SQL block is used to insert a new student in the student table. The PL/SQL code makes use of two variables, USER and SYSDATE, that are used in the select statement. The existing student_id_seq sequence is used to generate a unique ID for the new student.

For Example ch03_6a.sql

DECLARE 
   v_user student.created_by%TYPE; 
   v_date student.created_date%TYPE; 
BEGIN
   SELECT USER, sysdate
     INTO v_user, v_date
     FROM dual;
   INSERT INTO student
     (student_id, last_name, zip, 
      created_by, created_date, modified_by,
      modified_date, registration_date
     )
     VALUES (student_id_seq.nextval, 'Smith',
             11238, v_user, v_date, v_user, v_date,
             v_date
            ); 
END;

In the declaration section of the PL/SQL block, two variables are declared. They are both set to be data types within the student table using the %TYPE method of declaration. This ensures the data types match the columns of the tables into which they will be inserted. The two variables v_user and v_date are given values from the system by means of SELECT INTO statements. The value of the student_id is generated by using the next value of the student_id_seq sequence.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020