├── DDL Create DB from ERD ├── .DS_Store ├── DDL Create Database from ERD.sql └── ERD.png ├── Functions and Triggers ├── .DS_Store └── Functions_and_triggers.sql ├── README.md ├── Recursive CTE ├── .DS_Store └── Recursive_CTE.sql ├── SQL Basic Queries ├── .DS_Store ├── basics.sql └── joins_and_aggregation.sql ├── SQL Rank, Case and Intersect ├── .DS_Store └── Rank_Case_Intersect_Window_Functions.sql └── Stringagg, For XML Path AdventureWorks ├── .DS_Store └── StringAgg_ForXML_CTE.sql /DDL Create DB from ERD/.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/shivaniNK8/SQL-Server-Adventure-Works/4810617eb72e2155053d9d61d8a7b2ad2e5593e8/DDL Create DB from ERD/.DS_Store -------------------------------------------------------------------------------- /DDL Create DB from ERD/DDL Create Database from ERD.sql: -------------------------------------------------------------------------------- 1 | 2 | USE db; 3 | --Part A 4 | 5 | CREATE TABLE dbo.Student( 6 | StudentID int IDENTITY NOT NULL PRIMARY KEY, 7 | LastName varchar(40) NOT NULL, 8 | FirstName varchar(40) NOT NULL, 9 | DateOfBirth date NOT NULL 10 | ); 11 | 12 | CREATE TABLE dbo.Term( 13 | TermID int IDENTITY NOT NULL PRIMARY KEY, 14 | Year date NOT NULL, 15 | Term varchar(10) NOT NULL 16 | ); 17 | 18 | CREATE TABLE dbo.Course( 19 | CourseID int IDENTITY NOT NULL PRIMARY KEY, 20 | Name varchar(40) NOT NULL, 21 | Description varchar(200) NOT NULL 22 | ); 23 | 24 | CREATE TABLE dbo.Enrollment( 25 | StudentID int NOT NULL 26 | REFERENCES Student(StudentID), 27 | CourseID int NOT NULL 28 | REFERENCES Course(CourseID), 29 | TermID int NOT NULL 30 | REFERENCES Term(TermID), 31 | CONSTRAINT PKEnrollment PRIMARY KEY CLUSTERED 32 | (StudentID, CourseID, TermID) 33 | ); 34 | 35 | -------------------------------------------------------------------------------- /DDL Create DB from ERD/ERD.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/shivaniNK8/SQL-Server-Adventure-Works/4810617eb72e2155053d9d61d8a7b2ad2e5593e8/DDL Create DB from ERD/ERD.png -------------------------------------------------------------------------------- /Functions and Triggers/.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/shivaniNK8/SQL-Server-Adventure-Works/4810617eb72e2155053d9d61d8a7b2ad2e5593e8/Functions and Triggers/.DS_Store -------------------------------------------------------------------------------- /Functions and Triggers/Functions_and_triggers.sql: -------------------------------------------------------------------------------- 1 | USE db; 2 | 3 | /* 5-1 4 | * 5 | * Create a function in your own database that takes three 6 | * parameters: 7 | * 1) A year parameter 8 | * 2) A month parameter 9 | * 3) A color parameter 10 | * The function then calculates and returns the total sales 11 | * for products in the requested color during the requested 12 | * year and month. If there was no sale for the requested period, 13 | * 14 | */ 15 | 16 | CREATE FUNCTION ColorSales( 17 | @year INT, 18 | @month INT, 19 | @color NVARCHAR(15) 20 | ) 21 | RETURNS NUMERIC(38,6) 22 | AS 23 | BEGIN 24 | DECLARE @sales NUMERIC(38,6); 25 | SELECT @sales = ROUND(SUM(sod.UnitPrice * sod.OrderQty), 2) 26 | FROM AdventureWorks2008R2.Sales.SalesOrderHeader soh 27 | JOIN AdventureWorks2008R2.Sales.SalesOrderDetail sod 28 | ON soh.SalesOrderID = sod.SalesOrderID 29 | JOIN AdventureWorks2008R2.Production.Product p 30 | ON sod.ProductID = p.ProductID 31 | WHERE p.Color = @color AND 32 | DATEPART(mm, CAST(OrderDate AS DATE)) = @month AND 33 | DATEPART(yy, CAST(OrderDate AS DATE)) = @year 34 | IF @sales IS NULL 35 | SET @sales = 0.0 36 | RETURN @sales 37 | END 38 | 39 | SELECT dbo.ColorSales(2005,8,'Red') AS TotalSales; 40 | 41 | 42 | /* 43 | * 5-2 44 | * Write a stored procedure in your own database that accepts two parameters: 45 | * 1) A starting date 46 | * 2) The number of the consecutive dates beginning with the starting date 47 | * The stored procedure then populates all columns of the 48 | * DateRange table according to the two provided parameters. 49 | * */ 50 | 51 | DROP TABLE DateRange; 52 | 53 | CREATE TABLE DateRange 54 | (DateID INT IDENTITY, 55 | DateValue DATE, 56 | Year INT, 57 | Quarter INT, 58 | Month INT, 59 | DayOfWeek INT); 60 | 61 | 62 | DROP PROCEDURE PopulateDateRange; 63 | 64 | 65 | CREATE PROCEDURE PopulateDateRange 66 | @StartDate DATE, 67 | @NumberOfDates INT 68 | AS 69 | BEGIN 70 | DECLARE @counter INT; 71 | SET @counter = 0; 72 | WHILE @counter <> @NumberOfDates 73 | BEGIN 74 | DECLARE @InsertDate DATE; 75 | SET @InsertDate = DATEADD(day, @counter, @StartDate) 76 | INSERT dbo.DateRange 77 | VALUES(@InsertDate, 78 | DATEPART(year, @InsertDate), 79 | DATEPART(quarter, @InsertDate), 80 | DATEPART(month, @InsertDate), 81 | DATEPART(dw, @InsertDate) 82 | ); 83 | SET @counter = @counter + 1; 84 | END 85 | END 86 | 87 | --DateRange Data before executing procedure 88 | SELECT * 89 | FROM dbo.DateRange; 90 | 91 | EXEC dbo.PopulateDateRange '2008-3-13', 10; 92 | 93 | --DateRange Data before executing procedure 94 | SELECT * 95 | FROM dbo.DateRange; 96 | 97 | 98 | /* 5-3 99 | * Using an AdventureWorks database, create a function that accepts 100 | * a customer id and returns the full name (last name + first name) 101 | * of the customer. 102 | * */ 103 | 104 | DROP FUNCTION GetFullName; 105 | 106 | CREATE FUNCTION GetFullName 107 | ( 108 | @CustomerID INT 109 | ) 110 | RETURNS NVARCHAR(100) 111 | AS 112 | BEGIN 113 | DECLARE @FullName NVARCHAR(100); 114 | SELECT @FullName = p.LastName + ' ' +p.FirstName 115 | FROM AdventureWorks2008R2.Sales.Customer c 116 | JOIN AdventureWorks2008R2.Person.Person p 117 | ON c.PersonID = p.BusinessEntityID 118 | WHERE c.CustomerID = @CustomerID 119 | 120 | RETURN @FullName 121 | END 122 | 123 | SELECT dbo.GetFullName(29487) AS FullName; 124 | 125 | /* 126 | * 5-4 127 | * Write a trigger to put the change date and time in the LastModified column 128 | * of the Order table whenever an order item in SaleOrderDetail is changed. 129 | */ 130 | 131 | -- Create the required tables in database 132 | 133 | CREATE TABLE Customer 134 | (CustomerID INT PRIMARY KEY, 135 | CustomerLName VARCHAR(30), 136 | CustomerFName VARCHAR(30)); 137 | 138 | CREATE TABLE SaleOrder 139 | (OrderID INT IDENTITY PRIMARY KEY, 140 | CustomerID INT REFERENCES Customer(CustomerID), 141 | OrderDate DATE, 142 | LastModified datetime); 143 | 144 | CREATE TABLE SaleOrderDetail 145 | (OrderID INT REFERENCES SaleOrder(OrderID), 146 | ProductID INT, 147 | Quantity INT, 148 | UnitPrice INT, 149 | PRIMARY KEY (OrderID, ProductID)); 150 | 151 | 152 | /*Trigger if LastModified of SaleOrder table has to be updated when 153 | * an item is added, deleted or updated in the SaleOrderDetail table. 154 | * ie. All update, delete, insert commands are issued on 155 | * SaleOrderDetail Table 156 | */ 157 | 158 | DROP TRIGGER dbo.ItemChangeTimestampAll 159 | 160 | CREATE TRIGGER dbo.ItemChangeTimestampAll 161 | ON dbo.SaleOrderDetail 162 | AFTER INSERT, UPDATE, DELETE 163 | AS 164 | BEGIN 165 | DECLARE @ChangedOrderID INT; 166 | 167 | SELECT @ChangedOrderID = COALESCE (i.OrderID, d.OrderID) 168 | FROM inserted i 169 | FULL JOIN deleted d 170 | ON i.OrderID = d.OrderID; 171 | 172 | UPDATE dbo.SaleOrder 173 | SET LastModified = CURRENT_TIMESTAMP 174 | WHERE dbo.SaleOrder.OrderID = @ChangedOrderID; 175 | END 176 | 177 | /*Trigger if LastModified of SaleOrder table has to be updated only when 178 | * an item is updated in the SaleOrderDetail table. 179 | * ie. if Update command is issued on 180 | * SaleOrderDetail Table 181 | */ 182 | 183 | DROP TRIGGER dbo.ItemChangeTimestamp; 184 | 185 | CREATE TRIGGER dbo.ItemChangeTimestamp 186 | ON dbo.SaleOrderDetail 187 | AFTER UPDATE 188 | AS 189 | BEGIN 190 | UPDATE dbo.SaleOrder 191 | SET LastModified = CURRENT_TIMESTAMP 192 | WHERE dbo.SaleOrder.OrderID = (SELECT OrderID 193 | FROM inserted i) 194 | END 195 | 196 | /* 197 | * Checking trigger functionality with scenarios -------------------------------- 198 | */ 199 | 200 | --Create dummy data to check trigger working 201 | INSERT INTO dbo.Customer 202 | VALUES(1, 'Naik', 'Shivani'); 203 | INSERT INTO dbo.SaleOrder 204 | VALUES( 1, GETDATE(), CURRENT_TIMESTAMP); 205 | INSERT INTO dbo.SaleOrderDetail 206 | VALUES(3, 2, 20, 30); 207 | INSERT INTO dbo.SaleOrderDetail 208 | VALUES(3, 5, 7, 50); 209 | 210 | -- Check initial data in SaleOrder and SaleOrderDetail tables 211 | SELECT * 212 | FROM dbo.SaleOrder so ; 213 | 214 | SELECT * 215 | FROM dbo.SaleOrderDetail sod ; 216 | 217 | -- Check if trigger works on update of an item for SalerOrderDetail with OrderID = 3 and ProductID = 2 218 | UPDATE dbo.SaleOrderDetail 219 | SET UnitPrice = 40 220 | WHERE OrderID = 3 AND ProductID = 2; 221 | 222 | SELECT * 223 | FROM dbo.SaleOrder so 224 | 225 | -- Check if trigger works on insert a new item for a saleorderdetail with OrderID = 4 and ProductID = 2 226 | INSERT INTO dbo.SaleOrderDetail 227 | VALUES(4, 2, 20, 30); 228 | 229 | SELECT * 230 | FROM dbo.SaleOrder so 231 | 232 | -- Check if trigger works on deleting an item for a saleorderdetail with OrderID = 4 and ProductID = 2 233 | DELETE 234 | FROM dbo.SaleOrderDetail 235 | WHERE OrderID = 4 AND ProductID = 2; 236 | 237 | SELECT * 238 | FROM dbo.SaleOrder so 239 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQL-Adventure-Works 2 | Basic to Complex SQL Server queries with Adventure Works database 3 | -------------------------------------------------------------------------------- /Recursive CTE/.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/shivaniNK8/SQL-Server-Adventure-Works/4810617eb72e2155053d9d61d8a7b2ad2e5593e8/Recursive CTE/.DS_Store -------------------------------------------------------------------------------- /Recursive CTE/Recursive_CTE.sql: -------------------------------------------------------------------------------- 1 | 2 | USE AdventureWorks2008R2; 3 | 4 | /* Bill of Materials - Recursive */ 5 | /* Retrieves the components required for manufacturing 6 | the "Mountain-500 Black, 48" (Product 992). Retrieve the most expensive component(s) that cannot be manufactured internally. 7 | Use the list price of a component to determine the most expensive 8 | component. 9 | If there is a tie, your solutions must retrieve it. */ 10 | 11 | 12 | /* 13 | * Use Rank to find most expensive components that cannot be assembled for product 992 14 | */ 15 | --Check components from any component level that cannot be assembled 16 | WITH Parts(AssemblyID, ComponentID, PerAssemblyQty, EndDate, ComponentLevel) AS 17 | ( 18 | SELECT b.ProductAssemblyID , b.ComponentID, b.PerAssemblyQty , 19 | b.EndDate, 0 AS ComponentLevel 20 | FROM Production.BillOfMaterials b 21 | WHERE b.ProductAssemblyID = 992 AND EndDate IS NULL 22 | 23 | UNION ALL 24 | 25 | SELECT bom.ProductAssemblyID , bom.ComponentID, bom.PerAssemblyQty , 26 | bom.EndDate, ComponentLevel + 1 27 | FROM Production.BillOfMaterials bom 28 | INNER JOIN Parts p 29 | ON bom.ProductAssemblyID = p.ComponentID AND bom.EndDate IS NULL 30 | ), 31 | BOM AS 32 | ( 33 | SELECT AssemblyID, ComponentID, Name, ListPrice, PerAssemblyQty, 34 | ListPrice * PerAssemblyQty AS SubTotal, 35 | ComponentLevel, 36 | RANK() OVER(ORDER BY ListPrice DESC) [Rank] 37 | FROM Parts p 38 | INNER JOIN Production.Product pr 39 | ON p.ComponentID = pr.ProductID 40 | WHERE ComponentID NOT IN 41 | ( SELECT DISTINCT AssemblyID FROM Parts 42 | ) 43 | ) 44 | SELECT ComponentID , Name, ListPrice, PerAssemblyQty, SubTotal 45 | FROM BOM 46 | WHERE [Rank] = 1 47 | ORDER BY ComponentLevel, AssemblyID, ComponentID 48 | 49 | -- If we want to check for components from ComponentLevel 0 that cannot be assembled 50 | WITH Parts(AssemblyID, ComponentID, PerAssemblyQty, EndDate, ComponentLevel) AS 51 | ( 52 | SELECT b.ProductAssemblyID , b.ComponentID, b.PerAssemblyQty , 53 | b.EndDate, 0 AS ComponentLevel 54 | FROM Production.BillOfMaterials b 55 | WHERE b.ProductAssemblyID = 992 AND EndDate IS NULL 56 | 57 | UNION ALL 58 | 59 | SELECT bom.ProductAssemblyID , bom.ComponentID, bom.PerAssemblyQty , 60 | bom.EndDate, ComponentLevel + 1 61 | FROM Production.BillOfMaterials bom 62 | INNER JOIN Parts p 63 | ON bom.ProductAssemblyID = p.ComponentID AND bom.EndDate IS NULL 64 | ), 65 | BOM AS 66 | ( 67 | SELECT AssemblyID, ComponentID, Name, ListPrice, PerAssemblyQty, 68 | ListPrice * PerAssemblyQty AS SubTotal, 69 | ComponentLevel, 70 | RANK() OVER(ORDER BY ListPrice DESC) [Rank] 71 | FROM Parts p 72 | INNER JOIN Production.Product pr 73 | ON p.ComponentID = pr.ProductID 74 | WHERE ComponentLevel = 0 75 | AND ComponentID NOT IN 76 | ( SELECT DISTINCT AssemblyID FROM Parts 77 | WHERE ComponentLevel > 0 78 | ) 79 | ) 80 | SELECT ComponentID , Name, ListPrice, PerAssemblyQty, SubTotal 81 | FROM BOM 82 | WHERE [Rank] = 1 83 | ORDER BY ComponentLevel, AssemblyID, ComponentID 84 | -------------------------------------------------------------------------------- /SQL Basic Queries/.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/shivaniNK8/SQL-Server-Adventure-Works/4810617eb72e2155053d9d61d8a7b2ad2e5593e8/SQL Basic Queries/.DS_Store -------------------------------------------------------------------------------- /SQL Basic Queries/basics.sql: -------------------------------------------------------------------------------- 1 | USE AdventureWorks2008R2; 2 | 3 | -- Exercise 1 4 | /* Retrieve only the following columns from the 5 | Production.Product table: 6 | Product ID 7 | Name 8 | Selling start date 9 | Selling end date 10 | Size 11 | Weight */ 12 | 13 | SELECT ProductID , SellStartDate , SellEndDate , [Size] ,Weight 14 | FROM Production.Product p 15 | 16 | -- Exercise 2 17 | /* Select all info for all orders with no credit card id. */ 18 | SELECT * 19 | FROM Sales.SalesOrderHeader soh 20 | WHERE CreditCardID IS NULL 21 | 22 | -- Exercise 3 23 | /* Select all info for all products with size specified. */ 24 | SELECT * 25 | FROM Production.Product p 26 | WHERE [Size] IS NOT NULL 27 | 28 | -- Exercise 4 29 | /* Select all information for products that started selling 30 | between January 1, 2007 and December 31, 2007. */ 31 | 32 | SELECT * 33 | FROM Production.Product p 34 | WHERE SellStartDate BETWEEN '2007-01-01' AND '2007-12-31' 35 | 36 | -- Exercise 5 37 | /* Select all info for all orders placed in June 2007 using date 38 | functions, and include a column for an estimated delivery date 39 | that is 7 days after the order date. */ 40 | 41 | -- DATEADD adds interval specified to the date 42 | SELECT *, 43 | DATEADD(Day,7,OrderDate) Estimated_Delivery 44 | FROM Sales.SalesOrderHeader soh 45 | WHERE MONTH(OrderDate) = 6 AND YEAR(OrderDate) =2007 46 | 47 | -- Exercise 6 48 | /* Determine the date that is 30 days from today and display only 49 | the date in mm/dd/yyyy format (4-digit year). */ 50 | 51 | -- Convert can be used to convert datetime to a format from a list 52 | -- of formats 53 | 54 | SELECT CONVERT(varchar, DATEADD(Day, 30, GETDATE()), 101) 55 | SELECT CAST(DATEADD(Day, 30, GETDATE()) AS DATE) 56 | 57 | -- Excercise 7 58 | /* Determine the number of orders, overall total due, 59 | average of total due, amount of the smallest amount due, and 60 | amount of the largest amount due for all orders placed in May 61 | 2008. Make sure all columns have a descriptive heading. */ 62 | 63 | SELECT COUNT(SalesOrderID) '# of orders', 64 | SUM(TotalDue) 'Overall Total due', 65 | AVG(TotalDue) 'Avergae Total due', 66 | MIN(TotalDue) 'Smallest due', 67 | MAX(TotalDue) 'Largest due' 68 | FROM Sales.SalesOrderHeader r 69 | WHERE MONTH(OrderDate) = 5 AND YEAR(OrderDate) =2008 70 | 71 | -- Excercise 8 72 | 73 | /* Retrieve the Customer ID, total number of orders and overall total 74 | due for the customers who placed more than one order in 2007 75 | and sort the result by the overall total due in the descending 76 | order. */ 77 | SELECT CustomerID , 78 | COUNT(SalesOrderID) as '# of orders', 79 | SUM(TotalDue) 'Overall Total due' 80 | FROM Sales.SalesOrderHeader R 81 | WHERE DATEPART(YEAR, OrderDate)=2007 82 | GROUP BY CustomerID 83 | HAVING COUNT(SalesOrderID) > 1 84 | ORDER BY 'Overall Total due' DESC 85 | 86 | -- Exercise 9 87 | /* 88 | Provide a unique list of the sales person ids who have sold 89 | the product id 777. Sort the list by the sales person id. */ 90 | 91 | SELECT DISTINCT soh.SalesPersonID 92 | FROM Sales.SalesOrderHeader soh JOIN 93 | Sales.SalesOrderDetail sod 94 | ON soh.SalesOrderID = sod.SalesOrderID 95 | WHERE sod.ProductID = 777 96 | ORDER BY soh.SalesPersonID 97 | 98 | -- Exercise 10 99 | /* List the product ID, name, list price, size of products Under the ‘Bikes’ category (ProductCategoryID = 1) and Subcategory ‘Mountain Bikes’. */ 100 | 101 | 102 | SELECT p.ProductID ,p.Name, ListPrice ,[Size] 103 | FROM Production.Product p JOIN 104 | Production.ProductSubcategory ps 105 | ON p.ProductSubcategoryID = ps.ProductSubcategoryID 106 | WHERE ps.ProductCategoryID = 1 AND 107 | ps.Name = 'Mountain Bikes' 108 | 109 | -- Excercise 11 110 | /* List the SalesOrderID and currency name for each order. */ 111 | SELECT soh.SalesOrderID , cr.ToCurrencyCode , c.Name 112 | FROM Sales.SalesOrderHeader soh JOIN 113 | Sales.CurrencyRate cr 114 | ON soh.CurrencyRateID = cr.CurrencyRateID 115 | JOIN Sales.Currency c 116 | ON cr.ToCurrencyCode = c.CurrencyCode 117 | -------------------------------------------------------------------------------- /SQL Basic Queries/joins_and_aggregation.sql: -------------------------------------------------------------------------------- 1 | 2 | USE AdventureWorks2008R2 3 | 4 | 5 | /* 2-1 ----------------------------------------------------------------- 6 | * Retrieve all orders made after May 5, 2008 7 | * and had an total due value greater than $55,000. Include 8 | * the customer id, sales order id, order date and total due columns 9 | * in the returned data, order by customerid and orderdate 10 | */ 11 | SELECT CustomerID , 12 | SalesOrderID , 13 | CAST(OrderDate as DATE) OrderDate, 14 | ROUND(TotalDue, 2) TotalDue 15 | FROM Sales.SalesOrderHeader soh 16 | WHERE OrderDate > '2008-05-05' AND TotalDue >55000 17 | ORDER BY CustomerID , OrderDate 18 | 19 | 20 | 21 | /* 2-2 ----------------------------------------------------------------- 22 | * Latest order date, average order value, and total number 23 | * of orders for each customer. Include the customer ID, latest 24 | * order date, average order value, and the total number of orders 25 | * in the report. Order by total number of orders 26 | */ 27 | 28 | 29 | /* 30 | We use left outer join because there are 701 customers in Customer table 31 | that do not have orders in SalesOrderHeader and we want data for each customer. 32 | The values in report for these customers will be NULL 33 | */ 34 | SELECT c.CustomerID , 35 | MAX(CAST(OrderDate as DATE)) LatestOrderDate, 36 | ROUND(AVG(TotalDue), 2) [AverageOrderValue], 37 | COUNT(SalesOrderID) 'TotalNumberOfOrders' 38 | FROM Sales.Customer c 39 | LEFT OUTER JOIN Sales.SalesOrderHeader soh 40 | ON c.CustomerID = soh .CustomerID 41 | GROUP BY c.CustomerID 42 | ORDER BY TotalNumberOfOrders DESC 43 | 44 | 45 | 46 | /* 2-3 ----------------------------------------------------------------- 47 | * Select the product id, name, and list price 48 | * of the product(s) that have a list price greater than the 49 | * the average list price of the products 911 and 915 50 | */ 51 | SELECT ProductID, 52 | Name, 53 | ROUND(ListPrice, 2) ListPrice 54 | FROM Production.Product p2 55 | WHERE ListPrice > 56 | (SELECT AVG(ListPrice) AvgPrice 57 | FROM Production.Product p 58 | WHERE p.ProductID IN (911, 915)) 59 | ORDER BY ListPrice DESC 60 | 61 | 62 | 63 | /* 2-4 ----------------------------------------------------------------- 64 | * Retrieve the number of times a product has 65 | * been sold and the total sold quantity for each product. 66 | * Note it's the number of times a product has been contained 67 | * in an order and the total sold quantity of the product. Order 68 | * by Number of times sold descending and productid ascending 69 | */ 70 | 71 | SELECT p.ProductID, 72 | p.Name, 73 | COUNT(sod.SalesOrderID) 'NumTimesSold', 74 | SUM(sod.OrderQty) 'TotalSoldQuantity' 75 | FROM Sales.SalesOrderDetail sod 76 | JOIN Production.Product p 77 | ON p.ProductID = sod.ProductID 78 | GROUP BY p.ProductID, p.Name 79 | HAVING COUNT(sod.SalesOrderID) > 255 80 | ORDER BY 81 | 'NumTimesSold' DESC, 82 | p.ProductID ASC 83 | 84 | 85 | 86 | /* 2-5 ----------------------------------------------------------------- 87 | * Generate a unique list of customers 88 | * who have made an order before but have not placed an order 89 | * after January 5, 2007. 90 | * Include the customer id, and the total purchase of the customer 91 | * in the returned data. Use TotalDue to calculate the total purchase. 92 | * Use an alias and round numbers to two decimal places to make the 93 | * report look better. Sort the data by CustomerID in the descending 94 | * order. 95 | */ 96 | 97 | SELECT DISTINCT CustomerID, 98 | ROUND(SUM(TotalDue), 2) [TotalPurchase] 99 | FROM Sales.SalesOrderHeader soh2 100 | WHERE CustomerID NOT IN 101 | (SELECT DISTINCT CustomerID 102 | FROM Sales.SalesOrderHeader soh 103 | WHERE OrderDate > '2007-01-05') 104 | GROUP BY CustomerID 105 | ORDER BY CustomerID DESC 106 | 107 | 108 | 109 | /* 2-6 ----------------------------------------------------------------- 110 | * Create a report containing customer id, 111 | * first name, last name, and email address for all customers. 112 | * Return only customers who have a customer id greater than 11000. 113 | */ 114 | 115 | SELECT CustomerID, 116 | FirstName, 117 | LastName, 118 | ea.EmailAddress 119 | FROM Sales.Customer c 120 | LEFT OUTER JOIN Person.Person p 121 | ON p.BusinessEntityID = c.PersonID 122 | LEFT OUTER JOIN Person.EmailAddress ea 123 | ON p.BusinessEntityID = ea.BusinessEntityID 124 | WHERE CustomerID > 11000 125 | ORDER BY CustomerID ASC 126 | 127 | -------------------------------------------------------------------------------- /SQL Rank, Case and Intersect/.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/shivaniNK8/SQL-Server-Adventure-Works/4810617eb72e2155053d9d61d8a7b2ad2e5593e8/SQL Rank, Case and Intersect/.DS_Store -------------------------------------------------------------------------------- /SQL Rank, Case and Intersect/Rank_Case_Intersect_Window_Functions.sql: -------------------------------------------------------------------------------- 1 | 2 | 3 | USE AdventureWorks2008R2; 4 | 5 | /* 3.1 -------------------------------------------------------------------- 6 | * Generate following 7 | * 'No Order' for count = 0 8 | * 'One Time' for count = 1 9 | * 'Regular' for count range of 2-5 10 | * 'Often' for count range of 6-10 11 | * 'Loyal' for count greater than 10 12 | */ 13 | 14 | SELECT c.CustomerID, 15 | c.TerritoryID, 16 | COUNT(o.SalesOrderid) [Total Orders], 17 | CASE 18 | WHEN COUNT(o.SalesOrderid) = 0 19 | THEN 'No Order' 20 | WHEN COUNT(o.SalesOrderid) = 1 21 | THEN 'One Time' 22 | WHEN COUNT(o.SalesOrderid) BETWEEN 2 AND 5 23 | THEN 'Regular' 24 | WHEN COUNT(o.SalesOrderid) BETWEEN 6 AND 10 25 | THEN 'Often' 26 | WHEN COUNT(o.SalesOrderid) > 10 27 | THEN 'Loyal' 28 | END AS CustomerFrequency 29 | FROM Sales.Customer c 30 | LEFT OUTER JOIN Sales.SalesOrderHeader o 31 | ON c.CustomerID = o.CustomerID 32 | WHERE DATEPART(year, OrderDate) = 2007 33 | GROUP BY c.TerritoryID, c.CustomerID 34 | 35 | 36 | /* 3.2 -------------------------------------------------------------------- 37 | * Modify the following query to add a rank without gaps in the 38 | * ranking based on total orders in the descending order. Also 39 | * partition by territory 40 | */ 41 | 42 | SELECT c.CustomerID, 43 | c.TerritoryID, 44 | COUNT(o.SalesOrderid) [Total Orders], 45 | DENSE_RANK() OVER (PARTITION BY c.TerritoryID ORDER BY COUNT(o.SalesOrderid) DESC) [Rank] 46 | FROM Sales.Customer c 47 | LEFT OUTER JOIN Sales.SalesOrderHeader o 48 | ON c.CustomerID = o.CustomerID 49 | WHERE DATEPART(year, OrderDate) = 2007 50 | GROUP BY c.TerritoryID, c.CustomerID 51 | 52 | 53 | /* 3.3 -------------------------------------------------------------------- 54 | * Write a query that returns the salesperson(s) who received the 55 | * highest bonus amount and calculate the highest bonus amount’s 56 | * percentage of the total bonus amount for salespeople. Your 57 | * solution must be able to retrieve all salespersons who received 58 | * the highest bonus amount if there is a tie. 59 | * Include the salesperson’s last name and first name, highest 60 | * bonus amount, percentage in the report. 61 | */ 62 | WITH [Temp] AS 63 | (SELECT p.LastName, 64 | p.FirstName, 65 | Bonus, 66 | ROUND(Bonus * 100 / (SELECT SUM(Bonus) FROM Sales.SalesPerson), 2) BonusPercentage, -- try cast as decimal 67 | RANK() OVER (ORDER BY Bonus DESC) [Rank] 68 | FROM Sales.SalesPerson sp 69 | JOIN Person.Person p 70 | ON sp.BusinessEntityID = p.BusinessEntityID ) 71 | SELECT LastName, 72 | FirstName, 73 | Bonus AS HighestBonus, 74 | BonusPercentage AS HighestBonusPercentage 75 | FROM [Temp] 76 | WHERE [Rank] = 1 77 | 78 | 79 | /* Write a query to retrieve the most valuable salesperson of each month 80 | * in 2007. The most valuable salesperson is the salesperson who has 81 | * made most sales for AdventureWorks in the month. Use the monthly sum 82 | * of the TotalDue column of SalesOrderHeader as the monthly total sales 83 | * for each salesperson. If there is a tie for the most valuable salesperson, 84 | * your solution should retrieve it. Exclude the orders which didn't have 85 | * a salesperson specified. 86 | * */ 87 | 88 | WITH Temp AS( 89 | SELECT SalesPersonID, 90 | MONTH(OrderDate) [Month], 91 | ROUND(SUM(TotalDue), 2) MonthlySum, 92 | RANK() OVER (PARTITION BY MONTH(OrderDate) ORDER BY SUM(TotalDue) DESC) Ranking 93 | FROM Sales.SalesOrderHeader soh 94 | WHERE SalesPersonID IS NOT NULL AND 95 | YEAR(OrderDate) = 2007 96 | GROUP BY SalesPersonID, MONTH(OrderDate) ) 97 | SELECT t.[Month], 98 | t.SalesPersonID, 99 | sp.Bonus , 100 | t.MonthlySum 101 | FROM Temp t 102 | JOIN Sales.SalesPerson sp 103 | ON sp.BusinessEntityID = SalesPersonID 104 | WHERE t.Ranking = 1 105 | ORDER BY Month 106 | 107 | --Verify 108 | SELECT SUM(TotalDue ) 109 | FROM Sales.SalesOrderHeader soh 110 | WHERE SalesPersonID = 277 111 | AND MONTH(OrderDate) = 1 AND YEAR(OrderDate) = 2007 112 | 113 | SELECT SalesPersonID , ROUND(SUM(TotalDue), 2) 114 | FROM Sales.SalesOrderHeader soh 115 | WHERE MONTH(OrderDate) = 3 AND YEAR(OrderDate) = 2007 116 | GROUP BY SalesPersonID 117 | HAVING ROUND(SUM(TotalDue), 2) > 366536.9400 118 | 119 | /* 3.5 120 | * Provide a unique list of customer id’s which have ordered 121 | * both the red and yellow products after May 1, 2008. 122 | * Sort the list by customer id. */ 123 | 124 | SELECT DISTINCT CustomerID 125 | FROM Sales.SalesOrderHeader soh 126 | JOIN Sales.SalesOrderDetail sod 127 | ON soh.SalesOrderID = sod.SalesOrderID 128 | JOIN Production.Product p 129 | ON sod.ProductID = p.ProductID 130 | WHERE p.Color = 'Yellow' AND 131 | soh.OrderDate > '2008-05-01' 132 | INTERSECT 133 | SELECT DISTINCT CustomerID 134 | FROM Sales.SalesOrderHeader soh 135 | JOIN Sales.SalesOrderDetail sod 136 | ON soh.SalesOrderID = sod.SalesOrderID 137 | JOIN Production.Product p 138 | ON sod.ProductID = p.ProductID 139 | WHERE p.Color = 'Red' AND 140 | soh.OrderDate > '2008-05-01' 141 | ORDER BY CustomerID 142 | 143 | -------------------------------------------------------------------------------- /Stringagg, For XML Path AdventureWorks/.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/shivaniNK8/SQL-Server-Adventure-Works/4810617eb72e2155053d9d61d8a7b2ad2e5593e8/Stringagg, For XML Path AdventureWorks/.DS_Store -------------------------------------------------------------------------------- /Stringagg, For XML Path AdventureWorks/StringAgg_ForXML_CTE.sql: -------------------------------------------------------------------------------- 1 | 2 | USE AdventureWorks2008R2; 3 | /* 4 | * Write a query to retrieve the top 3 customers, based on the total purchase, for each year. 5 | * The top 3 customers have the 3 highest total purchase amounts. 6 | * Use TotalDue of SalesOrderHeader to calculate the total purchase. 7 | * Also calculate the top 3 customers' total purchase amount for the year. 8 | */ 9 | 10 | 11 | --Using String_agg function 12 | WITH Temp AS 13 | ( 14 | SELECT YEAR(OrderDate) as [Year], 15 | SUM(TotalDue) [Total Sale], 16 | CustomerID , 17 | RANK() OVER (PARTITION BY YEAR(OrderDate) ORDER BY SUM(TotalDue) DESC) [Rank] 18 | FROM Sales.SalesOrderHeader soh 19 | GROUP BY YEAR(OrderDate), CustomerID 20 | ) 21 | SELECT Temp.[Year], 22 | ROUND(SUM([Total Sale]),0) AS [Total Sale], 23 | STRING_AGG(CAST(Temp.CustomerID AS VARCHAR), 24 | ', ') AS Top3Customers 25 | FROM Temp 26 | WHERE [Rank] <=3 27 | GROUP BY Temp.[Year] 28 | ORDER BY Temp.[Year] 29 | 30 | -- Solution using For XML Path 31 | WITH Temp AS ( 32 | SELECT YEAR(OrderDate) as [Year], 33 | SUM(TotalDue) [Total Sale], 34 | CustomerID , 35 | RANK() OVER (PARTITION BY YEAR(OrderDate) ORDER BY SUM(TotalDue) DESC) [Rank] 36 | FROM Sales.SalesOrderHeader soh 37 | GROUP BY YEAR(OrderDate), CustomerID ), 38 | Y AS ( 39 | SELECT DISTINCT YEAR(OrderDate) [Year] 40 | FROM Sales.SalesOrderHeader soh2 ), 41 | Z AS ( 42 | SELECT Y.[Year], 43 | SUM(Temp.[Total Sale]) [Total Sale] 44 | FROM Temp 45 | JOIN Y 46 | ON Y.[Year] = Temp.[Year] 47 | WHERE Temp.[Rank] <= 3 48 | GROUP BY Y.[Year] 49 | ) 50 | SELECT Y.[Year] [Year], 51 | ROUND(Z.[Total Sale], 0) [Total Sale], 52 | STUFF((SELECT ', '+CAST(CustomerID AS VARCHAR) 53 | FROM Temp 54 | WHERE Rank <=3 55 | AND Temp.[Year] = Y.[Year] 56 | ORDER BY Temp.[Total Sale] DESC 57 | FOR XML PATH('')),1,2,'') AS Top3Customers 58 | FROM Y 59 | JOIN Z 60 | ON Y.[Year] = Z.[Year] 61 | ORDER BY Y.[Year] 62 | --------------------------------------------------------------------------------