Home > Articles

This chapter is from the book

This chapter is from the book

LAB 2.5: The ORDER BY Clause

Lab Objectives

After this lab, you will be able to:

  • Custom Sort Query Results

Using the ORDER BY Clause

Recall from Chapter 1, "SQL and Data," that data is not stored in a table in any particular order. In all of the examples used thus far, the result sets display data in the order in which they happen to be returned from the database. However, you may want to view data in a certain order and the ORDER BY clause accomplishes this by ordering the data any way you wish.

For example, the following statement retrieves a list of course numbers and descriptions for courses without a prerequisite, in alphabetical order by their descriptions:

SELECT course_no, description
   FROM course
 WHERE prerequisite IS NULL
 ORDER BY description
COURSE_NO DESCRIPTION
--------- --------------------------
	   10 DP Overview
	   20 Intro to Computers
	  146 Java for C/C++ Programmers
 	  310 Operating Systems

4 rows selected.

By default, when the ORDER BY is used, the result set is sorted in ascending order; or you can be explicit by adding the abbreviation ASC after the column. If descending order is desired, the abbreviation DESC is used after the column in the ORDER BY clause:

SELECT course_no, description
  FROM course
 WHERE prerequisite IS NULL
 ORDER BY description DESC
COURSE_NO DESCRIPTION
--------- --------------------------
 	  310 Operating Systems
	  146 Java for C/C++ Programmers
	   20 Intro to Computers
	   10 DP Overview

4 rows selected.

Instead of listing the name of the column to be ordered, you can list the sequence number of the column in the SELECT list. The next SQL statement returns the same result as the prior SQL statement, but uses a different ORDER BY clause. The number 2 indicates the second column of the SELECT list.

SELECT course_no, description
  FROM course
 WHERE prerequisite IS NULL
 ORDER BY 2 DESC

A result set can be sorted by more than one column. The columns you wish to sort by need only be included in the ORDER BY clause, separated by commas. The ORDER BY clause is always the last clause in an SQL statement.

COLUMN ALIAS

A column alias can be used in the SELECT list to give a column or value an alias; it can also make the result much easier to read. In next example, different forms of a column alias are used to take the place of the column name in the result set. An alias may also contain one or more words or be spelled in exact case when enclosed in double quotes. The optional keyword AS can precede the alias name.

SELECT first_name first,
 	   first_name "First Name",
	   first_name AS "First"
  FROM student
 WHERE zip = '10025'
FIRST 					  First Name				First
------------------------- ------------------------- ------
Jerry 					  Jerry					    Jerry
Nicole					  Nicole					Nicole
Frank					  Frank					    Frank

3 rows selected.

To format the column with the SQL*Plus COLUMN format, you must specify the alias in quotes as well. For example:

COL "First" FORMAT A13

You can also use the column alias to order by a specific column.

SELECT first_name first, first_name "First Name",
 	   first_name AS "First"
  FROM student
 WHERE zip = '10025'
 ORDER BY "First Name"
FIRST 					  First Name 				First
------------------------- ------------------------- ------
Frank					  Frank						Frank
Jerry					  Jerry					    Jerry
Nicole					  Nicole				    Nicole

3 rows selected.

Distinct and ORDER BY

The ORDER BY clause often contains columns listed in the SELECT clause, but it is also possible to ORDER BY columns that are not selected. One exception is columns qualified using the DISTINCT keyword—if the SELECT list contains DISTINCT, the column(s) the keyword pertains to must also be listed in the ORDER BY clause.

The next example shows that the STUDENT_ID column is not a column listed in the DISTINCT SELECT list and therefore results in an Oracle error message.

SQL> SELECT DISTINCT first_name, last_name
  2 FROM student
  3 WHERE zip = '10025'
  4 ORDER BY student_id
  5 /
 ORDER BY student_id
		  *
ERROR at line 4:
ORA-01791: not a SELECTed expression

NULL VALUES AND ORDER BY

The following statement orders the COST column by the default sort order. Note that the row with a COST column value of NULL is the last row in the sort order.

SELECT DISTINCT cost
  FROM course
 ORDER BY cost
 COST
----------
 1095
 1195
 1595


4 rows selected.

You can change the default ordering of the nulls with the NULLS FIRST or NULLS LAST option in the ORDER BY clause as you see in the next statement. Here the requested order is to list the NULL value first followed by the other values in the default ascending sort order.

SELECT DISTINCT cost
  FROM course
 ORDER BY cost NULLS FIRST
 COST
----------
 1095
 1195
 1595

4 rows selected.

Understanding Oracle Error Messages

As you begin to learn SQL, you will inevitably make mistakes when writing statements. Oracle returns an error number and error message to inform you of your mistake. Some error messages are easy to understand; others are not. While we cannot anticipate every possible error you may encounter, you will see that throughout the book I point out common mistakes. Here are some general guidelines when dealing with Oracle errors.

1. Read the Oracle error message carefully

Oracle will tell you on which line the error occurred.

SQL> SELECT salutation, first_name, las_name
 2 FROM student
 3 WHERE first_name = 'John'
 4 /

SELECT salutation, first_name, las_name * ERROR at line 1: ORA-00904: "LAS_NAME": invalid identifier

In this example the error is very easy to spot and the error message is self-explanatory. One of the column names is invalid, and Oracle points out the error by indicating the line number. The error is on line 1, and the asterisk indicates in what position within the line the error is found; it is the misspelled LAST_NAME column name.

2. Resolve one error at a time

Sometimes you may have multiple errors in a single SQL statement. The Oracle parser, which checks the syntax of all statements, starts checking from the end of the entire statement.

SQL> SELECT salutation, first_name, las_name
  2 FROM studen
  3 WHER first_name = 'John'
  4 /
 WHER first_name = 'John'
 		*
ERROR at line 3:
ORA-00933: SQL command not properly ended

This type of error message may leave you clueless as to what could be wrong with this query. In fact, the statement contains three errors, one in each line. Because the parser works its way backwards, it complains about the first error on line 3. The position of the asterisk suggests that there is something wrong with the spelling of the FIRST_NAME column. But in fact, it is spelled correctly; otherwise, you would see the ORA-00904 invalid identifier error listed as in one of the previous examples complaining about the incorrect column name. The WHERE key word is missing the letter E; therefore, Oracle cannot interpret what you are attempting to do.

After you correct this error, you will see line 2 reported, exemplifying how the parser works its way backward.

SQL> SELECT salutation, first_name, las_name
  2 FROM studen
  3 WHERE first_name = 'John'
  4 /

FROM studen * ERROR at line 2: ORA-00942: table or view does not exist

Here the table name is misspelled and Oracle indicates that such a table does not exist.

The last error in the statement is found on line 1 and is the misspelled LAST_NAME column name. The parser will report this error as the last error. If you are unsure about the spelling of a column or table name, you can always use the DESCRIBE SQL*Plus command to list the column names and their respective data types, or you can refer to Appendix D, "Student Database Schema," for a list of table and column names.

3. Double-check the syntax of your statement

Simple typos, such as a stray period or comma, a missing space, or single quote, can cause very strange and seemingly unrelated error message that may have nothing to do with the problem. Therefore, carefully reread the statement or simply retype it. After looking at a statement for a long time, the error may not be apparent. Perhaps put it aside, take a break, and look at it with a fresh mind later, or ask someone for help in spotting the error.

4. Look up the Oracle Error Number

You can look up the Oracle error number in the Oracle Database Error Messages Manual. If the error starts with an ORA message type, it is typically a database-related error, whereas an error with an SP2 prefix indicates a SQL*Plus or iSQL*Plus specific error. Once you found the error in the manual, you will see the reason for the error and a recommended action on how to correct it. The recommended action may be general or very specific, once again depending on what type of error occurred.

Initially, the challenge may be finding the correct manual to look up the error message. Following are some suggestions on how to find this information. Besides looking at the online documentation that comes with your Oracle software and which is either found on your CDs or installed on your machine, you can also find the online manual on the Oracle Technology Network (OTN) Web site. Oracle offers a free subscription to the site, which includes a number of features such as access to the online manuals and discussion groups. The URL for OTN is http:// otn.oracle.com; you must register first to become a member. Also refer to Appendix H, "Navigating through the Oracle Documentation" and Appendix G, "Resources." These appendixes offer you tips on how to find the needed information.

In some operating systems such as Unix, Linux, and VMS, you can also use the Oracle program called oerr to look up the error message from the operating system prompt. This does not work in the Windows environment. For example, to look up the ORA-00939 error you type at the Unix operating system prompt (indicated with the $ sign):

$ oerr ora 00939
00939, 00000, " too many arguments for function"
// *Cause: The function was referenced with too many arguments.
// *Action: Check the function syntax and specify only the
// 			required number of arguments.
$

Lab 2.5 Exercises

2.5.1 Custom Sort Query Results

  1. Write a SELECT statement to list each city and zip code in New York or Connecticut. Sort the result in ascending order by zip code.

  2. Write a SELECT statement to list course descriptions and their prerequisite course numbers, sorted in ascending order by description. Do not list courses without a prerequisite.

  3. Show the salutation, first, and last name of students with the last name Grant. Order the result by salutation in descending order and the first name in ascending order.

  4. Execute the following query. What do you observe about the last row returned by the query?

  5. SELECT student_id, last_name
      FROM student
     ORDER BY last_name

Lab 2.5 Exercise Answers

2.5.1 Answers

  1. Write a SELECT statement to list each city and zip code in New York or Connecticut. Sort the result in ascending order by zip code.

  2. Answer: The SELECT statement selects two columns, uses the equal operator and OR logical operator to combine expressions in the WHERE clause, and uses ORDER BY with a single column to sort the results in ascending order.

    SELECT city, zip
      FROM zipcode
     WHERE state = 'NY'
     	OR state = 'CT'
     ORDER BY zip
    CITY 					  ZIP
    ------------------------- -----
    Ansonia					  06401
    Middlefield				  06455
    ...
    Hicksville				  11802
    Endicott				  13760
    
    142 rows selected.

Alternatively, the WHERE clause can be written as:

WHERE state IN ('NY', 'CT')
  1. Write a SELECT statement to list course descriptions and their prerequisite course numbers, sorted in ascending order by description. Do not list courses without a prerequisite.

  2. Answer: The following query shows the use of the IS NOT NULL comparison operator in the WHERE clause. The result is sorted by the DESCRIPTION column in ascending order.

    SELECT description, prerequisite
      FROM course
     WHERE prerequisite IS NOT NULL
     ORDER BY description
    

    DESCRIPTION PREREQUISITE --------------------------------- ------------ Advanced Java Programming 122 Advanced Unix Admin 132 ... Structured Programming Techniques 204 Unix Tips and Techniques 134 26 rows selected.

Alternatively, the ORDER BY clause can be written as:

ORDER BY 1

You can even use the column alias.

SELECT description "Descr", prerequisite
  FROM course
 WHERE prerequisite IS NOT NULL
 ORDER BY "Descr"

In most of the previous examples, you see the SELECT list is taking up one line only. By spreading it over several lines, it sometimes makes it easier to read and this is perfectly acceptable formatting. By putting elements in the SELECT list on separate lines, you control exactly when the next line begins and indent it for easy readability below the line above it. The following SELECT statement has multiple columns in the SELECT list.

SELECT description, prerequisite,
	   cost, modified_date
  FROM course
 WHERE prerequisite IS NOT NULL
 ORDER BY description

DESCRIPTION PREREQUISITE COST MODIFIED_ ------------------------- ------------ ---- --------- Advanced Java Programming 122 1195 05-APR-03 ... Unix Tips and Techniques 134 1095 05-APR-03 26 rows selected.

  1. Show the salutation, first, and last name of students with the last name Grant. Order the result by salutation in descending order and the first name in ascending order.

  2. Answer: The ORDER BY clause contains two columns, the salutation and the first_name. The salutation is sorted first in descending order. Within each salutation, the first name is sorted in ascending order.

    SELECT salutation, first_name, last_name
      FROM student
     WHERE last_name = 'Grant'
    ORDER BY salutation DESC, first_name ASC
    SALUT FIRST_NAME 		LAST_NAME
    ----- ----------------- ---------
    Ms.   Eilene 			Grant
    Ms.   Verona 			Grant
    Mr.   Omaira 			Grant
    Mr.   Scott 			Grant
    
    4 rows selected.

Again, you can write the query also with this ORDER BY clause:

ORDER BY 1 DESC, 2 ASC

Or to use the default order for the second column, which is ASC and can be omitted:

ORDER BY 1 DESC, 2

If you give your column a column alias, you can also use the column alias in the ORDER BY clause.

SELECT salutation "Sal", first_name "First Name",
 	   last_name "Last Name"
 	FROM student
 WHERE last_name = 'Grant'
 ORDER BY "Sal" DESC, "First Name" ASC
Sal   First Name 		Last Name
----- ----------------- ---------
Ms.   Eilene 			Grant
Ms.   Verona 			Grant
Mr.   Omaira 			Grant
Mr.   Scott 			Grant

4 rows selected.
  1. Execute the following query. What do you observe about the last row returned by the query?

  2. SELECT student_id, last_name
      FROM student
     ORDER BY last_name

    Answer: The student with the student_id of 206 has the last name entered in lowercase. When ordering the result set, the lowercase letters are listed after the uppercase letters.

    STUDENT_ID LAST_NAME
    ---------- ----------
    	   119 Abdou
    	   399 Abdou
    ...
    	   184 Zuckerberg
    	   206 annunziato
    
    268 rows selected.

Lab 2.5 Self-Review Questions

In order to test your progress, you should be able to answer the following questions.

  1. The following is the correct order of all clauses in this SELECT statement:

  2. SELECT ...
      FROM ...
     ORDER BY ...
     WHERE ...
    1. True

    2. False

  3. You must explicitly indicate whether an ORDER BY is ascending.

    1. True

    2. False

  4. The following statement is correct:

  5. SELECT *
      FROM instructor
     ORDER BY phone
    1. True

    2. False

  6. The following statement is incorrect:

  7. SELECT description "Description",
     			prerequisite AS prereqs,
     			course_no "Course#"
      FROM course
     ORDER BY 3, 2
    1. True

    2. False

  8. You can order by a column you have not selected.

    1. True

    2. False

Answers appear in Appendix A, Section 2.5.

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