Commit b1fb358b by O'Reilly Media, Inc.

Initial commit

parents
{\rtf1\ansi\ansicpg1252\cocoartf1038\cocoasubrtf350
{\fonttbl\f0\fswiss\fcharset0 Helvetica;}
{\colortbl;\red255\green255\blue255;}
\margl1440\margr1440\vieww9000\viewh8400\viewkind0
\pard\tx720\tx1440\tx2160\tx2880\tx3600\tx4320\tx5040\tx5760\tx6480\tx7200\tx7920\tx8640\ql\qnatural\pardirnatural
\f0\fs24 \cf0 No work files for this lesson...}
\ No newline at end of file
-- Scalar UDF Example
-- We will create a function to provide a more
-- descriptive result set for the EmailPromotion column
-- in the Person.EmailAddress table
SELECT * FROM Person.Person
-- Create a function named fnEmailPromo
-- It will accept EmailAddress as an input and
-- return a string value based on the int value
-- being passed in
-- We will use the function in a select statement
CREATE FUNCTION fnEmailPromo (@promo int)
RETURNS varchar(20)
AS
BEGIN
DECLARE @ret_promo varchar(20)
select @ret_promo=
CASE
WHEN @promo=0 then 'None'
WHEN @promo=1 then 'Local'
WHEN @promo=2 THEN 'National'
ELSE 'Not designated'
END
RETURN @ret_promo
END
-- Now, let's user our new fnEmailPromo function
-- Note that to call the new function we must include
-- dbo. in the name
SELECT FirstName + ' ' + Lastname Customer, dbo.fnEmailPromo(EmailPromotion) 'Promotion Type'
FROM Person.Person
-- TVF Example
-- Here are the three tables we will be getting our data from
select top 1 * from person.person
select top 1 * from person.emailaddress
select top 1 * from humanresources.employee
-- Our TVF will return the names and email addresses of our
-- employees based on their gender
-- Let's create our TVF
CREATE FUNCTION dbo.fnGetEmail(@gender char(1))
RETURNS TABLE
AS
RETURN
SELECT p.FirstName, p.Lastname,e.EmailAddress,em.Gender
FROM person.person p
JOIN person.EmailAddress e on p.BusinessEntityID=e.BusinessEntityID
JOIN HumanResources.Employee em on e.BusinessEntityID=em.BusinessEntityID
WHERE em.Gender=@gender
-- Let's use our TVF
SELECT * FROM dbo.fnGetEmail('m')
-- We can add a WHERE clause to get more creative with the results
SELECT * FROM dbo.fnGetEmail('m')
WHERE LastName LIKE 'D%'
--Correlated Subquery
--First let's look at a join query
SELECT DISTINCT p.BusinessEntityID, p.FirstName + ' ' + p.LastName Name
FROM
Person.Person p
JOIN
sales.SalesOrderHeader s
ON
p.BusinessEntityID=s.SalesPersonID
WHERE s.TotalDue>150000
--Now, let's write this as a correlated subquery
--NOTE that the inner query runs first and locates a matching record
--The outer query runs using the record found, then the inner query
--runs again searching for another match...until all records are found
SELECT p.BusinessEntityID, FirstName + ' ' + LastName Salesperson FROM Person.Person p
WHERE
EXISTS
(SELECT s.SalesPersonID FROM Sales.Salesorderheader s
WHERE TotalDue>150000
and p.BusinessEntityID=s.SalesPersonID)
-- Multi-vaued query examples
-- Let's start off with a simple multi-valued query
-- that returns a list of values
-- We need a list of employees who were born after 1972
-- Here' where we can get the data...
SELECT TOP 1 * from Person.Person
SELECT TOP 1 * from HumanResources.Employee
-- We can use a subquery to pull the list of BusinesEntityID's
-- for every BirthDate greater than 1972 in the Employee table
-- and use that list with the IN keyword to get the Employee names
-- from the Person table
SELECT Firstname + ' ' + Lastname Employee
FROM Person.Person
WHERE Person.BusinessEntityID IN
(SELECT BusinessEntityID
FROM HumanResources.Employee
WHERE Year(BirthDate)>1972)
ORDER BY LastName, FirstName
-- Now, let's use a table-value subquery...also known as a table expression
-- to find the last SalesOrderID for each year
SELECT OrderYear, MAX(SalesOrderID) LastOrderID
FROM
(SELECT SalesOrderID, Year(OrderDate) OrderYear -- Run this inner query separately
FROM Sales.SalesOrderHeader)as D -- to see the table being returned
GROUP BY OrderYear
ORDER BY OrderYear
-- Scalar Subquery Example
-- We want to retrieve the largest order amount
-- from the SalesOrderHeader table
SELECT * from Sales.SalesOrderHeader
-- Could we just use the MAX() function to find it?
SELECT MAX(TotalDue)
FROM Sales.SalesOrderHeader
-- MAX(TotalDue) gives us the largest order, but what is the
-- SalesOrderID?
-- This query will produce an error and we'll have to add group by
SELECT SalesOrderID,MAX(TotalDue)
FROM Sales.SalesOrderHeader
-- We can add GROUP BY, and use ORDER BY DESC to see the
-- largest order but this returns too many results
SELECT SalesOrderID,MAX(TotalDue) MaxOrder
FROM Sales.SalesOrderHeader
GROUP BY SalesOrderID
ORDER BY MaxOrder DESC
-- A scalar subquery makes this much easier
SELECT SalesOrderID, TotalDue
FROM Sales.SalesOrderHeader
WHERE TotalDue = (SELECT MAX(TotalDue) FROM Sales.SalesOrderHeader);
{\rtf1\ansi\ansicpg1252\cocoartf1038\cocoasubrtf350
{\fonttbl\f0\fswiss\fcharset0 Helvetica;}
{\colortbl;\red255\green255\blue255;}
\margl1440\margr1440\vieww9000\viewh8400\viewkind0
\pard\tx720\tx1440\tx2160\tx2880\tx3600\tx4320\tx5040\tx5760\tx6480\tx7200\tx7920\tx8640\ql\qnatural\pardirnatural
\f0\fs24 \cf0 No work files for this lesson...}
\ No newline at end of file
{\rtf1\ansi\ansicpg1252\cocoartf1038\cocoasubrtf350
{\fonttbl\f0\fswiss\fcharset0 Helvetica;}
{\colortbl;\red255\green255\blue255;}
\margl1440\margr1440\vieww9000\viewh8400\viewkind0
\pard\tx720\tx1440\tx2160\tx2880\tx3600\tx4320\tx5040\tx5760\tx6480\tx7200\tx7920\tx8640\ql\qnatural\pardirnatural
\f0\fs24 \cf0 No work files for this lesson...}
\ No newline at end of file
{\rtf1\ansi\ansicpg1252\cocoartf1038\cocoasubrtf350
{\fonttbl\f0\fswiss\fcharset0 Helvetica;}
{\colortbl;\red255\green255\blue255;}
\margl1440\margr1440\vieww9000\viewh8400\viewkind0
\pard\tx720\tx1440\tx2160\tx2880\tx3600\tx4320\tx5040\tx5760\tx6480\tx7200\tx7920\tx8640\ql\qnatural\pardirnatural
\f0\fs24 \cf0 No work files for this lesson...}
\ No newline at end of file
-- Basic SELECT Statement
-- The USE statement sets the context, or database,
-- that the query will be executed against
USE AdventureWorks2012;
SELECT
LastName, FirstName
FROM
Person.Person
\ No newline at end of file
-- Column Aliasing
USE AdventureWorks2012;
SELECT FirstName AS First, LastName AS Last
FROM Person.Person
WHERE LastName = 'Adams' AND FirstName = 'Alex'
SELECT FirstName 'Employee First Name', LastName 'Last Name'
FROM Person.Person
WHERE LastName = 'Adams' AND FirstName = 'Alex'
-- Concatenation Example
select LastName, FirstName
from person.person
-- Let's concatenate the Last and First names into one column
select distinct LastName + ', ' + FirstName AS Employee
from person.person
-- order by LastName, FirstName --Note this doesn't work...must use alias!
order by Employee
-- Now, let's concatenate a number with a name
-- This will fail due to the data type of EmailPromotion
select distinct FirstName + ' ' + LastName + ' : ' + EmailPromotion
from person.person
-- We can convert EmailPromotion to a string
select distinct FirstName + ' ' + LastName + ' : ' + CONVERT(varchar(5),EmailPromotion)
from person.person
-- We can also use CONCAT which will perform the conversion automatically
select CONCAT(FirstName,' ',LastName,' : ',EmailPromotion) Employee
from person.person
order by lastname, firstname
-- Using DISTINCT
USE AdventureWorks2012;
-- This query returns all columns and all rows
SELECT * FROM Sales.SalesOrderDetail
-- This query returns all ProductID rows from the table
-- including duplicate rows
SELECT ProductID FROM Sales.SalesOrderDetail
-- By using the DISTINCT keyword, we can limit the results
-- set to only the unique ProductID values in the table
SELECT DISTINCT ProductID FROM Sales.SalesOrderDetail
\ No newline at end of file
-- Orders the results by LastName only
select distinct LastName, FirstName, EmailPromotion
from Person.person
order by LastName
-- Orders the results by LastName, then FirstName
select distinct LastName, FirstName, EmailPromotion
from Person.person
order by LastName,FirstName
-- Orders the results by LastName in descending order (Z-A), then FirstName
select distinct LastName, FirstName, EmailPromotion
from Person.person
order by LastName DESC,FirstName
-- Orders the results by EmailPromotion
select distinct LastName, FirstName, EmailPromotion
from Person.person
order by EmailPromotion ASC
\ No newline at end of file
-- WHERE clause example
USE AdventureWorks2012;
SELECT
*
FROM
Person.Person
WHERE
LastName = 'Adams' AND FirstName = 'Alex'
select *
from Production.Product
-- Using a simple CASE expression
-- Adds a column to the result set that contains a
-- conditional result
select ProductID, Name, Availability=
CASE DaysToManufacture
WHEN '0' THEN 'Immediate'
WHEN '1' THEN 'Two Business Days'
WHEN '2' THEN 'Three Business Days'
WHEN '3' THEN 'Four Business Days'
Else 'Verify Availability'
END
from Production.Product
-- Using a searched CASE expression
-- Allows the use of comparison values in the CASE expression
select ProductID, Name, Availability=
CASE
WHEN DaysToManufacture = '0' THEN 'Immediate'
WHEN DaysToManufacture >0 AND DaysToManufacture < '4' THEN 'Four Business Days'
WHEN DaysToManufacture = '4' THEN 'Six Business Days'
ELSE 'Verify Availability'
END
from Production.Product
-- Here are all the products
select productid
from production.product
order by productid
-- Here are the products that have work orders
select productid
from production.workorder
-- Here's records for rows that have the same productid in the tables
-- on the left and right of the INTERSECT operator
select productid
from production.product
INTERSECT
select productid
from production.workorder
-- We can use EXCEPT to return all values from the left side of
-- the INTERSECT operator that do not appear on the right side
select productid
from production.product
EXCEPT
select productid
from production.workorder
-- Select all names with the last name of Adams
select Lastname + ', ' + Firstname
from person.person
where Lastname='Adams'
-- Select all last names that begin with A
select Lastname + ', ' + Firstname
from person.person
where Lastname like 'A%'
-- Select all names with 'ber' anywhere in the last name
select Lastname + ', ' + Firstname
from person.person
where Lastname like '%ber%'
-- Select all names with last names beginning with a, d, or g
select Lastname + ', ' + Firstname
from person.person
where Lastname LIKE '[adg]%'
-- Select all names with last names beginning with f, g, h, or i
select Lastname + ', ' + Firstname
from person.person
where Lastname LIKE '[f-i]%'
-- Select all names where last name is Adams, Jones, or Smith
-- and the first name begins with d, e, or f
select Lastname + ', ' + Firstname
from person.person
where Lastname IN ('Adams', 'Jones', 'Smith')
AND Firstname LIKE '[d-f]%'
--PIVOT Example
-- Let's create our example table
CREATE TABLE dbo.PivotTest
(
OrderID INT NOT NULL,
OrderDate DATE NOT NULL,
SalesID INT NOT NULL,
CustID VARCHAR(5) NOT NULL,
Qty INT NOT NULL,
CONSTRAINT PK_Orders PRIMARY KEY(OrderID)
);
-- Load the example table with test data
INSERT INTO dbo.PivotTest(OrderID, OrderDate, SalesID, CustID, Qty)
VALUES
(30001, '20120601', 3, 'A', 9),
(10001, '20121018', 2, 'A', 21),
(10005, '20121018', 1, 'B', 15),
(40001, '20130111', 3, 'A', 26),
(10006, '20130107', 1, 'C', 8),
(20001, '20130209', 2, 'B', 21),
(40005, '20140209', 1, 'A', 15),
(20002, '20140222', 1, 'C', 13),
(30003, '20140417', 2, 'B', 8),
(30004, '20120417', 3, 'C', 7),
(30007, '20130922', 2, 'D', 22);
-- Take a look at the contents of the PivotTest example table
SELECT * FROM dbo.PivotTest;
-- Let's produce some summarized data using GROUP BY
SELECT SalesID, CustID, SUM(Qty) 'Total Qty'
FROM PivotTest
GROUP BY SalesID, CustID
-- We have a request to produce a pivoted report...
-- SalesID on the left, with CustID's across the page
-- We can accomplish this manually using the T-SQL
-- CASE expression
SELECT SalesID,
SUM(CASE WHEN CustID = 'A' THEN Qty END) as A,
SUM(CASE WHEN CustID = 'B' THEN Qty END) as B,
SUM(CASE WHEN CustID = 'C' THEN Qty END) as C,
SUM(CASE WHEN CustID = 'D' THEN Qty END) as D
FROM PivotTest
GROUP BY SalesID
-- We can use the T-SQL PIVOT operator to achieve
-- the same result
SELECT SalesID, A, B, C, D
FROM
(SELECT SalesID, CustID, Qty -- This inner query produces a derived table named dt in memory that is
FROM PivotTest) as dt -- used to create the pivot table based on the outer query derived table pv
PIVOT(SUM(Qty) FOR CustID IN (A,B,C,D)) as pv
-- OFFSET and FETCH Examples
-- This query returns over 500 rows
SELECT productid, Name, ProductNumber, ListPrice
FROM Production.Product
ORDER BY Name ASC
-- We can use OFFSET and FETCH to return the
-- first 15 rows
SELECT productid, Name, ProductNumber, ListPrice
FROM Production.Product
ORDER BY Name ASC
OFFSET 0 ROWS FETCH NEXT 15 ROWS ONLY;
-- This query uses OFFSET and FETCH to skip the
-- first 15 rows and return the next 15 rows
SELECT productid, Name, ProductNumber, ListPrice
FROM Production.Product
ORDER BY Name ASC
OFFSET 15 ROWS FETCH NEXT 15 ROWS ONLY;
-- This query uses OFFSET and FETCH to skip the
-- first 30 rows and return the next 15 rows
SELECT productid, Name, ProductNumber, ListPrice
FROM Production.Product
ORDER BY Name ASC
OFFSET 30 ROWS FETCH NEXT 15 ROWS ONLY;
-- We need to create an alphabetized list of people for Christmas cards
CREATE TABLE Employees
(
EID int not null,
FirstName varchar(20) not null,
LastName varchar(25) not null,
StreetAddress varchar(50),
City varchar(20),
State char(2)
)
CREATE TABLE Customers
(
CID int not null,
FirstName varchar(20) not null,
LastName varchar(25) not null,
StreetAddress varchar(50),
City varchar(20),
State char(2)
)
INSERT INTO Employees
VALUES
('1','Jack','Harris','1423 Main Street', 'Jackson', 'TN'),
('2','Mark','James','432 Seashore Street', 'Nashville', 'TN'),
('3','Alice','Johnson','5235 Highway 495', 'Brentwood', 'TN'),
('4','Morgan','Denton','4634 Bluebird Lane', 'Dickson', 'TN'),
('5','Don','Carleson','62346 Williamsburg Court', 'Nolensville', 'TN')
INSERT INTO Customers
VALUES
('101','Jerry','Algood','333 Bullard Ave', 'Chicago', 'IL'),
('102','John','Williams','2523 First Avenue North', 'Atlanta', 'GA'),
('103','Kristin','Addison','26675 East Hwy 33', 'Dallas', 'TX'),
('104','Megan','Wilson','6786 3rd Ave', 'Memphis', 'TN'),
('105','Janet','Greene','99674 Jackson Square', 'Louisville', 'KY')
-- Here's the Employees
select * from employees
-- Here's the Customers
select * from customers
-- Here are the combined names from both result sets
-- Data types for columns in both queries must be similar !!!
select Firstname, Lastname, StreetAddress, City, State
from customers
UNION
select Firstname, Lastname, StreetAddress, City, State
from employees
order by Lastname, Firstname
\ No newline at end of file
-- Let's look at a simple JOIN example
-- We want each employee's first name, last name, and email address
-- We will get data from the FirstName and LastName
-- columns in the Person.Person table
select top 1 * from person.person
-- We will get data from the EmailAddress column
-- in the Person.EmailAddress table
select top 1 * from person.emailaddress
-- Here's the basic structure
select Person.FirstName, Person.LastName, EmailAddress.EmailAddress
from Person.Person
JOIN
Person.EmailAddress
ON
Person.BusinessEntityID = EmailAddress.BusinessEntityID
where LastName like 'b%'
order by LastName, FirstName
\ No newline at end of file
-- Let's take a look at the two tables we will be using
SELECT TOP 5 * from Production.Product -- There are 508 rows in this table
SELECT TOP 5 * from Production.ProductReview -- There are 4 rows in this table
-- This query will perform an INNER JOIN
SELECT p.Name, pr.ProductReviewID
FROM Production.Product p
JOIN Production.ProductReview pr
ON p.ProductID = pr.ProductID
-- This query will perform a LEFT JOIN
SELECT p.Name, pr.ProductReviewID
FROM Production.Product p
LEFT OUTER JOIN Production.ProductReview pr
ON p.ProductID = pr.ProductID
-- This query will perform a RIGHT JOIN
SELECT p.Name, pr.ProductReviewID
FROM Production.Product p
RIGHT OUTER JOIN Production.ProductReview pr
ON p.ProductID = pr.ProductID
SELECT p.Name, pr.ProductReviewID
FROM Production.Product p
CROSS JOIN Production.ProductReview pr
-- Table Aliasing
-- Here's the basic structure of a simple JOIN query
select Person.FirstName, Person.LastName, EmailAddress.EmailAddress
from Person.Person
JOIN
Person.EmailAddress
ON
Person.BusinessEntityID = EmailAddress.BusinessEntityID
where LastName like 'b%'
order by LastName, FirstName
-- Table aliasing can be used to reduce keystrokes
-- and make the query easier to read
select p.FirstName, p.LastName, e.EmailAddress
from Person.Person p
JOIN
Person.EmailAddress e
ON
p.BusinessEntityID = e.BusinessEntityID
where LastName like 'b%'
order by LastName, FirstName
\ No newline at end of file