Call now: (800) 766-1884  



 Home


 SQL Server Tips
 SQL Server Training

 SQL Server Consulting
 SQL Server Support
 SQL Server Remote DBA



 Articles
 Services
 SQL Server Scripts
 Scripts Menu



 

 

 

   
  SQL Server Tips by Gama and Naughter


Views

A view is a virtual table, it contains no data of its own. Views are created from tables, other views, UDF's, OPENQUERY, etc... Their contents are either a filtered set of rows or calculated columns or both. Complex queries can be stored as views and used by many other views or SP's.

Example: To calculate the total of each order by summing the cost of the purchased items and considering that one order detail has a quantity column to be multiplied by the unit price. Grouping by order assures that every row has the data from one order only.

CREATE VIEW dbo.myOrderCost
AS
SELECT dbo.Orders.OrderID, dbo.Orders.OrderDate, SUM((dbo.[Order Details].UnitPrice * dbo.[Order Details].Quantity)
* (1 - dbo.[Order Details].Discount)) AS total
FROM dbo.Orders INNER JOIN
dbo.[Order Details] ON dbo.Orders.OrderID = dbo.[Order Details].OrderID
GROUP BY dbo.Orders.OrderID, dbo.Orders.OrderDate


Example: To calculate the total of all orders by month. In this situation, the result is grouped by the month number and year number.

CREATE VIEW dbo.myMonthlyCost
AS
SELECT TOP 100 PERCENT YEAR(dbo.Orders.OrderDate) AS order_year, MONTH(dbo.Orders.OrderDate) AS order_month,
SUM((dbo.[Order Details].UnitPrice * dbo.[Order Details].Quantity) * (1 - dbo.[Order Details].Discount)) AS total
FROM dbo.Orders INNER JOIN
dbo.[Order Details] ON dbo.Orders.OrderID = dbo.[Order Details].OrderID
GROUP BY MONTH(dbo.Orders.OrderDate), YEAR(dbo.Orders.OrderDate)
ORDER BY YEAR(dbo.Orders.OrderDate), MONTH(dbo.Orders.OrderDate)


Example: To calculate the total of all orders by month and the sum of all months until the current one, also included. This is only possible with the help of an extra column named all_month that will separate the same months from different years. This View uses a correlated subquery to calculate the sum of all months because a row cannot access the previous row from within the SELECT statement. It can only do it with another SELECT statement.

CREATE VIEW dbo.myMonthlyCostSum
AS
SELECT TOP 100 PERCENT YEAR(dbo.Orders.OrderDate) AS order_year, MONTH(dbo.Orders.OrderDate) AS order_month,
SUM((dbo.[Order Details].UnitPrice * dbo.[Order Details].Quantity) * (1 - dbo.[Order Details].Discount)) AS total,
(SELECT SUM((det.UnitPrice * det.Quantity) * (1 - det.Discount))
FROM dbo.Orders ord INNER JOIN
dbo.[Order Details] det ON ord.OrderID = det.OrderID
WHERE (YEAR(ord.OrderDate) * 12 + MONTH(ord.OrderDate)) <= (YEAR(dbo.Orders.OrderDate) * 12 + MONTH(dbo.Orders.OrderDate)))
AS total_sum, YEAR(dbo.Orders.OrderDate) * 12 + MONTH(dbo.Orders.OrderDate) AS all_month
FROM dbo.Orders INNER JOIN
dbo.[Order Details] ON dbo.Orders.OrderID = dbo.[Order Details].OrderID
GROUP BY MONTH(dbo.Orders.OrderDate), YEAR(dbo.Orders.OrderDate), YEAR(dbo.Orders.OrderDate) * 12 + MONTH(dbo.Orders.OrderDate)
ORDER BY YEAR(dbo.Orders.OrderDate), MONTH(dbo.Orders.OrderDate)


It is interesting to notice that table Order has a primary key OrderID with consecutive numbers and rows already sorted by date. A correlated subquery would work for getting the data from the previous row but, in this case, grouping rows renders that advantage useless.

Example: To calculate a View like the latest example but with a new total that would have the sum of all orders from the months before plus 10%.


CREATE VIEW dbo.myMonthlyCostSum10
AS
SELECT TOP 100 PERCENT YEAR(dbo.Orders.OrderDate) AS order_year, MONTH(dbo.Orders.OrderDate) AS order_month,
SUM((dbo.[Order Details].UnitPrice * dbo.[Order Details].Quantity) * (1 - dbo.[Order Details].Discount)) AS total,
(SELECT 1.1 * SUM((det.UnitPrice * det.Quantity) * (1 - det.Discount))
FROM dbo.Orders ord INNER JOIN
dbo.[Order Details] det ON ord.OrderID = det.OrderID
WHERE (YEAR(ord.OrderDate) * 12 + MONTH(ord.OrderDate)) <= (YEAR(dbo.Orders.OrderDate) * 12 + MONTH(dbo.Orders.OrderDate)))
AS total_sum, YEAR(dbo.Orders.OrderDate) * 12 + MONTH(dbo.Orders.OrderDate) AS all_month
FROM dbo.Orders INNER JOIN
dbo.[Order Details] ON dbo.Orders.OrderID = dbo.[Order Details].OrderID
GROUP BY MONTH(dbo.Orders.OrderDate), YEAR(dbo.Orders.OrderDate), YEAR(dbo.Orders.OrderDate) * 12 + MONTH(dbo.Orders.OrderDate)
ORDER BY YEAR(dbo.Orders.OrderDate), MONTH(dbo.Orders.OrderDate)


The result is wrong! The value of total_sum in the second row should be 61746.69538530349703 because the sum adds 10% to the current total plus the previous total_sum, which should have 10% from its own sum plus the corresponding total_sum.

The expected value was 61746.69538530349703 = (25485.274970054626 + 27861.894973754883 * 1.1) * 1.1 but, instead, it was 58681.8869381904599. This value comes from (27861.894973754883 + 25485.274970054626) * 1.1
This is not possible because SELECT statements are not recursive in SQL Server 2000. A solution for this problem is in the section about Cursors, in this chapter.
 


The above book excerpt is from:

Super SQL Server Systems
Turbocharge Database Performance with C++ External Procedures

ISBN: 0-9761573-2-2
Joseph Gama, P. J. Naughter

 http://www.rampant-books.com/book_2005_2_sql_server_external_procedures.htm
 

 

Burleson Consulting Remote DB Administration


 

 


 

 

 

 

 
Burleson is the America's Team

Note: The pages on this site were created as a support and training reference for use by our staff of DBA consultants.  If you find it confusing, please exit this page.

Errata?  SQL Server technology is changing and we strive to update our SQL Server support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:and include the URL for the page.
 


Burleson Consulting
SQL Server database support

 

Copyright 1996 -  2013 by Vaaltech Web Services. All rights reserved.

Hit Counter