SQL Sunday Fun – Word Search with New T-SQL 2012 Functionality

 

 

new_sql2012_word_jumbleClick on the grid to enlarge, then print it.

Find the following words in the grid up, down, left, right, horizontal, vertical, and diagonal.

ROWS  RANGE  PRECEDING 
FOLLOWING  UNBOUNDED  IIF 
CHOOSE  OFFSET  FETCH 
FORMAT  CONCAT  SEQUENCE 
PARSE  TRYPARSE  TRYCONVERT 
THROW  LEAD  LAG 
FIRSTVALUE  LASTVALUE  PERCENTRANK 
CUMEDIST  PERCENTILEDISC  PERCENTILECONT 

NOTE:  some of these terms normally have an underscore in them, but for the purpose of the word scramble the underscores have been omitted.

 

Related Links:

SEQUENCE object

CHOOSE function

Analytics – Analytic Functions – PERCENT_RANK

Analytics PERCENTILE_DISC and PERCENTILE_CONT

IIF function in TSQL.

TSQL Analytic Functions LEAD and LAG

OVER clause with ROWS PRECEDING and FOLLOWING in TSQL 2012

OFFSET / FETCH in a SELECT statement

Cumulative Distribution Function (CDF) or as it is known in TSQL CUME_DIST()

 

 

Rows and Range, Preceding and Following

SQL Server 2012 adds many new features to Transact SQL (T-SQL).  One of my favorites is the Rows/Range enhancements to the over clause. These enhancements are often times referred to as the windowing functions.

Overview:
ROWS PRECEDING, FOLLOWING, UNBOUNDED, refers to the current row and those before or after based on preceding or following.
RANGE PRECEDING, FOLLOWING, UNBOUNDED, means all values in the current range and those before or after.

An example of a need for rows preceding would be to calculate a 3 year trailing average, which needs to look at the current year and the three previous years in the calculation.

Terminology:
ROWS or RANGE- specifying rows or range.
PRECEDING – get rows before the current one.
FOLLOWING – get rows after the current one.
UNBOUNDED – when used with PRECEDING or FOLLOWING, it returns all before or after.
CURRENT ROW

To start out we need a database to work on, so we will create a tsql2012 database. you can use your own database if you wish.

CREATE DATABASE [tsql2012];
GO
USE [tsql2012];

Next we create a table to use for the over clause enhancments of rows and range preceding and following.

-- Table to be used by Over Clause Rows/Range

CREATE TABLE REVENUE
(
[DepartmentID] int,
[Revenue] int,
[Year] int
);

insert into REVENUE
values (1,10030,1998),(2,20000,1998),(3,40000,1998),
 (1,20000,1999),(2,60000,1999),(3,50000,1999),
 (1,40000,2000),(2,40000,2000),(3,60000,2000),
 (1,30000,2001),(2,30000,2001),(3,70000,2001),
 (1,90000,2002),(2,20000,2002),(3,80000,2002),
 (1,10300,2003),(2,1000,2003), (3,90000,2003),
 (1,10000,2004),(2,10000,2004),(3,10000,2004),
 (1,20000,2005),(2,20000,2005),(3,20000,2005),
 (1,40000,2006),(2,30000,2006),(3,30000,2006),
 (1,70000,2007),(2,40000,2007),(3,40000,2007),
 (1,50000,2008),(2,50000,2008),(3,50000,2008),
 (1,20000,2009),(2,60000,2009),(3,60000,2009),
 (1,30000,2010),(2,70000,2010),(3,70000,2010),
 (1,80000,2011),(2,80000,2011),(3,80000,2011),
 (1,10000,2012),(2,90000,2012),(3,90000,2012);

Take a look at the revenue table to see whats there before we start the demo.


USE [tsql2012];

-- first lets look at the REVENUE table

SELECT *
 FROM Revenue;

rows_range_preceding_following1
Contents of the REVENUE table.

Then a quick review of sum and avg.

-- first simple sum and avg aggregates
SELECT sum(Revenue) as TotalRevenue,
 avg(Revenue) as AverageRevenue,
 count(*) as NumRows
 FROM Revenue;

rows_range_preceding_following2

OVER Clause Pre SQL Server 2012

The OVER clause before SQL Server 2012 is really handy to perform aggregates over a different range than your standard grouping.

--First OVER Clause pre SQL 2012
SELECT *,
 avg(Revenue) OVER (PARTITION by DepartmentID) as AverageDeptRevenue,
 sum(Revenue) OVER (PARTITION by DepartmentID) as TotalDeptRevenue
FROM REVENUE
ORDER BY departmentID, year;

rows_range_preceding_following3

ROWS PRECEDING

Now the new features, ROWS PRECEDING specifies the the aggregate functions in the current partition in the OVER clause will consider the current row, and a specific number of rows before the current row.


--ROWS PRECEDING
-- look at the sum of revenue over a trailing 3 year period
SELECT Year, DepartmentID, Revenue,
 sum(Revenue) OVER (PARTITION by DepartmentID
 ORDER BY [YEAR]
 ROWS BETWEEN 3 PRECEDING AND CURRENT ROW) as CurrentAndPrev3
FROM REVENUE
ORDER BY departmentID, year;

rows_range_preceding_following4

ROWS FOLLOWING

Now rows following… The ROWS FOLLOWING option specifies a specific number of rows in the current partition to use after the current row.

-- ROWS FOLLOWING
SELECT Year, DepartmentID, Revenue,
 sum(Revenue) OVER (PARTITION by DepartmentID
 ORDER BY [YEAR]
 ROWS BETWEEN CURRENT ROW AND 3 FOLLOWING) as CurrentAndNext3
FROM REVENUE
ORDER BY departmentID, year;

rows_range_preceding_following5

Both PRECEDING and FOLLOWING

Using both ROWS PRECEDING and ROWS FOLLOWING allows you to do things like calculate an average including the current year and years both before and after the current year.


--ROWS PRECEDING AND FOLLOWING

SELECT Year, DepartmentID, Revenue,
 sum(Revenue) OVER (PARTITION by DepartmentID
 ORDER BY [YEAR]
 ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING) as BeforeAndAfter
FROM REVENUE
ORDER BY departmentID, year;

rows_range_preceding_following6

UNBOUNDED

UNBOUNDED PRECEDING tells the windowing function and aggregrates to use the current value, and all values in the partition before the current value.

-- ROWS UNBOUNDED PRECEDING
SELECT Year, DepartmentID, Revenue,
 min(Revenue) OVER (PARTITION by DepartmentID
 ORDER BY [YEAR]
 ROWS UNBOUNDED PRECEDING) as MinRevenueToDate
FROM REVENUE
ORDER BY departmentID, year;

rows_range_preceding_following7

When using UNBOUNDED FOLLOWING as follows, this means the use the current row, and consider all rows after the current row in the current partition.

-- ROWS UNBOUNDED FOLLOWING
-- http://stevestedman.com/?p=1485
SELECT Year, DepartmentID, Revenue,
 min(Revenue) OVER (PARTITION by DepartmentID
 ORDER BY [YEAR]
 ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING) as MinRevenueBeyond
FROM REVENUE
ORDER BY departmentID, year;

rows_range_preceding_following8

ROWS vs RANGE

ROWS vs RANGE appears to cause much confusion.

ROWS means the specific row or rows specified, and RANGE refers to those same rows plus any others that have the same matching values.

Here is an example of ROWS and RANGE producing the exact same results because the years and department IDs don’t have any duplicates. In this case the ROWS and RANGE are identical.

-- ROWS vs RANGE UNBOUNDED PRECEDING

SELECT Year, DepartmentID, Revenue,
 sum(Revenue) OVER (PARTITION by DepartmentID
 ORDER BY [YEAR]
 ROWS UNBOUNDED PRECEDING) as RowsCumulative,
 sum(Revenue) OVER (PARTITION by DepartmentID
 ORDER BY [YEAR]
 RANGE UNBOUNDED PRECEDING) as RangeCumulative
FROM REVENUE
WHERE year between 2003 and 2008
ORDER BY departmentID, year;

rows_range_preceding_following9

Now if we consider the same query of ROWS vs RANGE with duplicate values. Here we insert a duplicate set of values for 2005, and the results below show that for the year 2005 there are two rows in the result set, and the RowsCumulative column is different form the RangeCumulative.  The rows counts the specific rows it the aggregate calculation, the range counts the current row, plus the other 2005 rows for that department id.

-- INSERT A DUPLICATE VALUE FOR RANGE UNBOUNDED PRECEEDING

INSERT INTO REVENUE
VALUES (1,10000,2005),(2,20000,2005),(3,30000,2005);

-- same query as above
SELECT Year, DepartmentID, Revenue,
 sum(Revenue) OVER (PARTITION by DepartmentID
 ORDER BY [YEAR]
 ROWS UNBOUNDED PRECEDING) as RowsCumulative,
 sum(Revenue) OVER (PARTITION by DepartmentID
 ORDER BY [YEAR]
 RANGE UNBOUNDED PRECEDING) as RangeCumulative
FROM REVENUE
WHERE year between 2003 and 2008
ORDER BY departmentID, year;

rows_range_preceding_following10

Summary

With all the great new features in SQL Server 2012, the windowing functions, ROWS and RANGE, PRECEDING and FOLLOWING updates to the OVER clause are a great addition.

Happy Birthday SQL Server 2012

It has been a year since SQL Server 2012 released.

There were some fun posts on Twitter about the SQL Server 2012 birthday or anniversary. For instance:

declare @greetings varchar(100)

SET @greetings= 'Happy Birthday @SQLServer 2012'

SELECT @greetings

and another anniversary query (which doesn’t actually run):

SELECT Happy FROM Anniversary WHERE Year = 1 AND Version = '11.0.2100.60';

1 year out since SQL 2012 released, and here are some things to note:

There is no more Business Intelligence Development Studio (BIDS) in SQL Server 2012, instead it has been replaced with the SQL Server Data Tools that uses the core of Visual Studio 2010, with the Report Builder and Report Designer built in to the new Visual Studio.

SQL Server 2012 introduced a new T-SQL object used to generate numbers, a SEQUENCE, similar to an identity column.

SQL Server 2012 introduced the IIF statement. It is very similar to the IIF statement in MS Access.

In SQL Server 2012 there is a new function called CHOOSE that takes in an offset, and a list of options.

The OFFSET and FETCH functionality was added  to achieve data paging server side in TSQL.

Other Notable features:

I hope you are able to get as much out of SQL Server 2012 as I am.  Happy Birthday to SQL Server 2012.

SQL Saturday Presentation

I am at SQL Saturday in Vancouver BC today.

Here is the download of my presentation.

Download zip file.

Here is the presentation outline.

  • OVER Clause Enhancements
  • ROWS PRECEDING, FOLLOWING, UNBOUNDED
  • RANGE PRECEDING, FOLLOWING, UNBOUNDED
  • IIF – Immediate IF or Inline IF (from Access)
  • CHOOSE (from Access)
  • OFFSET / FETCH
  • FORMAT
  • CONCAT
  • SEQUENCE (from Oracle)
  • sp_describe_first_result_set
  • New Date and Time Functions
  • Conversion Functions
  • PARSE, TRY_PARSE, TRY_CONVERT
  • THROW exception

My Top 10 TSQL Enhancements in SQL Server 2012

So far after playing around with SQL Server 2012 there are many new features to SQL.  Overall I think my favorites are in the Analytic Functions category.  Here is my breakdown of the top 10 transact SQL enhancements to SQL Server 2012.

10.  New SEQUENCE object

9.  CHOOSE function

8.  Analytics – Analytic Functions – PERCENT_RANK

7.  Analytics PERCENTILE_DISC and PERCENTILE_CONT

6. IIF function in TSQL.

5. TSQL Analytic Functions LEAD and LAG

4.  OVER clause with ROWS PRECEDING and FOLLOWING in TSQL 2012

3.  OFFSET / FETCH in a SELECT statement

2.  LAST_VALUE and FIRST_VALUE

1.  Cumulative Distribution Function (CDF) or as it is known in TSQL CUME_DIST()

Whats your favorite?

IIF in TRANSACT SQL on SQL SERVER 2012

For years I have heard the question of how can I do an IIF in TSQL?  Honestly I never thought it would be that useful since the CASE statement is easy enough to use, but after seeing it in TSQL 2012, I can safely say I like it.

The answer used to be, just use the CASE statement, and the CASE statement in TSQL has worked great for years.

Here is the sample showing the differences between IIF and CASE, using the revenue table from the same database I used in a previous ROWS PRECEDING and FOLLOWING in TSQL 2012 example.


-- assume we want to display an indicator to see if we are above
-- or below average. First we start with the average over departmentID
select Year, DepartmentID, Revenue,
 avg(Revenue) OVER (PARTITION by DepartmentID) as AverageRevenue
from REVENUE
order by DepartmentID, year;

-- without IIF using the CASE statement we would get the following
select Year, DepartmentID, Revenue, AverageRevenue,
 case when Revenue > AverageRevenue THEN 'Better Than Average'
 else 'Not' end as Ranking
from (select Year, DepartmentID, Revenue,
 avg(Revenue) OVER (PARTITION by DepartmentID) as AverageRevenue
 from REVENUE ) as t
order by DepartmentID, year;

-- now the same functionality using IIF and simplifying the code
select Year, DepartmentID, Revenue, AverageRevenue,
 iif(Revenue > AverageRevenue, 'Better Than Average', 'Not') as Ranking
from (select Year, DepartmentID, Revenue,
 avg(Revenue) OVER (PARTITION by DepartmentID) as AverageRevenue
 from REVENUE ) as t
order by DepartmentID, year;

Narrowing it down to just the differences

CASE WHEN Revenue > AverageRevenue

THEN 'Better Than Average'
 ELSE 'Not' end as Ranking

IIF(Revenue > AverageRevenue, 'Better Than Average', 'Not') as Ranking

Comparing the two, they aren’t that different, other than the IIF option is easier to remember.  Also, I did analyze the plan and there is no difference in the execution time between the two.

 

It is going to take some getting used to, but I consider the IIF to be a simple time savings for the TSQL programmer in SQL Server 2012.