Home > Articles > Data > Oracle

This chapter is from the book

This section gives you some suggested answers to the questions in Lab 3.1, with discussion related to how those answers resulted. The most important thing to realize is whether your answer works. You should figure out the implications of the answers here and what the effects are from any different answers you may come up with.

3.1.1 Answers

a)

Why does PL/SQL have so many different types of characters? What are they used for?

A1:

Answer: The PL/SQL engine recognizes different characters as having different meaning and therefore processes them differently. PL/SQL is neither a pure mathematical language nor a spoken language, yet it contains elements of both. Letters will form various lexical units such as identifiers or key words, mathematic symbols will form lexical units known as delimiters that will perform an operation, and other symbols, such as /*, indicate comments that should not be processed.

b)

What would be the equivalent of a verb and a noun in English in PL/SQL? Do you speak PL/SQL?

A2:

Answer: A noun would be similar to the lexical unit known as an identifier. A verb would be similar to the lexical unit known as a delimiter. Delimiters can simply be quotation marks, but others perform a function such as to multiply "*".

3.1.2 Answers

a)

If you ran the previous example in a SQL*Plus, what would be the result?

A1:

Answer: Assuming SET SERVEROUTPUT ON had been issued, you would get only born on. The reason is that the variables v_name and v_dob have no values.

b)

Run the example and see what happens. Explain what is happening as the focus moves from one line to the next.

A2:

Answer: Three variables are declared. When each one is declared, its initial value is null. v_name is set as a varchar2VARCHAR2 with a length of 30, v_dob is set as a character type date, and v_us_citizen is set to BOOLEAN. Once the executable section begins, the variables have no value and, therefore, when the DBMS_OUTPUT is told to print their values, it prints nothing.

This can be seen if the variables were replaced as follows: Instead of v_name, use NVL(v_name, 'No Name') and instead of v_dob use NVL (v_dob, '01-Jan-1999'). Then run the same block and you will get

No Name born on 01-Jan-1999

In order to make use of a variable, you must declare it in the declaration section of the PL/SQL block. You will have to give it a name and state its data type. You also have the option to give your variable an initial value. Note that if you do not assign a variable an initial value, it will be null. It is also possible to constrain the declaration to "not null," in which case you must assign an initial value. Variables must first be declared and then they can be referenced. PL/SQL does not allow forward references. You can set the variable to be a constant, which means it cannot change.

3.1.3 Answers

a)

What would happen if you ran the preceding PL/SQL block? Would you receive an error message? If so, explain.

A1:

Answer: In this example, you declare a variable called exception. Next, you initialize this variable and display its value on the screen.

This example illustrates an invalid use of reserved words. To the PL/SQL compiler, "exception" is a reserved word and it denotes the beginning of the exception-handling section. As a result, it cannot be used to name a variable. Consider the huge error message produced by this tiny example.


exception VARCHAR2(15);
   *
ERROR at line 2:
ORA-06550: line 2, column 4:
PLS-00103: Encountered the symbol "EXCEPTION" when
expecting one of the following:
begin function package pragma procedure subtype type use
<an identifier> <a double-quoted delimited-identifier>
 cursor
form current
The symbol "begin was inserted before "EXCEPTION"
to continue.
ORA-06550: line 4, column 4:
PLS-00103: Encountered the symbol "EXCEPTION" when
expecting one of the following:
begin declare exit for goto if loop mod null pragma
 raise
return select update while <an identifier>
<a double-quoted delimited-identifier> <a bin
ORA-06550: line 5, column 25:
PLS-00103: Encountered the symbol "EXCEPTION" when
expecting one of the following:
( ) - + mod not null others <an identifier>
<a double-quoted delimited-identifier> <a bind variable>
avg
count current exists max min prior sql s
ORA-06550: line 7, column 0:
PLS-00103: Encountered the symbol "end-of-file" when
expecting one of the following:
begin declare end exception exit for goto if loop

Here is a question you should ask yourself: If you did not know that the word "exception" is a reserved word, do you think you would attempt to debug the preceding script after looking at this error message? I know I would not.

3.1.4 Answers

a)

What would happen if you ran the preceding PL/SQL block?

A1:

Answer: In this example, you declare and initialize three numeric variables. The first declaration and initialization (v_var1 NUMBER(2) := 123) causes an error because the value 123 exceeds the specified precision. The second variable declaration and initialization (v_var2 NUMBER(3) := 123) does not cause any errors because the value 123 corresponds to the specified precision. The last declaration and initialization (v_var3 NUMBER(5,3) := 123456.123) causes an error because the value 123456.123 exceeds the specified precision. As a result, this example produces the following output:


DECLARE
*
ERROR at line 1:
ORA-06502: PL/SQL: numeric or value error
ORA-06512: at line 2

3.1.5 Answers

a)

In the previous example, what has been declared? State the data type and value.

A1:

Answer: The variable v_name was declared with the identical data type as the column first_name from the database table STUDENT - varchar2(25). Additionally, the variable v_grade was declared the identical data type as the column grade_numeric on the grade database table – number NUMBER(3). Each has a value of null.

Most Common Data Types

VARCHAR2(maximum_length)

  • Stores variable-length character data.

  • Takes a required parameter that specifies a maximum length up to 32,767 bytes.

  • Does not use a constant or variable to specify the maximum length; an integer literal must be used.

  • The maximum width of a VARCHAR2 database column is 4000 bytes.

CHAR[(maximum_length)]

  • Stores fixed-length (blank-padded if necessary) character data.

  • Takes an optional parameter that specifies a maximum length up to 32,767 bytes.

  • Does not use a constant or variable to specify the maximum length; an integer literal must be used. If maximum length is not specified, it defaults to 1.

  • The maximum width of a CHAR database column is 2000 bytes; the default is 1 byte.

NUMBER[(precision, scale)]

  • Stores fixed or floating-point numbers of virtually any size.

  • Precision is the total number of digits.

  • Scale determines where rounding occurs.

  • It is possible to specify precision and omit scale, in which case scale is 0 and only integers are allowed.

  • Constants or variables cannot be used to specify precision and scale; integer literals must be used.

  • Maximum precision of a NUMBER value is 38 decimal digits.

  • Scale can range from −84 to 127.

  • For instance, a scale of 2 rounds to the nearest hundredth (3.456 becomes 3.46).

  • Scale can be negative, which causes rounding to the left of the decimal point. For example, a scale of -3 rounds to the nearest thousandth (3456 becomes 3000). A scale of zero rounds to the nearest whole number. If you do not specify the scale, it defaults to zero.

BINARY_INTEGER

  • Stores signed integer variables.

  • Compares to the NUMBER data type. BINARY_INTEGER variables are stored in the binary format, which takes less space.

  • Calculations are faster.

  • Can store any integer value in the range −2,147,483,747 through 2,147,483,747.

  • This data type is primarily used for indexing a PL/SQL table. This will be explained in more depth in Chapter 16, "PL/SQL Tables." You cannot create a column in a regular table of binary_integer type.

DATE

  • Stores fixed-length date values.

  • Valid dates for DATE variables include January 1, 4712 B.C. to December 31, A.D. 9999.

  • When stored in a database column, date values include the time of day in seconds since midnight. The date portion defaults to the first day of the current month; the time portion defaults to midnight.

  • Dates are actually stored in binary format and will be displayed according to the default format.

TIMESTAMP

  • This is a new data type introduced with Oracle 9i. It is an extension of the DATE data type. It stores fixed-length date values with precision down to a fraction of a second with up to 9 places after the decimal (the default is 6). Here is an example of the default this displays for this data type: '12-JAN-2002 09.51.44.000000 PM'

  • The "with timezone" or "with local timezone" option allows the TIMESTAMP to be related to a particular time zone. This will then be adjusted to the time zone of the database. For example, this would allow a global database to have an entry in London and New York recorded as being the same time even though it will display as noon in New York and 5 P.M. in London.

BOOLEAN

  • Stores the values TRUE and FALSE and the nonvalue NULL. Recall that NULL stands for a missing, unknown, or inapplicable value.

  • Only the values TRUE and FALSE and the nonvalue NULL can be assigned to a BOOLEAN variable.

  • The values TRUE and FALSE cannot be inserted into a database column.

LONG

  • Stores variable-length character strings.

  • The LONG data type is like the VARCHAR2 data type, except that the maximum length of a LONG value is 2 gigabytes.

  • You cannot select a value longer than 4000 bytes from a LONG column into a LONG variable.

  • LONG columns can store text, arrays of characters, or even short documents. You can reference LONG columns in UPDATE, INSERT, and (most) SELECT statements, but not in expressions, SQL function calls, or certain SQL clauses, such as WHERE, GROUP BY, and CONNECT BY.

LONG RAW

  • Stores raw binary data of variable length up to 2 gigabytes.

LOB (Large Object)

  • There are four types of LOBS: BLOB, CLOB, NCLOB, and BFILE. These can store binary objects, such as image or video files, up to 4 gigabytes in length.

  • A BFILE is a large binary file stored outside the database. The maximum size is 4 gigabytes.

ROWID

  • Internally, every Oracle database table has a ROWID pseudocolumn, which stores binary values called rowids.

  • Rowids uniquely identify rows and provide the fastest way to access particular rows.

  • Use the ROWID data type to store rowids in a readable format.

  • When you select or fetch a rowid into a ROWID variable, you can use the function ROWIDTOCHAR, which converts the binary value into an 18-byte character string and returns it in that format.

  • Extended rowids use a base 64 encoding of the physical address for each row. The encoding characters are A–Z, a–z, 0–9, +, and /. Row ID in Oracle 9i is as follows: OOOOOOFFFBBBBBBRRR. Each component has a meaning. The first section, OOOOOO, signifies the database segment. The next section, FFF, indicates the tablespace- relative datafile number of the datafile that contains the row. The following section, BBBBBB, is the data block that contains the row. The last section, RRR, is the row in the block (keep in mind that this may change in future versions of Oracle).

3.1.6 Answers

a)

What will the output be for the preceding script? Explain what is being declared and what the value of the variable is throughout the scope of the block.

A1:

Answer: The server output will be


I ate 2 cookies with 600 calories.
I really ate 3 cookies with 900 calories.
The truth is, I actually ate 8 cookies with
2400 calories.
PL/SQL procedure successfully completed.

Initially the variable v_cookies_amt is declared to be a NUMBER with the value of 2, and the variable v_calories_per_cookie is declared to be a CONSTANT NUMBER with a value of 300 (since it is declared to be a tCONSTANT, it will not change its value). In the course of the procedure, the value of v_cookies_amt is later set to be 3, and then finally it is set to be its current value, 3 plus 5, thus becoming 8.

b)

In the previous example, add the following expressions to the beginning of the procedure (immediately after the BEGIN in the previous example), then explain the values of the variables at the beginning and at the end of the script.

A3:

Answer: Initially the variable v_lname is declared as a data type VARCHAR2 with a length of 30 and a value of null. The variable v_regdate is declared as data type date with a value of null. The variable v_pctincr is declared as CONSTANT NUMBER with a length of 4 and a precision of 2 and a value of 1.15. The variable v_counter is declared as NUMBER with a value of 0. The variable v_YorN is declared as a variable of BOOLEAN data type and a value of TRUE.

The output of the procedure will be as follows (make sure you have entered SET SERVEROUTPUT ON earlier on in your SQL*Plus session):


1
1200
PL/SQL procedure successfully completed.

Once the executable section is complete, the variable v_counter will be changed from null to 1. The value of v_new_cost will change from null to 1200 (800 times 1.50).

Note that a common way to find out the value of a variable at different points in a block is to add a DBMS_OUTPUT.PUT_LINE(v_variable_name); throughout the block.

c)

What will the values of the variables be at the end of the script?

A5:

Answer: The value of v_counter will then change from 1 to 6, which is ((1 + 5) *2))/2, and the value of new_cost will go from 1200 to 1800, which is (800 * 6)/4. The output from running this procedure will be:


6
1800
PL/SQL procedure successfully completed.

Operators (Delimiters): the Separators in an Expression

Arithmetic ( **, *, /, +, -)

Comparison( =, <>, !=, <, >, <=, >=, LIKE, IN, BETWEEN, IS NULL )

Logical ( AND, OR, NOT )

String ( ||, LIKE )

Expressions

Operator Precedence

    • **, NOT

    • +, - ( arithmetic identity and negation ) *, / +, -, || =, <>, !=, <=, >=, <, >, LIKE, BETWEEN, IN, IS NULL

  • AND— logical conjunction

  • OR— logical inclusion

3.1.7 Answers

a)

If the following example were run in SQL*Plus, what do you think would be displayed?


-- ch03_5a.pls
SET SERVEROUTPUT ON
DECLARE
   e_show_exception_scope EXCEPTION;
   v_student_id           NUMBER := 123;
BEGIN
  DBMS_OUTPUT.PUT_LINE('outer student id is '
     ||v_student_id);
   DECLARE
     v_student_id    VARCHAR2(8) := 125;
   BEGIN
      DBMS_OUTPUT.PUT_LINE('inner student id is '
         ||v_student_id);
      RAISE e_show_exception_scope;
   END;
EXCEPTION
   WHEN e_show_exception_scope
   THEN
      DBMS_OUTPUT.PUT_LINE('When am I displayed?');
      DBMS_OUTPUT.PUT_LINE('outer student id is '
         ||v_student_id);
END;
A1:

Answer: The following would result:


outer student id is 123
inner student id is 125
When am I displayed?
outer student id is 123
PL/SQL procedure successfully completed.
b)

Now run the example and see if it produces what you expected. Explain how the focus moves from one block to another in this example.

A2:

Answer: The variable e_Show_Exception_Scope is declared as an exception type in the declaration section of the block. There is also a declaration of the variable called v_student_id of data type NUMBER that is initialized to the number 123. This variable has a scope of the entire block, but it is visible only outside of the inner block. Once the inner block begins, another variable, named v_student_id, is declared. This time it is of data type VARCHAR2(8) and is initialized to 125. This variable will have a scope and visibility only within the inner block. The use of DBMS_OUTPUT helps to show which variable is visible. The inner block raises the exception e_Show_Exception_Scope; this means that the focus will move out of the execution section and into the exception section. The focus will look for an exception named e_Show_Exception_Scope. Since the inner block has no exception with this name, the focus will move to the outer block's exception section and it will find the exception. The inner variable v_student_id is now out of scope and visibility. The outer variable v_student_id (which has always been in scope) now regains visibility. Because the exception has an IF/THEN construct, it will execute the DBMS_OUTPUT call. This is a simple use of nested blocks. Later in the book you will see more complex examples. Once you have covered exception handling in depth in Chapters 7, 10, and 11, you will see that there is greater opportunity to make use of nested blocks.

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