Home > Articles > Data > SQL Server

Transact-SQL Improvements with SQL Server 2008, Part 2

📄 Contents

  1. Working with Multiple Groupings of Data in a Single Command
  2. Passing Multiple Data Rows to a Stored Procedure with Table-Valued Parameters
Database administration expert Baya Dewald discusses improvements to Transact-SQL language in SQL Server 2008. He concludes this two-part series by discussing functions for grouping and table-valued parameters for passing multiple data rows to a stored procedure.
Like this article? We recommend

Like this article? We recommend

In this article, we'll continue our brief look at new and changed Transact-SQL functionality in SQL Server 2008. In part 1 of this series, we considered initializing and incrementing variables, merging multiple data sets into one, separating date and time values with new data types, and some new functions for dealing with date and time. Now we'll take a look at functions for grouping, as well as how to use table-valued parameters to pass multiple data rows to a stored procedure.

Working with Multiple Groupings of Data in a Single Command

The SELECT statement's GROUP BY clause has been extended to allow for a new GROUPING SETS option, which enables you to have multiple groupings of data in a single command. For example, a quick look at the Person.Address table in the AdventureWorks sample database reveals that persons reside in different cities within multiple states. The following query shows the number of persons in each combination of city and state/province:

SELECT b.Name AS StateProvince, a.City, COUNT(*) AS NumberOfAddresses
FROM Person.Address a
INNER JOIN Person.StateProvince b
ON a.StateProvinceID = b.StateProvinceID
GROUP BY b.Name, a.City
ORDER BY 3 DESC

The following table shows partial results of this query:

StateProvince

City

NumberOfAddresses

England

London

434

Seine (Paris)

Paris

398

Washington

Burien

215

California

Concord

214

Washington

Bellingham

213

Oregon

Beaverton

213

California

Chula Vista

207

However, this result doesn't produce subtotals by each city and each province. I can easily modify this query to include subtotals for each city name, province name, and a combination of city and state, simply by adding the GROUPING SETS clause:

SELECT b.Name AS StateProvince, a.City, COUNT(*) AS NumberOfAddresses
FROM Person.Address a
INNER JOIN Person.StateProvince b
ON a.StateProvinceID = b.StateProvinceID
GROUP BY GROUPING SETS (b.Name, a.City, (a.City, b.Name))
ORDER BY 3 DESC

Partial results:

StateProvince

City

NumberOfAddresses

California

NULL

4564

Washington

NULL

2636

England

NULL

1954

New South Wales

NULL

1588

British Columbia

NULL

1579

Oregon

NULL

1105

NULL

London

434

England

London

434

NULL

Paris

398

Seine (Paris)

Paris

398

To be fair, previous versions of SQL Server also allowed constructing a similar output, but doing so would require considerably more typing. The following query would return results identical to the one above:

SELECT b.Name AS StateProvince, NULL AS City, COUNT(*) AS NumberOfAddresses
 FROM Person.Address a
INNER JOIN Person.StateProvince b
ON a.StateProvinceID = b.StateProvinceID
GROUP BY b.Name
UNION ALL
SELECT NULL AS StateProvince, City, COUNT(*) AS NumberOfAddresses
 FROM Person.Address a
INNER JOIN Person.StateProvince b
ON a.StateProvinceID = b.StateProvinceID
GROUP BY City
UNION ALL
SELECT b.Name AS StateProvince, City, COUNT(*) AS NumberOfAddresses
 FROM Person.Address a
INNER JOIN Person.StateProvince b
ON a.StateProvinceID = b.StateProvinceID
GROUP BY b.Name, City
ORDER BY 3 DESC

In addition to saving the effort of typing a much longer statement, the GROUPING SETS clause provides considerably better performance than the equivalent statement using a UNION ALL construct. As the statistics report below shows, the SELECT command using the GROUPING SETS clause scans the Address table twice, whereas the statement using UNION ALL scans the same table three times:

Statistics report for GROUPING SETS:

Table 'Address'. Scan count 2, logical reads 245, physical reads 6,
 read-ahead reads 240, lob logical reads 0, lob physical reads 0,
 lob read-ahead reads 0.
Table 'StateProvince'. Scan count 2, logical reads 7, physical reads 2,
 read-ahead reads 0, lob logical reads 0, lob physical reads 0,
 lob read-ahead reads 0.
Table 'Worktable'. Scan count 0, logical reads 0, physical reads 0,
 read-ahead reads 0, lob logical reads 0, lob physical reads 0,
 lob read-ahead reads 0.


Statistics report for UNION ALL:

Table 'Worktable'. Scan count 0, logical reads 0, physical reads 0,
 read-ahead reads 0, lob logical reads 0, lob physical reads 0,
 lob read-ahead reads 0.
Table 'Address'. Scan count 3, logical reads 461, physical reads 9,
 read-ahead reads 240, lob logical reads 0, lob physical reads 0,
 lob read-ahead reads 0.
Table 'StateProvince'. Scan count 2, logical reads 7, physical reads 2,
 read-ahead reads 0, lob logical reads 0, lob physical reads 0,
 lob read-ahead reads 0.

Transact-SQL now also includes ANSI-standard ROLLUP and CUBE operators, which are shorthand alternatives to GROUPING SETS. For example, the following query will produce subtotals for each state/province and a grand total for all addresses:

SELECT b.Name AS StateProvince, a.City, COUNT(*) AS NumberOfAddresses
FROM Person.Address a
INNER JOIN Person.StateProvince b
ON a.StateProvinceID = b.StateProvinceID
GROUP BY ROLLUP (b.name, a.City)
ORDER BY 1

Partial results:

StateProvince

City

NumberofAddresses

NULL

NULL

19614

Alabama

Birmingham

2

Alabama

Florence

1

Alabama

Huntsville

2

Alabama

Mobile

1

Alabama

Montgomery

1

Alabama

NULL

7

Alberta

Calgary

23

Alberta

Edmonton

2

Alberta

NULL

25

Arizona

Chandler

4

Arizona

Gilbert

1

Arizona

Lemon Grove

2

Arizona

Mesa

1

Arizona

Phoenix

5

Arizona

Scottsdale

2

Arizona

Surprise

1

Arizona

Tucson

2

Arizona

NULL

18

The next query will produce subtotals for each city, subtotals for each state, and the grand total for all addresses:

SELECT b.Name AS StateProvince, a.City, COUNT(*) AS NumberOfAddresses
FROM Person.Address a
INNER JOIN Person.StateProvince b
ON a.StateProvinceID = b.StateProvinceID
GROUP BY CUBE (b.name, a.City)
ORDER BY 1

The GROUPING_ID function allows us to identify the column(s) used to aggregate the results. To demonstrate, I'll limit the output to cities found in Alabama:

SELECT
      GROUPING_ID(b.Name, a.City) AS grouping_bits,
      b.Name AS StateProvince,
      a.City,
      COUNT(*) AS NumberOfAddresses
FROM Person.Address a
INNER JOIN Person.StateProvince b
ON a.StateProvinceID = b.StateProvinceID
WHERE b.Name = 'Alabama'
GROUP BY CUBE (b.name, a.City)
ORDER BY 1, 3

Results:

grouping_bits

StateProvince

City

NumberofAddresses

0

Alabama

Birmingham

2

0

Alabama

Florence

1

0

Alabama

Huntsville

2

0

Alabama

Mobile

1

0

Alabama

Montgomery

1

1

Alabama

NULL

7

2

NULL

Birmingham

2

2

NULL

Florence

1

2

NULL

Huntsville

2

2

NULL

Mobile

1

2

NULL

Montgomery

1

3

NULL

NULL

7

Notice that I passed the state column first to the GROUPING_ID function, followed by city. So the grouping bits column will have a value of 1 if results are aggregated by state, 2 if aggregated by city, and 3 (1+2) if aggregated by both. If addresses are displayed for a combination of city and state, we aren't aggregating by either column, so grouping bits will have a value of zero. Note also that the grouping bits column allowed for a very nice option for sorting the results (using the ORDER BY clause). Similarly, if the result set was large, we could materialize it—persist it as an indexed view or table—and build an index on the grouping bits column for faster data retrieval.

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