Home > Articles

This chapter is from the book

10.9 Complex Examples with GROUP BY

Consider the following examples that illustrate the extensive possibilities of the GROUP BY clause.

Example 10.17: What is the average total amount of penalties for players who live in Stratford and Inglewood?

SELECT   AVG(TOTAL)
FROM    (SELECT   PLAYERNO, SUM(AMOUNT) AS TOTAL
         FROM     PENALTIES
         GROUP BY PLAYERNO) AS TOTALS
WHERE    PLAYERNO IN 
        (SELECT   PLAYERNO
         FROM     PLAYERS
         WHERE    TOWN = 'Stratford' OR TOWN = 'Inglewood')

The result is:

AVG(TOTAL)
----------
       85

Explanation: The intermediate result of the subquery in the FROM clause is a table consisting of two columns, called PLAYERNO and TOTAL, and five rows (players 6, 8, 27, 44, and 104). This table is passed on to the WHERE clause, in which a subquery is used to select players from Stratford and Inglewood (players 6, 8, and 44). Finally, the average is calculated in the SELECT clause of the column TOTAL.

Example 10.18: For each player (who incurred penalties and is captain), get the player number, name, number of penalties that he or she incurred, and number of teams that he or she captains.

SELECT   PLAYERS.PLAYERNO, NAME, NUMBER_OF_PENALTIES,
         NUMBER_OF_TEAMS
FROM     PLAYERS,
        (SELECT   PLAYERNO, COUNT(*) AS NUMBER_OF_PENALTIES
         FROM     PENALTIES
         GROUP BY PLAYERNO) AS NUMBER_PENALTIES,
        (SELECT   PLAYERNO, COUNT(*) AS NUMBER_OF_TEAMS
         FROM     TEAMS
         GROUP BY PLAYERNO) AS NUMBER_TEAMS
WHERE    PLAYERS.PLAYERNO = NUMBER_PENALTIES.PLAYERNO
AND      PLAYERS.PLAYERNO = NUMBER_TEAMS.PLAYERNO

The result is:

PLAYERNO  NAME       NUMBER_OF_PENALTIES  NUMBER_OF_TEAMS

--------  ---------  -------------------  ---------------
       6  Parmenter                    1                 1
      27  Collins                      2                 1

Explanation: The FROM clause contains two subqueries that both have a GROUP BY clause.

We could more easily formulate the previous statement by including subqueries in the SELECT clause, which eliminates the need for GROUP BY clauses. See the next example, and note that the only difference is that all players appear in the result.

SELECT   PLAYERS.PLAYERNO, NAME,
        (SELECT    COUNT(*) 
         FROM      PENALTIES
         WHERE     PLAYERS.PLAYERNO =
                   PENALTIES.PLAYERNO) AS NUMBER_OF_PENALTIES,
        (SELECT    COUNT(*)
         FROM      TEAMS
         WHERE     PLAYERS.PLAYERNO =
                   TEAMS.PLAYERNO) AS NUMBER_OF_TEAMS
FROM     PLAYERS

Example 10.19: Get the player number and total number of penalties for each player who played a match.

SELECT    DISTINCT M.PLAYERNO, NUMBERP
FROM      MATCHES AS M LEFT OUTER JOIN
           (SELECT   PLAYERNO, COUNT(*) AS NUMBERP
            FROM     PENALTIES
            GROUP BY PLAYERNO) AS NP
         ON M.PLAYERNO = NP.PLAYERNO

Explanation: In this statement, the subquery creates the following intermediate result (this is the NP table):

PLAYERNO   NUMBERP
--------  --------
       6         1
       8         1
      27         2
      44         3
     104         1

Next, this table is joined with the MATCHES table. We execute a left outer join, so no players will disappear from this table. The final result is:

PLAYERNO  NUMBERP
--------   -------
       2         ?
       6         1
       8         1
      27         2
      44         3
      57         ?
      83         ?
     104         1
     112         ?

Example 10.20: Group the penalties on the basis of payment date. Group 1 should contain all penalties between January 1, 1980, and June 30, 1982; group 2 should contain all penalties between July 1, 1981, and December 31, 1982; and group 3 should contain all penalties between January 1, 1983, and December 31, 1984. For each group, get the sum of all penalties.

SELECT   GROUPS.PGROUP, SUM(P.AMOUNT)
FROM     PENALTIES AS P,
        (SELECT 1 AS PGROUP, '1980-01-01' AS START, 
                '1981-06-30' AS END
         UNION
         SELECT 2, '1981-07-01', '1982-12-31'
         UNION
         SELECT 3, '1983-01-01', '1984-12-31') AS GROUPS
WHERE    P.PAYMENT_DATE BETWEEN START AND END
GROUP BY GROUPS.PGROUP
ORDER BY GROUPS.PGROUP

The result is:

GROUP  SUM(P.AMOUNT)
-----   -------------
    1          225.00
    2           30.00
    3          225.00

Explanation: In the FROM clause, a new (virtual) table is created in which the three groups have been defined. This GROUPS table is joined with the PENALTIES table. A BETWEEN operator is used to join the two tables. Penalties with a payment date that falls outside these groups will not be included in the result.

Example 10.21: For each penalty, get the penalty amount plus the sum of that amount and the amounts of all penalties with a lower payment number (cumulative value).

SELECT   P1.PAYMENTNO, P1.AMOUNT, SUM(P2.AMOUNT)
FROM     PENALTIES AS P1, PENALTIES AS P2
WHERE    P1.PAYMENTNO >= P2. PAYMENTNO
GROUP BY P1. PAYMENTNO, P1.AMOUNT
ORDER BY P1. PAYMENTNO

For convenience, assume that the PENALTIES table consists of the following three rows only (you can create this, too, by temporarily removing all penalties with a number greater than 3):

PAYMENTNO  PLAYERNO  PAYMENT_DATE  AMOUNT
---------  --------  ------------  ------
        1         6  1980-12-08       100
        2        44  1981-05-05        75
        3        27  1983-09-10       100

The desired result is:

PAYMENTNO  AMOUNT     SUM
---------  ------   -----
        1     100     100
        2      75     175
        3     100     275

The intermediate result of the FROM clause (showing only the columns PAYMENTNO and AMOUNT):

P1.PAYNO  P1.AMOUNT  P2.PAYNO   P2.AMOUNT
--------  ---------  --------   ---------
       1        100         1         100
       1        100         2          75
       1        100         3         100
       2         75         1         100
       2         75         2          75
       2         75         3         100
       3        100         1         100
       3        100         2          75
       3        100         3         100

The intermediate result of the WHERE clause:

P1.PAYNO  P1.AMOUNT  P2.PAYNO  P2.AMOUNT
--------  ---------  --------  ---------
       1        100         1        100
       2         75         1        100
       2         75         2         75
       3        100         1        100
       3        100         2         75
       3        100         3        100

The intermediate result of the GROUP BY clause:

P1.PAYNO  P1.AMOUNT  P2.PAYNO    P2.AMOUNT
--------  ---------  ---------  --------------
       1        100  {1}        {100}
       2         75  {1, 2}     {100, 75}
       3        100  {1, 2, 3}  {100, 75, 100}

The intermediate result of the SELECT clause:

P1.PAYNO  P1.AMOUNT  SUM(P2.AMOUNT)
--------  ---------  --------------
       1        100             100
       2         75             175
       3        100             275

This final result is equal to the desired table.

Most joins in this book (and in the real world) are equi joins. Non-equi joins are rare. However, the previous statement shows an example where non-equi joins can be useful and the powerful statements they can formulate.

Example 10.22: For each penalty, get the payment number, penalty amount, and percentage that the amount forms of the sum of all amounts (use the same PENALTIES table as in the previous example).

SELECT   P1.PAYMENTNO, P1.AMOUNT,
         (P1.AMOUNT * 100) / SUM(P2.AMOUNT)
FROM     PENALTIES AS P1, PENALTIES AS P2
GROUP BY P1.PAYMENTNO, P1.AMOUNT
ORDER BY P1.PAYMENTNO

The intermediate result of the FROM clause is equal to that of the previous example. However, the intermediate result of the GROUP BY clause differs:

P1.PAYNO  P1.AMOUNT  P2.PAYNO   P2.AMOUNT
--------  ---------  ---------  --------------
       1        100  {1, 2, 3}  {100, 75, 100}
       2         75  {1, 2, 3}  {100, 75, 100}
       3        100  {1, 2, 3}  {100, 75, 100}

The intermediate result of the SELECT clause is:

P1.PAYNO  P1.AMOUNT  (P1.AMOUNT * 100) / SUM(P2.AMOUNT)
--------  ---------  ----------------------------------
       1        100                               36.36
       2         75                               27.27
       3        100                               36.36

Determine yourself whether this is the final result.

Exercise 10.14: How many players live in a town, on average?

Exercise 10.15: For each team, get the team number, division, and number of players that played matches for that team.

Exercise 10.16: For each player, get the player number, name, sum of all penalties that he or she incurred, and number of teams from the first division that he or she captains.

Exercise 10.17: For each team captained by a player who lives in Stratford, get the team number and number of players who have won at least one match for that team.

Exercise 10.18: For each player, get the player number, name, and difference between the year in which he or she joined the club and the average year of joining the club.

Exercise 10.19: For each player, get the player number, name, and difference between the year in which he or she joined the club and the average year in which players who live in the same town joined the club.

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