├── Interpolations ├── Next or Previous Non-Null Value - Solution 1.sql ├── Next or Previous Non-Null Value - Solution 2.sql ├── Phase 1 - Original Data.sql ├── Phase 2 - Auxiliary Data.sql ├── Phase 3 - Source Sets.sql ├── Phase 4 - Linear Interpolation - Add Last and Next Non Null Values.sql ├── Phase 4 - Proximal Interpolation - Add Last and Next Non Null Values.sql ├── Phase 5 - Linear Interpolation - Final Solution.sql ├── Phase 5 - Proximal Interpolation - Final Solution.sql ├── Readme.txt └── Review Demo.sql ├── Mastering-Basics ├── 04 - Development Environment.txt ├── 06 - DQL - DML.sql ├── 09 - FROM and JOINS.sql ├── 10 - WHERE.sql ├── 11 - GROUP BY.sql ├── 12 - ORDER BY.sql ├── 13 - Subqueries.sql ├── 14 - Set Operators.sql ├── DemoDB_SQLite3.db ├── DemoDB_Script.sql ├── Readme.txt └── Relational_SQL_MasterPPT.pdf ├── PostgreSQL Fundamentals ├── Basic Demo Database.sql ├── Module 1-1.sql ├── Module 1-2.sql ├── Module 1-3.sql ├── Module 2-1.sql ├── Module 2-2.sql ├── Module 2-3.sql ├── Module 3-1.sql ├── Module 3-2.sql ├── Module 3-3.sql ├── Module 3-4.sql ├── Module 4-1.sql ├── Module 4-2.sql ├── Module 4-3.sql ├── PostgreSQL Fundamentals.pdf └── ReadMe.txt ├── README.md ├── Relational-Division ├── 1_Create_HR_Demo_Database.sql ├── 2_Relational_Division_Using_Set_Operators.sql ├── 3_Relational_Division_Using_COUNT.sql ├── 5_Relational_Division_Using_Nested_NOT_EXISTS.sql ├── 6_Advanced_Relational_Division.sql └── Readme.txt ├── SQL Server Fundamentals ├── Basic Demo Database.sql ├── Module 1-1.sql ├── Module 1-2.sql ├── Module 1-3.sql ├── Module 2-1.sql ├── Module 2-2.sql ├── Module 2-3.sql ├── Module 3-1.sql ├── Module 3-2.sql ├── Module 3-3.sql ├── Module 3-4.sql ├── Module 4-1.sql ├── Module 4-2.sql ├── Module 4-3.sql ├── Read Me.txt └── SQL Server Fundamentals.pdf └── Window Functions ├── Aggregate.sql ├── Analytic.sql ├── DemoDB_Script.sql ├── Exercise 1 - Windows and Frames.sql ├── Exercise 2 - Ranking.sql ├── Exercise 3 - Offset.sql ├── Offset.sql ├── Processing Order.sql ├── ROWS-RANGE.sql ├── Ranking.sql ├── Readme.txt └── Window and Frame.sql /Interpolations/Next or Previous Non-Null Value - Solution 1.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------- 2 | -- O'Reilly Online Training ------------ 3 | -- Advanced SQL Series ----------------- 4 | -- Linear and Proximal Interpolations -- 5 | ---------------------------------------- 6 | -- Next / Previous Non-Null Value -- 7 | -- Solution 1 Using CASE ----------- 8 | ------------------------------------ 9 | 10 | USE [tempdb]; 11 | GO 12 | 13 | CREATE TABLE [Example1] 14 | ( 15 | [ID] INT IDENTITY NOT NULL PRIMARY KEY, 16 | [Value] INT NULL 17 | ); 18 | 19 | INSERT INTO [Example1] ( [Value] ) 20 | VALUES (10), (8), (NULL), (NULL), (7), (NULL), (2), (4), (NULL), (0); 21 | 22 | SELECT * 23 | FROM [Example1]; 24 | GO 25 | 26 | WITH [CTE] 27 | AS 28 | ( 29 | SELECT *, 30 | MAX ([NotNullID]) 31 | OVER ( 32 | ORDER BY [ID] 33 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW 34 | ) AS [LastNotNullID] 35 | FROM [Example1] 36 | CROSS APPLY (VALUES ( 37 | CASE 38 | WHEN [Value] IS NOT NULL 39 | THEN [ID] 40 | ELSE NULL 41 | END 42 | ) 43 | ) AS [NotNullIDs] ([NotNullID]) 44 | ) 45 | SELECT [ID], 46 | [Value], 47 | MAX([Value]) 48 | OVER ( 49 | PARTITION BY [LastNotNullID] 50 | ) AS [LastNotNullValue] 51 | FROM [CTE] 52 | ORDER BY [ID]; 53 | GO 54 | 55 | -- Inline NotNullID 56 | 57 | WITH [CTE] 58 | AS 59 | ( 60 | SELECT *, 61 | MAX (CASE 62 | WHEN [Value] IS NOT NULL THEN [ID] ELSE NULL 63 | END 64 | ) 65 | OVER ( 66 | ORDER BY [ID] 67 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW 68 | ) AS [LastNotNullID] 69 | FROM [Example1] 70 | ) 71 | SELECT [ID], 72 | [Value], 73 | MAX([Value]) 74 | OVER ( 75 | PARTITION BY [LastNotNullID] 76 | ) AS [LastNotNullValue] 77 | FROM [CTE] 78 | ORDER BY [ID]; 79 | GO 80 | -------------------------------------------------------------------------------- /Interpolations/Next or Previous Non-Null Value - Solution 2.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------- 2 | -- O'Reilly Online Training ------------ 3 | -- Advanced SQL Series ----------------- 4 | -- Linear and Proximal Interpolations -- 5 | ---------------------------------------- 6 | -- Next / Previous Non-Null Value -- 7 | -- Solution 2 Using COUNT ---------- 8 | ------------------------------------ 9 | 10 | USE [tempdb]; 11 | GO 12 | 13 | -- DROP TABLE IF EXISTS [Example2]; -- SQL 2016 14 | -- GO 15 | 16 | CREATE TABLE [Example2] 17 | ( 18 | [ID] INT IDENTITY NOT NULL PRIMARY KEY, 19 | [Value] INT NULL 20 | ); 21 | 22 | INSERT INTO [Example2] 23 | ( [Value] ) 24 | VALUES (10), (8), (NULL), (NULL), (7), (NULL), (2), (4), (NULL), (0); 25 | 26 | SELECT * 27 | FROM [Example2]; 28 | GO 29 | 30 | ;WITH 31 | [Value_Counts] 32 | AS ( 33 | SELECT * , 34 | COUNT([Value]) 35 | OVER ( 36 | ORDER BY [ID] ASC 37 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW 38 | ) AS [Count_Backwards] 39 | FROM [Example2] 40 | ) 41 | --SELECT * FROM Value_Counts ORDER BY ID 42 | SELECT * , 43 | MAX([Value]) 44 | OVER (PARTITION BY [Count_Backwards]) AS [Last_Non_Null_Value] 45 | FROM [Value_Counts] 46 | ORDER BY ID; 47 | 48 | -- With next non null as well 49 | 50 | ;WITH 51 | [Value_Counts] 52 | AS ( 53 | SELECT * , 54 | COUNT([Value]) 55 | OVER ( 56 | ORDER BY [ID] ASC 57 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW 58 | ) AS [Count_Backwards] , 59 | COUNT([Value]) 60 | OVER ( 61 | ORDER BY [ID] DESC 62 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW 63 | ) AS [Count_Forward] 64 | FROM [Example2] 65 | ) 66 | --SELECT * FROM Value_Counts ORDER BY ID 67 | SELECT * , 68 | MAX([Value]) 69 | OVER (PARTITION BY [Count_Backwards]) AS [Last_Non_Null_Value] , 70 | MAX([Value]) 71 | OVER (PARTITION BY [Count_Forward]) AS [Next_Non_Null_Value] 72 | FROM [Value_Counts] 73 | ORDER BY ID; -------------------------------------------------------------------------------- /Interpolations/Phase 1 - Original Data.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------- 2 | -- O'Reilly Online Training ------------ 3 | -- Advanced SQL Series ----------------- 4 | -- Linear and Proximal Interpolations -- 5 | ---------------------------------------- 6 | -- Phase I - Original Data -- 7 | ----------------------------- 8 | USE [master]; 9 | GO 10 | 11 | -- DROP DATABASE /*IF EXISTS*/ [Interpolation]; -- SQL 2016 12 | -- GO 13 | 14 | CREATE DATABASE [Interpolation]; 15 | GO 16 | 17 | USE [Interpolation]; 18 | GO 19 | 20 | -- Sensors 21 | CREATE TABLE [Sensors] 22 | ( 23 | [Sensor] NVARCHAR(10) NOT NULL, 24 | CONSTRAINT [PK_Sensors] 25 | PRIMARY KEY CLUSTERED ([Sensor]) 26 | ); 27 | GO 28 | 29 | INSERT INTO [Sensors] 30 | ( 31 | [Sensor] 32 | ) 33 | VALUES (N'Sensor A'), 34 | (N'Sensor B'), 35 | (N'Sensor C'); 36 | GO 37 | 38 | -- Measurements 39 | CREATE TABLE [Measurements] 40 | ( 41 | [Sensor] NVARCHAR(10) NOT NULL, 42 | [Measure Date] DATETIME2(0) NOT NULL, 43 | [Measurement] DECIMAL(7,2) NOT NULL, 44 | CONSTRAINT [PK_Measurements] 45 | PRIMARY KEY CLUSTERED([Sensor], [Measure Date]), 46 | CONSTRAINT [FK_Measurements_Sensors] 47 | FOREIGN KEY ([Sensor]) 48 | REFERENCES [Sensors]([Sensor]) 49 | ); 50 | GO 51 | 52 | INSERT INTO [Measurements] 53 | VALUES (N'Sensor A', N'20160101', 10.00), 54 | (N'Sensor A', N'20160105', 12.00), 55 | (N'Sensor A', N'20160111', 14.00), 56 | (N'Sensor A', N'20160121', 12.00), 57 | (N'Sensor A', N'20160127', 08.00), 58 | (N'Sensor A', N'20160127 01:30:00', 08.00), -- Duplicate Entry due to bad data type choice - DATETIME2 instead of DATE 59 | (N'Sensor B', N'20160110', 09.00), 60 | (N'Sensor B', N'20160111', 22.00), 61 | (N'Sensor B', N'20160123', 10.00), 62 | (N'Sensor C', N'20160101', 16.00), 63 | (N'Sensor C', N'20160103', 14.00), 64 | (N'Sensor C', N'20160121', 19.00); 65 | GO 66 | 67 | SELECT * 68 | FROM [Measurements]; 69 | GO 70 | -------------------------------------------------------------------------------- /Interpolations/Phase 2 - Auxiliary Data.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------- 2 | -- O'Reilly Online Training ------------ 3 | -- Advanced SQL Series ----------------- 4 | -- Linear and Proximal Interpolations -- 5 | ---------------------------------------- 6 | -- Phase II - Auxiliary Data -- 7 | ------------------------------- 8 | 9 | USE [Interpolation]; 10 | GO 11 | 12 | -- Numbers Table 13 | 14 | CREATE TABLE [Numbers] 15 | ( 16 | [Number] INT NOT NULL 17 | ); 18 | 19 | -- Populate Numbers 20 | ; WITH 21 | [Level0] AS (SELECT 1 AS [constant] UNION ALL SELECT 1), 22 | [Level1] AS (SELECT 1 AS [constant] FROM [Level0] AS [A] CROSS JOIN [Level0] AS [B]), 23 | [Level2] AS (SELECT 1 AS [constant] FROM [Level1] AS [A] CROSS JOIN [Level1] AS [B]), 24 | [Level3] AS (SELECT 1 AS [constant] FROM [Level2] AS [A] CROSS JOIN [Level2] AS [B]), 25 | [Level4] AS (SELECT 1 AS [constant] FROM [Level3] AS [A] CROSS JOIN [Level3] AS [B]), 26 | [Sequential Numbers] AS (SELECT ROW_NUMBER() OVER(ORDER BY (SELECT NULL)) AS [Number] FROM [Level4]) 27 | INSERT INTO [Numbers] ([Number]) 28 | SELECT [Number] 29 | FROM [Sequential Numbers]; 30 | GO 31 | 32 | ALTER TABLE [dbo].[Numbers] 33 | ADD CONSTRAINT [PK_Numbers] 34 | PRIMARY KEY CLUSTERED ([Number]); 35 | GO 36 | 37 | -- Calendar Table 38 | 39 | CREATE TABLE [Calendar] 40 | ( 41 | [Date] DATE NOT NULL, 42 | [Year] SMALLINT NOT NULL, 43 | [Month] TINYINT NOT NULL, 44 | [Month Name] NVARCHAR(10) NOT NULL, 45 | [Day] TINYINT NOT NULL, 46 | [Day Name] NVARCHAR(10) NOT NULL, 47 | [Day Of Year] SMALLINT NOT NULL, 48 | [Weekday] NVARCHAR(10) NOT NULL, 49 | [Year Week] TINYINT NOT NULL--, 50 | --[US Federal Holiday] NVARCHAR(50) NULL, 51 | --[Other Holiday] NVARCHAR(50) NULL 52 | ); 53 | GO 54 | 55 | -- https://catalog.data.gov/dataset/federal-holidays/resource/28f55f36-dbff-4b9b-9092-ad8b8d679ef7 56 | 57 | -- Populate Calendar 58 | 59 | INSERT [Calendar] 60 | ( 61 | [Date], 62 | [Year], 63 | [Month], 64 | [Month Name], 65 | [Day], 66 | [Day Name], 67 | [Day Of Year], 68 | [Weekday], 69 | [Year Week] 70 | ) 71 | SELECT DATEADD(DAY, [Number]-1, '19000101'), 72 | YEAR(DATEADD(DAY, [Number]-1, '19000101')), 73 | MONTH(DATEADD(DAY, [Number]-1, '19000101')), 74 | DATENAME(MONTH, (DATEADD(DAY, [Number]-1, '19000101'))), 75 | DAY((DATEADD(DAY, [Number]-1, '19000101'))), 76 | DATENAME(WEEKDAY, (DATEADD(DAY, [Number]-1, '19000101'))), 77 | DATEPART(DAYOFYEAR, (DATEADD(DAY, [Number]-1, '19000101'))), 78 | DATEPART(WEEKDAY, (DATEADD(DAY, [Number]-1, '19000101'))), 79 | DATEPART(WEEK, (DATEADD(DAY, [Number]-1, '19000101'))) 80 | FROM [Numbers] 81 | WHERE [Number] <= 65536; 82 | GO 83 | 84 | ALTER TABLE [dbo].[Calendar] 85 | ADD CONSTRAINT [PK_Calendar] 86 | PRIMARY KEY CLUSTERED ([Date]); 87 | GO 88 | 89 | -- CREATE NONCLUSTERED INDEX Calendar_Year ON Calendar (Year); 90 | -- CREATE NONCLUSTERED INDEX Calendar_Month ON Calendar (Month); 91 | -- CREATE NONCLUSTERED INDEX Calendar_Day ON Calendar (Day); 92 | -- ... 93 | 94 | SELECT TOP (100) * 95 | FROM [Calendar]; 96 | GO 97 | -------------------------------------------------------------------------------- /Interpolations/Phase 3 - Source Sets.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------- 2 | -- O'Reilly Online Training ------------ 3 | -- Advanced SQL Series ----------------- 4 | -- Linear and Proximal Interpolations -- 5 | ----------------------------------------------- 6 | -- Phase III - Generate Source Data Set Rows -- 7 | ----------------------------------------------- 8 | 9 | USE [Interpolation]; 10 | GO 11 | 12 | CREATE VIEW [Measurements With Sequential Date Ranges] 13 | AS 14 | WITH [Daily Measurements] -- Clean source data to make sure we don't get 2 measurements per day -- 15 | AS ( SELECT [Sensor], 16 | CAST([Measure Date] AS DATE) AS [Measure Date], 17 | AVG([Measurement]) AS [Measurement] 18 | FROM [Measurements] 19 | GROUP BY [Sensor], 20 | CAST([Measure Date] AS DATE) 21 | ) 22 | --SELECT * FROM [Daily Measurements] ORDER BY [Sensor], [Measure Date] 23 | , 24 | [Date Ranges Per Sensor] 25 | AS ( 26 | SELECT [Sensor], 27 | MIN([Measure Date]) AS [Min Date], 28 | MAX([Measure Date]) AS [Max Date] 29 | FROM [Daily Measurements] 30 | GROUP BY [Sensor] 31 | ) 32 | -- SELECT * FROM [Date Ranges Per Sensor] ORDER BY [Sensor], [Min Date] 33 | -- Return all sequntial date ranges for all sensors 34 | SELECT [DRPS].[Sensor], 35 | [C].[Date], 36 | [DM].[Measurement] 37 | FROM ( 38 | [Calendar] AS [C] 39 | INNER JOIN 40 | [Date Ranges Per Sensor] AS [DRPS] 41 | ON [C].[Date] BETWEEN [DRPS].[Min Date] AND [DRPS].[Max Date] 42 | ) 43 | LEFT OUTER JOIN 44 | [Daily Measurements] AS [DM] 45 | ON [DM].[Sensor] = [DRPS].[Sensor] 46 | AND 47 | [DM].[Measure Date] = [C].[Date]; 48 | GO 49 | 50 | SELECT * 51 | FROM [Measurements With Sequential Date Ranges] 52 | ORDER BY [Sensor], 53 | [Date]; 54 | GO 55 | -------------------------------------------------------------------------------- /Interpolations/Phase 4 - Linear Interpolation - Add Last and Next Non Null Values.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------- 2 | -- O'Reilly Online Training ------------ 3 | -- Advanced SQL Series ----------------- 4 | -- Linear and Proximal Interpolations -- 5 | -------------------------------------------------- 6 | -- Phase IV - Add Last and Next Non Null Values -- 7 | -- Using solution 2 with counts ------------------ 8 | -------------------------------------------------- 9 | 10 | USE [Interpolation]; 11 | GO 12 | 13 | CREATE VIEW [Measurements With Previous and Next Non Null Values Using COUNT] 14 | AS 15 | WITH 16 | [With Previous and Next Non Null Value Counts] 17 | AS 18 | ( 19 | SELECT * , 20 | COUNT([Measurement]) 21 | OVER( PARTITION BY [Sensor] 22 | ORDER BY [Date] ASC 23 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW 24 | ) AS [Count Backwards] , 25 | COUNT([Measurement]) 26 | OVER( PARTITION BY [Sensor] 27 | ORDER BY [Date] DESC 28 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW 29 | ) AS [Count Forward] 30 | FROM [Measurements With Sequential Date Ranges] 31 | ) 32 | --SELECT * FROM [With Previous and Next Non Null Value Counts] ORDER BY Sensor, Date 33 | SELECT * , 34 | MAX([Measurement]) 35 | OVER (PARTITION BY [Sensor], [Count Backwards]) AS [Last Non Null Measurement] , 36 | MAX([Measurement]) 37 | OVER (PARTITION BY [Sensor], [Count Forward]) AS [Next Non Null Measurement], 38 | ROW_NUMBER() 39 | OVER(PARTITION BY [Sensor], [Count Backwards] 40 | ORDER BY [Date] ASC 41 | ) AS [Sequence Within Group] 42 | FROM [With Previous and Next Non Null Value Counts]; 43 | GO 44 | 45 | SELECT * 46 | FROM [Measurements With Previous and Next Non Null Values Using COUNT] 47 | ORDER BY [Sensor], [Date]; 48 | GO 49 | -------------------------------------------------------------------------------- /Interpolations/Phase 4 - Proximal Interpolation - Add Last and Next Non Null Values.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------- 2 | -- O'Reilly Online Training ------------ 3 | -- Advanced SQL Series ----------------- 4 | -- Linear and Proximal Interpolations -- 5 | -------------------------------------------------- 6 | -- Phase IV - Add Last and Next Non Null Values -- 7 | -- Using solution 1 with CASE -------------------- 8 | -------------------------------------------------- 9 | 10 | USE [Interpolation]; 11 | GO 12 | 13 | CREATE VIEW [Measurements With Previous and Next Non Null Values Using CASE] 14 | AS 15 | WITH 16 | [With Previous and Next Non Null Value Dates] 17 | AS 18 | ( 19 | SELECT *, 20 | MAX (CASE WHEN [Measurement] IS NOT NULL THEN [Date] ELSE NULL END) 21 | OVER (PARTITION BY [Sensor] ORDER BY [Date] ASC ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) 22 | AS [Last Date With Measurement Value], 23 | MIN (CASE WHEN [Measurement] IS NOT NULL THEN [Date] ELSE NULL END) 24 | OVER (PARTITION BY [Sensor] ORDER BY [Date] ASC ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING) 25 | AS [Next Date With Measurement Value] 26 | FROM [Measurements With Sequential Date Ranges] 27 | ) 28 | --SELECT * FROM [With Previous and Next Non Null Value Dates] ORDER BY Sensor, [Date] 29 | SELECT *, 30 | MAX ([Measurement]) 31 | OVER (PARTITION BY [Sensor], [Last Date With Measurement Value]) AS [Last Value], 32 | MAX ([Measurement]) 33 | OVER (PARTITION BY [Sensor], [Next Date With Measurement Value]) AS [Next Value] 34 | FROM [With Previous and Next Non Null Value Dates]; 35 | GO 36 | 37 | SELECT * 38 | FROM [Measurements With Previous and Next Non Null Values Using CASE] 39 | ORDER BY [Sensor], [Date]; 40 | GO -------------------------------------------------------------------------------- /Interpolations/Phase 5 - Linear Interpolation - Final Solution.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------- 2 | -- O'Reilly Online Training ------------ 3 | -- Advanced SQL Series ----------------- 4 | -- Linear and Proximal Interpolations -- 5 | ---------------------------------------- 6 | -- Phase V - Final Solution -- 7 | -- Linear Interpolation ------ 8 | ------------------------------ 9 | 10 | USE [Interpolation]; 11 | GO 12 | 13 | SELECT [Sensor], 14 | [Date], 15 | CAST( 16 | ISNULL ([Measurement], [Last Non Null Measurement] 17 | + ( 18 | ( 19 | ( [Next Non Null Measurement] - [Last Non Null Measurement]) 20 | / MAX([Sequence Within Group]) 21 | OVER ( 22 | PARTITION BY [Sensor], [Count Backwards] 23 | ) 24 | ) 25 | * ([Sequence Within Group] - 1) -- Offset Group Starting Point 26 | ) 27 | ) 28 | AS DECIMAL(7,2) 29 | ) AS [Measurement], 30 | CASE WHEN [Measurement] IS NULL 31 | THEN N'Interpolated' 32 | ELSE N'Measured' 33 | END AS [Measurement Type] 34 | FROM [Measurements With Previous and Next Non Null Values Using COUNT] 35 | ORDER BY [Sensor], [Date]; 36 | GO 37 | -------------------------------------------------------------------------------- /Interpolations/Phase 5 - Proximal Interpolation - Final Solution.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------- 2 | -- O'Reilly Online Training ------------ 3 | -- Advanced SQL Series ----------------- 4 | -- Linear and Proximal Interpolations -- 5 | ---------------------------------------- 6 | -- Phase V - Final Solution -- 7 | -- Proximal Interpolation ---- 8 | ------------------------------ 9 | 10 | USE [Interpolation]; 11 | GO 12 | 13 | SELECT [Sensor], 14 | [Date], 15 | ISNULL ([Measurement], 16 | CASE 17 | WHEN DATEDIFF(DAY, [Date], [Next Date With Measurement Value]) 18 | > DATEDIFF(DAY, [Last Date With Measurement Value], [Date]) 19 | THEN [Last Value] 20 | ELSE [Next Value] 21 | END 22 | ) AS [Measurement], 23 | CASE 24 | WHEN [Measurement] IS NULL 25 | THEN N'Interpolated' 26 | ELSE N'Measured' 27 | END AS [Measurement Type] 28 | FROM [Measurements With Previous and Next Non Null Values Using CASE] 29 | ORDER BY [Sensor], 30 | [Date]; 31 | GO -------------------------------------------------------------------------------- /Interpolations/Readme.txt: -------------------------------------------------------------------------------- 1 | Demo code for O'Reilly training, "Advanced SQL Series: Linear and proximal interpolations". 2 | -------------------------------------------------------------------------------- /Interpolations/Review Demo.sql: -------------------------------------------------------------------------------- 1 | USE BasicDemos; 2 | GO 3 | 4 | SELECT * 5 | FROM [dbo].[Orders]; 6 | 7 | SELECT * 8 | FROM [dbo].[OrderItems]; 9 | 10 | -- Show each customer's order totals, with a running total to Date 11 | 12 | /* 13 | OrderID OrderDate Customer OrderTotal Orders Total to Date 14 | -------------------------------------------------------------- 15 | 1 2018-01-01 Dave 3.75 3.75 16 | 2 2018-01-02 John 9 9 17 | 3 2018-01-03 Gerald 4.5 4.5 18 | 4 2018-01-09 John 14.5 23.50 19 | */ 20 | 21 | 22 | ;WITH [Order Totals] 23 | AS 24 | ( 25 | SELECT O.OrderID, 26 | SUM(OD.Quantity * OD.Price) AS OrderTotal 27 | FROM Orders AS O 28 | INNER JOIN 29 | [OrderItems] AS OD 30 | ON OD.OrderID = O.OrderID 31 | GROUP BY O.OrderID 32 | ) 33 | , [Order Totals with Order Attributes] 34 | AS 35 | ( 36 | SELECT OT.OrderID, 37 | OT.OrderTotal, 38 | O.OrderDate, 39 | O.Customer 40 | FROM [Order Totals] AS OT 41 | INNER JOIN 42 | Orders AS O 43 | ON OT.OrderID = O.OrderID 44 | ) 45 | SELECT *, 46 | ( 47 | SELECT SUM(OTA1.OrderTotal) 48 | FROM [Order Totals with Order Attributes] AS OTA1 49 | WHERE OTA.Customer = OTA1.Customer 50 | AND 51 | OTA1.OrderDate <= OTA.OrderDate 52 | ) 53 | AS [Total to Date], 54 | SUM(OTA.OrderTotal) 55 | OVER ( PARTITION BY OTA.Customer 56 | ORDER BY OTA.OrderDate ASC 57 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW 58 | ) AS [Total to Date 2] 59 | FROM [Order Totals with Order Attributes] AS OTA; 60 | 61 | -------------------------------------------------------------------------------- /Mastering-Basics/04 - Development Environment.txt: -------------------------------------------------------------------------------- 1 | O'reilly Online Training 2 | Mastering Relational SQL Querying 3 | Development Environment Setup 4 | ------------------------------------------- 5 | 6 | Go to http://sqlitebrowser.org/ 7 | Download and install the version for your O/S 8 | * Installation instructions on home page 9 | 10 | Launch DB Browser for SQLite. 11 | Click 'New Database'. 12 | Select a folder and name for your database file. 13 | * Note - This example will be a tiny file, don't worry about space considerations 14 | 15 | The client will launch the CREATE TABLE wizard automatically. 16 | Type 'MyFirstTable' in the name text box. 17 | 18 | Click 'Add Field'. 19 | * Note - in most RDBMS the term is a 'column'. However, since SQLite does not enforce domain integrity, it is unfortunately a 'field', like in a spreadsheet 20 | Type 'KeyColumn' in the field name text box. 21 | Leave the domain data type at the default type 'INTEGER'. 22 | Check the 'Not NULL' and 'Primary Key' check boxes. 23 | 24 | Click 'Add Field'. 25 | Type 'AttributeColumn' in the field name text box. 26 | Change the domain data type to 'TEXT'. 27 | Check the 'Not NULL' check box. 28 | 29 | Examine the SQL statement that was automatically generated for you by the wizard. 30 | Click 'OK' 31 | 32 | Click the 'Browse Data' tab, the table is still empty of course. 33 | Click 'New Record' 34 | * Note that the term 'Record' is wrong. In a relational database, the term is a 'Row'. 35 | Enter the values '1' and 'A' for both Columns respectively and click 'New Record'. 36 | * NOTE - you must press 'Enter' after inserting a value for each cell. 37 | * NOTE - Do not type the values in the filter field, use the empty text boxes right below it. 38 | Enter the values '2' and 'B' for both Columns respectively and press 'Enter'. 39 | 40 | Explore the various tabs that the tool offers. 41 | 42 | Click 'Write Changes' 43 | * Note - Your changes are not committed to the database file until you click 'Write Changes'. 44 | 45 | Click 'File -> Close Database' (or CTRL+W). 46 | 47 | Click 'File' and select your database from the list of 3 recently used files (or CTRL+1). 48 | Click the 'Browse Data' tab and make sure your table values are still there. 49 | 50 | Congratulations! 51 | You successfully created your first database! 52 | 53 | Additional Links: 54 | 55 | https://dev.mysql.com/downloads/ 56 | https://www.postgresql.org/download/ 57 | https://www.microsoft.com/en-us/sql-server/sql-server-editions-express 58 | https://docs.microsoft.com/en-us/sql/ssms/download-sql-server-management-studio-ssms 59 | https://docs.microsoft.com/en-us/sql/sql-operations-studio/download 60 | http://www.oracle.com/technetwork/database/database-technologies/express-edition/downloads/index.html 61 | http://www.sqlfiddle.com/ 62 | https://dbfiddle.uk/ 63 | -------------------------------------------------------------------------------- /Mastering-Basics/06 - DQL - DML.sql: -------------------------------------------------------------------------------- 1 | -- O'reilly Online Training 2 | -- Mastering Relational SQL Querying 3 | -- DML and DQL 4 | -------------------------------------- 5 | 6 | -- Open the database created in the previous exercise 'set up the development environment' 7 | -- Or use this script to create MyFirstTable 8 | 9 | CREATE TABLE MyFirstTable 10 | ( 11 | KeyColumn INT PRIMARY KEY, 12 | AttributeColumn VARCHAR(10) NOT NULL 13 | ); 14 | 15 | INSERT INTO MyFirstTable (KeyColumn,AttributeColumn) 16 | VALUES (1,'A'), (2, 'C'); 17 | 18 | -- DQL 19 | SELECT * 20 | FROM MyFirstTable; 21 | 22 | -- DML 23 | INSERT INTO MyFirstTable 24 | VALUES(3, 'C'); 25 | -- Execute the above SELECT statement again 26 | -- Try to execute the INSERT again and read the error at the bottom pane 27 | 28 | UPDATE MyFirstTable 29 | SET AttributeColumn = 'CC' 30 | WHERE KeyColumn = 3; 31 | -- Execute the above SELECT statement again 32 | 33 | DELETE 34 | FROM MyFirstTable 35 | WHERE KeyColumn = 3; 36 | -- Execute the above SELECT statement again 37 | 38 | -- Click 'Revert Changes' or 'Write Changes' as you wish 39 | -------------------------------------------------------------------------------- /Mastering-Basics/09 - FROM and JOINS.sql: -------------------------------------------------------------------------------- 1 | -- O'reilly Online Training 2 | -- Mastering Relational SQL Querying 3 | -- FROM clause and JOINS 4 | -------------------------------------- 5 | 6 | ----------------------------------- 7 | -- CLASS EXAMPLES ----------------- 8 | ----------------------------------- 9 | 10 | -- CROSS JOIN 11 | SELECT * 12 | FROM Customers 13 | CROSS JOIN 14 | Items; 15 | 16 | SELECT * 17 | FROM Customers AS C 18 | INNER JOIN 19 | Items 20 | ON 1=1; 21 | 22 | -- INNER JOIN 23 | SELECT * 24 | FROM Orders AS O 25 | INNER JOIN 26 | OrderItems AS OI 27 | ON O.OrderID = OI.OrderID; 28 | 29 | -- OUTER JOIN 30 | SELECT * 31 | FROM Items AS I 32 | LEFT OUTER JOIN 33 | OrderItems AS OI 34 | ON I.Item = OI.Item; 35 | -- Which item was never ordered? 36 | 37 | -- Joining more than 2 tables 38 | SELECT * 39 | FROM Items AS I 40 | LEFT OUTER JOIN 41 | ( 42 | OrderItems AS OI 43 | INNER JOIN -- LEFT OUTER JOIN 44 | Orders AS O 45 | ON O.OrderID = OI.OrderID 46 | ) 47 | ON I.Item = OI.Item; 48 | 49 | -- Non equality JOIN predicate 50 | SELECT * 51 | FROM Customers AS C1 52 | INNER JOIN 53 | Customers AS C2 54 | ON C1.Customer > C2.Customer; 55 | 56 | 57 | ----------------------------------- 58 | -- EXERCISES ---------------------- 59 | ----------------------------------- 60 | 61 | -- Create a new database using the DemoDB_Script.sql script 62 | ----------------------------------------------------------- 63 | -- 1. Download the DemoDB_Script.sql file and save to a local folder 64 | -- 2. Open DB Browser and click File -> Import -> Database from SQL File 65 | -- 3. Select the DemoDB_Script.sql file and click Open 66 | -- 4. In the 'save as database file' window, choose a name and location for the database file 67 | -- 5. Click OK and confirm that you can see the tables and data 68 | 69 | -- OR Use the pre-built DemoDB_SQLite3.db file 70 | ----------------------------------- 71 | -- 1. Download the DemoDB_SQLite3.db and save it to a local folder 72 | -- 2. Open DB Browser and click File -> Open Database 73 | -- 3. Point to the downloaded file and click 'OK. 74 | -- 4. Confirm that you can see the tables and data 75 | 76 | -- Exercise 1 77 | -- Write a query that returns all orders and include the countries of the customers 78 | 79 | -- Exercise 2 80 | -- Change the above query so that it returns customers that made no orders as well 81 | 82 | -- Exercise 3 83 | -- Write a query that returns all orders, include the country of the customer, and the order items 84 | -- 85 | -- 86 | -- 87 | -- 88 | -- 89 | -- 90 | -- 91 | -- 92 | -- 93 | -- 94 | -- 95 | -- 96 | -- 97 | -- 98 | -- 99 | -- 100 | -- 101 | -- 102 | -- 103 | ----------------------------------- 104 | -- EXERCISE ANSWERS --------------- 105 | ----------------------------------- 106 | 107 | -- Exercise 1 108 | -- Write a query that returns all orders and include the countries of the customers 109 | 110 | SELECT * 111 | FROM Orders AS O 112 | INNER JOIN 113 | Customers AS C 114 | ON O.Customer = C.Customer 115 | 116 | -- Exercise 2 117 | -- Change the above query so that it returns customers that made no orders as well 118 | 119 | SELECT * 120 | FROM Customers AS C 121 | LEFT OUTER JOIN 122 | Orders AS O 123 | ON O.Customer = C.Customer 124 | 125 | -- Exercise 3 126 | -- Write a query that returns all orders, the order items, and include the country of the customer 127 | 128 | SELECT * 129 | FROM Orders AS O 130 | INNER JOIN 131 | OrderItems AS OI 132 | ON O.OrderID = OI.OrderID 133 | INNER JOIN 134 | Customers AS C 135 | ON C.Customer = O.Customer; 136 | -------------------------------------------------------------------------------- /Mastering-Basics/10 - WHERE.sql: -------------------------------------------------------------------------------- 1 | -- O'reilly Online Training 2 | -- Mastering Relational SQL Querying 3 | -- WHERE 4 | -------------------------------------- 5 | 6 | ----------------------------------- 7 | -- CLASS EXAMPLES ----------------- 8 | ----------------------------------- 9 | 10 | -- Simple Filter 11 | SELECT * 12 | FROM Customers 13 | WHERE Country = 'USA'; 14 | 15 | -- NULL 16 | ALTER TABLE Items 17 | ADD TipSize INT NULL; 18 | 19 | UPDATE Items SET TipSize = 1 WHERE Item = 'Pencil'; 20 | UPDATE Items SET TipSize = 1 WHERE Item = 'Pen'; 21 | UPDATE Items SET TipSize = 3 WHERE Item = 'Marker'; 22 | 23 | SELECT * 24 | FROM Items; 25 | 26 | SELECT * 27 | FROM Items 28 | WHERE TipSize = NULL; 29 | 30 | SELECT * 31 | FROM Items 32 | WHERE TipSize IS NULL; 33 | 34 | -- Composite Filter 35 | SELECT * 36 | FROM Customers AS C 37 | INNER JOIN 38 | Orders AS O 39 | ON O.Customer = C.Customer 40 | WHERE C.Country <> 'USA' 41 | AND 42 | O.OrderDate BETWEEN '20180101' AND '20180131'; 43 | 44 | -- IN 45 | 46 | SELECT * 47 | FROM Customers 48 | WHERE Country IN ('USA', 'Canada'); 49 | 50 | 51 | -- Items that were never ordered 52 | SELECT I.Item 53 | FROM Items AS I 54 | LEFT OUTER JOIN 55 | OrderItems AS OI 56 | ON I.Item = OI.Item 57 | WHERE OI.OrderID IS NULL; 58 | 59 | ----------------------------------- 60 | -- EXERCISES ---------------------- 61 | ----------------------------------- 62 | -- Execute the ALTER TABLE and INSERTs to add the TipSize column to Items 63 | 64 | -- Exercise 1 - Write a query to show customers that have no orders 65 | 66 | -- Exercise 2 - Write a query to show customers that ordered pencils 67 | -- 68 | -- 69 | -- 70 | -- 71 | -- 72 | -- 73 | -- 74 | -- 75 | -- 76 | -- 77 | -- 78 | -- 79 | -- 80 | -- 81 | -- 82 | -- 83 | -- 84 | -- 85 | -- 86 | ----------------------------------- 87 | -- EXERCISE ANSWERS --------------- 88 | ----------------------------------- 89 | 90 | -- Exercise 1 - Write a query to show customers that have no orders 91 | 92 | SELECT C.Customer 93 | FROM Customers AS C 94 | LEFT OUTER JOIN 95 | Orders AS O 96 | ON C.Customer = O.Customer 97 | WHERE O.OrderID IS NULL; 98 | 99 | -- Exercise 2 - Write a query to show customers that ordered pencils 100 | 101 | SELECT DISTINCT O.Customer 102 | FROM Orders AS O 103 | INNER JOIN 104 | OrderItems AS OI 105 | ON OI.OrderID = O.OrderID 106 | WHERE OI.Item = 'Pencil'; 107 | -------------------------------------------------------------------------------- /Mastering-Basics/11 - GROUP BY.sql: -------------------------------------------------------------------------------- 1 | -- O'reilly Online Training 2 | -- Mastering Relational SQL Querying 3 | -- GROUP BY 4 | -------------------------------------- 5 | 6 | ----------------------------------- 7 | -- CLASS EXAMPLES ----------------- 8 | ----------------------------------- 9 | 10 | -- BEWARE! 11 | SELECT * 12 | FROM Orders 13 | GROUP BY Customer; 14 | 15 | -- Aggregate functions 16 | SELECT Customer, COUNT(*) AS NumOrders 17 | FROM Orders 18 | GROUP BY Customer; 19 | 20 | SELECT OrderID, SUM(Price * Quantity) AS Total 21 | FROM OrderItems 22 | GROUP BY OrderID; 23 | 24 | -- Aggregates with no GROUP BY 25 | SELECT COUNT(*) 26 | FROM Items; 27 | 28 | -- Multiple aggregates 29 | SELECT C.Country, 30 | OI.Item, 31 | SUM(OI.Quantity) AS NumItems, 32 | MAX(OI.Price) AS MostExpensive 33 | FROM Customers AS C 34 | INNER JOIN 35 | Orders AS O 36 | ON O.Customer = C.Customer 37 | INNER JOIN 38 | OrderItems AS OI 39 | ON OI.OrderID = O.OrderID 40 | GROUP BY C.Country, OI.Item 41 | HAVING SUM(OI.Quantity) > 1; 42 | 43 | 44 | -- NULL 45 | SELECT TipSize, 46 | COUNT(*) AS NumItems 47 | FROM Items 48 | GROUP BY TipSize; 49 | 50 | SELECT OI.OrderID, 51 | COUNT(*) AS NumItems, 52 | COUNT(I.TipSize) AS NumberOfItemsWithATip, 53 | COUNT(DISTINCT I.TipSize) AS NumberOfUniqueTipSizes 54 | FROM OrderItems AS OI 55 | RIGHT OUTER JOIN 56 | Items AS I 57 | ON I.Item = OI.Item 58 | GROUP BY OI.OrderID 59 | 60 | 61 | 62 | ----------------------------------- 63 | -- EXERCISES ---------------------- 64 | ----------------------------------- 65 | 66 | -- Exercise 1: Write a query that shows how many customers per country we have 67 | 68 | -- Exercise 2: Write a query that shows how many distinct items every customer bought 69 | 70 | -- Exercise 3: Modify the above query to exclude customers that bought more than 2 distinct items 71 | 72 | -- 73 | -- 74 | -- 75 | -- 76 | -- 77 | -- 78 | -- 79 | -- 80 | -- 81 | -- 82 | -- 83 | -- 84 | -- 85 | -- 86 | -- 87 | -- 88 | -- 89 | -- 90 | -- 91 | ----------------------------------- 92 | -- EXERCISE ANSWERS --------------- 93 | ----------------------------------- 94 | 95 | -- Exercise 1: Write a query that shows how many customers per country we have 96 | 97 | SELECT Country, COUNT(*) AS NumCustomers 98 | FROM Customers 99 | GROUP BY Country; 100 | 101 | -- Exercise 2: Write a query that shows how many distinct items every customer bought 102 | 103 | SELECT O.Customer, COUNT(DISTINCT OI.Item) AS NumItems 104 | FROM Orders AS O 105 | INNER JOIN 106 | OrderItems AS OI 107 | ON O.OrderID = OI.OrderID 108 | GROUP BY O.Customer; 109 | 110 | -- Exercise 3: Modify the above query to exclude customers that bought more than 2 distinct items 111 | 112 | SELECT O.Customer, COUNT(DISTINCT OI.Item) AS NumItems 113 | FROM Orders AS O 114 | INNER JOIN 115 | OrderItems AS OI 116 | ON O.OrderID = OI.OrderID 117 | GROUP BY O.Customer 118 | HAVING COUNT(DISTINCT OI.Item) <= 2; 119 | -------------------------------------------------------------------------------- /Mastering-Basics/12 - ORDER BY.sql: -------------------------------------------------------------------------------- 1 | -- O'reilly Online Training 2 | -- Mastering Relational SQL Querying 3 | -- ORDER BY 4 | -------------------------------------- 5 | 6 | ----------------------------------- 7 | -- CLASS EXAMPLES ----------------- 8 | ----------------------------------- 9 | 10 | -- Simple ordering 11 | SELECT * 12 | FROM OrderItems 13 | ORDER BY Quantity DESC 14 | 15 | -- Order by non selected column 16 | SELECT distinct Item, Price --distinct - another mortal sin 17 | FROM OrderItems 18 | ORDER BY Quantity DESC; 19 | 20 | -- Order by expression 21 | SELECT * 22 | FROM OrderItems 23 | ORDER BY (Price * Quantity) DESC; 24 | 25 | -- Use SELECT list alias for ORDER BY 26 | SELECT *, Price * Quantity AS ItemTotal 27 | FROM OrderItems 28 | ORDER BY ItemTotal DESC; 29 | 30 | -- Multiple expressions order 31 | SELECT OrderID, SUM(Price * Quantity) AS OrderTotal, SUM(Quantity) AS TotalQuantity 32 | FROM OrderItems 33 | GROUP BY OrderID 34 | ORDER BY OrderTotal DESC, TotalQuantity DESC; 35 | 36 | -- Paging 37 | -- SQL Server syntax 38 | SELECT * 39 | FROM Orders AS O 40 | ORDER BY OrderDate 41 | OFFSET 0 ROWS FETCH NEXT 3 ROWS ONLY; 42 | 43 | -- SQLite syntax 44 | --SELECT * 45 | --FROM Orders AS O 46 | --ORDER BY OrderDate 47 | --LIMIT 3 OFFSET 0; 48 | 49 | ----------------------------------- 50 | -- EXERCISES ---------------------- 51 | ----------------------------------- 52 | 53 | -- Exercise 1: Write a query that returns customers, ordered by their total number of orders 54 | 55 | -- Exercise 2: Write a query that returns all items, ordered by the date they were last ordered 56 | 57 | -- 58 | -- 59 | -- 60 | -- 61 | -- 62 | -- 63 | -- 64 | -- 65 | -- 66 | -- 67 | -- 68 | -- 69 | -- 70 | -- 71 | -- 72 | -- 73 | -- 74 | -- 75 | -- 76 | ----------------------------------- 77 | -- EXERCISE ANSWERS --------------- 78 | ----------------------------------- 79 | 80 | -- Exercise 1: Write a query that returns customers, ordered by their total number of orders 81 | 82 | SELECT Customer, COUNT(*) AS NumOrders 83 | FROM Orders 84 | GROUP BY Customer 85 | ORDER BY NumOrders; 86 | 87 | 88 | -- Exercise 2: Write a query that returns all items, ordered by the date they were last ordered 89 | 90 | SELECT OI.Item, MAX(O.OrderDate) AS LastOrdered 91 | FROM OrderItems AS OI 92 | INNER JOIN 93 | Orders AS O 94 | ON OI.OrderID = O.OrderID 95 | GROUP BY OI.Item 96 | ORDER BY LastOrdered; 97 | 98 | 99 | -------------------------------------------------------------------------------- /Mastering-Basics/13 - Subqueries.sql: -------------------------------------------------------------------------------- 1 | -- O'reilly Online Training 2 | -- Mastering Relational SQL Querying 3 | -- Subqueries 4 | -------------------------------------- 5 | 6 | ----------------------------------- 7 | -- CLASS EXAMPLES ----------------- 8 | ----------------------------------- 9 | 10 | -- Derived table 11 | SELECT * 12 | FROM Orders AS O 13 | INNER JOIN 14 | ( 15 | SELECT Customer, Country 16 | FROM Customers 17 | WHERE Country IN ('USA', 'Canada') 18 | ) AS AmericanCustomers 19 | ON O.Customer = AmericanCustomers.Customer; 20 | GO 21 | 22 | -- Nested aggregates 23 | 24 | SELECT O.Customer, MAX(TQPO.OrderTotalItems) 25 | FROM ( 26 | SELECT OrderID, SUM(Quantity) AS OrderTotalItems 27 | FROM OrderItems 28 | GROUP BY OrderID 29 | ) AS TQPO 30 | INNER JOIN 31 | Orders AS O 32 | ON O.OrderID = TQPO.OrderID 33 | GROUP BY O.Customer 34 | 35 | -- IN 36 | 37 | SELECT * 38 | FROM Orders 39 | WHERE Customer IN (SELECT Customer FROM Customers WHERE Country = 'USA') 40 | 41 | -- Expression sub query 42 | 43 | SELECT OrderID, Item, Quantity, 44 | (SELECT MAX(Quantity) FROM OrderItems) AS HigestQuantityEverSold 45 | FROM OrderItems; 46 | 47 | 48 | 49 | 50 | 51 | 52 | 53 | -- Correlated 54 | 55 | SELECT * 56 | FROM OrderItems AS OI 57 | INNER JOIN 58 | ( 59 | SELECT Item, SUM(Quantity) AS TotalSoldForItem 60 | FROM OrderITems 61 | GROUP BY Item 62 | ) AS ItemTotals 63 | ON OI.Item = ItemTotals.Item 64 | 65 | 66 | SELECT *, 67 | ( 68 | SELECT SUM(Quantity) AS TotalQuantityForItemEver 69 | FROM OrderItems AS OI2 70 | WHERE OI1.Item = OI2.Item 71 | ) AS TotalOrderedForItem 72 | FROM OrderItems AS OI1 73 | 74 | 75 | -- EXISTS 76 | SELECT DISTINCT country 77 | FROM Customers AS C 78 | WHERE EXISTS ( 79 | SELECT * 80 | FROM Orders AS O 81 | WHERE O.Customer = C.Customer 82 | ); 83 | 84 | 85 | 86 | 87 | -- NOT EXISTS 88 | SELECT Country 89 | FROM Customers AS C 90 | WHERE NOT EXISTS ( 91 | SELECT NULL 92 | FROM Orders AS O 93 | WHERE O.Customer = C.Customer 94 | ); 95 | 96 | ----------------------------------- 97 | -- EXERCISES ---------------------- 98 | ----------------------------------- 99 | 100 | -- Exercise 1: Write a query that shows items that were never ordered using EXISTS 101 | 102 | -- Exercise 2: Write a query that shows all items ever ordered, 103 | -- the quantity they were ordered, 104 | -- and the % they consist of the total of all items ordered 105 | 106 | -- Exercise 3 (Optional): Modify the previous query to add a column for the maximum quantity this item 107 | -- was ever ordered, but only by the same customer who made the order 108 | 109 | -- 110 | -- 111 | -- 112 | -- 113 | -- 114 | -- 115 | -- 116 | -- 117 | -- 118 | -- 119 | -- 120 | -- 121 | -- 122 | -- 123 | -- 124 | -- 125 | -- 126 | -- 127 | -- 128 | ----------------------------------- 129 | -- EXERCISE ANSWERS --------------- 130 | ----------------------------------- 131 | 132 | -- Exercise 1: Write a query that shows items that were never ordered using EXISTS 133 | 134 | SELECT Item 135 | FROM Items AS I 136 | WHERE NOT EXISTS ( SELECT NULL 137 | FROM OrderItems AS OI 138 | WHERE OI.Item = I.Item 139 | ); 140 | 141 | -- Exercise 2: Write a query that shows all items ordered for each customer, 142 | -- the total quantity they were ordered by that customer, 143 | -- and the % of that item quantity out of the total quantity of all items ever ordered by all customers 144 | 145 | SELECT O.Customer, OI.Item, SUM(OI.Quantity) AS TotalSoldForItem, 146 | 1.0 * SUM(OI.Quantity) / (SELECT SUM(Quantity) FROM OrderItems) * 100 AS PercentOfTotalItems 147 | -- The 1.0 is needed to make the expression decimal instead of integer 148 | FROM OrderItems AS OI 149 | INNER JOIN 150 | Orders AS O 151 | ON OI.OrderID = O.OrderID 152 | GROUP BY O.Customer, OI.Item 153 | 154 | -- Exercise 3: Modify the previous query to add a column for the maximum quantity this item 155 | -- was ever ordered, but only by the same customer who made the order 156 | 157 | SELECT O1.Customer, OI1.Item, 158 | SUM(OI1.Quantity) AS TotalSoldForItem, 159 | 1.0 * SUM(OI1.Quantity) / (SELECT SUM(Quantity) FROM OrderItems) * 100 AS PercentOfTotalItems, 160 | -- The 1.0 is needed to make the expression decimal instead of integer 161 | ( SELECT MAX(OI2.Quantity) 162 | FROM OrderItems AS OI2 163 | INNER JOIN 164 | Orders AS O2 165 | ON OI2.OrderID = O2.OrderID 166 | WHERE O2.Customer = O1.Customer 167 | AND 168 | OI2.Item = OI1.Item 169 | ) AS MaxItemOrderedByCustomer 170 | FROM OrderItems AS OI1 171 | INNER JOIN 172 | Orders AS O1 173 | ON OI1.OrderID = O1.OrderID 174 | GROUP BY O1.Customer, OI1.Item 175 | 176 | -------------------------------------------------------------------------------- /Mastering-Basics/14 - Set Operators.sql: -------------------------------------------------------------------------------- 1 | -- O'reilly Online Training 2 | -- Mastering Relational SQL Querying 3 | -- Set Operators 4 | -------------------------------------- 5 | 6 | ----------------------------------- 7 | -- CLASS EXAMPLES ----------------- 8 | ----------------------------------- 9 | 10 | -- Join / subquery alternative - show items that were never ordered 11 | SELECT Item FROM Items 12 | EXCEPT 13 | SELECT Item FROM OrderItems; 14 | 15 | -- Show items that were ordered on both Order #1 and Order #2 16 | SELECT Item FROM OrderItems WHERE OrderID = 1 17 | INTERSECT 18 | SELECT Item FROM OrderItems WHERE OrderID = 2; 19 | 20 | -- Show items ordered by both USA and Canadian customers 21 | SELECT OD.Item 22 | FROM OrderItems AS OD 23 | INNER JOIN 24 | Orders AS O 25 | ON OD.OrderID = O.OrderID 26 | INNER JOIN 27 | Customers AS C 28 | ON C.Customer = O.Customer 29 | WHERE C.Country = 'USA' 30 | INTERSECT 31 | SELECT OD.Item 32 | FROM OrderItems AS OD 33 | INNER JOIN 34 | Orders AS O 35 | ON OD.OrderID = O.OrderID 36 | INNER JOIN 37 | Customers AS C 38 | ON C.Customer = O.Customer 39 | WHERE C.Country = 'Canada'; 40 | 41 | -- Composing set operators 42 | -- Show Items that were ordered, and those that were never ordered, and tell them apart 43 | SELECT DISTINCT Item, 'Yes' AS Ordered 44 | FROM OrderItems 45 | UNION ALL 46 | ( 47 | SELECT Item, 'No' AS Ordered 48 | FROM Items 49 | EXCEPT 50 | SELECT Item, 'No' FROM OrderItems 51 | ); 52 | 53 | ----------------------------------- 54 | -- EXERCISES ---------------------- 55 | ----------------------------------- 56 | 57 | -- Exercise 1: Write a query that shows customers that made no orders using set operators 58 | 59 | -- Exercise 2: Write a query that shows items that were bought by either canadian customers, 60 | -- or by any customer with a quantity of 2 or more 61 | 62 | -- 63 | -- 64 | -- 65 | -- 66 | -- 67 | -- 68 | -- 69 | -- 70 | -- 71 | -- 72 | -- 73 | -- 74 | -- 75 | -- 76 | -- 77 | -- 78 | -- 79 | -- 80 | -- 81 | ----------------------------------- 82 | -- EXERCISE ANSWERS --------------- 83 | ----------------------------------- 84 | -- Exercise 1: Write a query that shows customers that made no orders using set operators 85 | 86 | SELECT Customer 87 | FROM Customers 88 | EXCEPT 89 | SELECT Customer 90 | FROM Orders; 91 | 92 | -- Exercise 2: Write a query that shows items that were bought by either canadian customers, 93 | -- or by any customer with a quantity of 2 or more total for that item in all their orders 94 | 95 | SELECT OI.Item 96 | FROM OrderItems AS OI 97 | INNER JOIN 98 | Orders AS O 99 | ON O.OrderID = OI.OrderID 100 | INNER JOIN 101 | Customers AS C 102 | ON C.Customer = O.Customer 103 | WHERE C.Country = 'Canada' 104 | UNION 105 | SELECT OI.Item 106 | FROM OrderItems AS OI 107 | INNER JOIN 108 | Orders AS O 109 | ON O.OrderID = OI.OrderID 110 | GROUP BY OI.Item, O.Customer 111 | HAVING SUM(OI.Quantity) > 1 112 | -------------------------------------------------------------------------------- /Mastering-Basics/DemoDB_SQLite3.db: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/ami-levin/OReilly-Training/e6ebe61b129d3e60d244fcb4f126679296d30704/Mastering-Basics/DemoDB_SQLite3.db -------------------------------------------------------------------------------- /Mastering-Basics/DemoDB_Script.sql: -------------------------------------------------------------------------------- 1 | -- O'reilly Online Training 2 | -- Relational SQL Querying - Mastering the Basics 3 | -- Demo DB 4 | -------------------------------------- 5 | -- DROP DATABASE BasicDemos; 6 | -- CREATE DATABASE BasicDemos; 7 | -- GO 8 | 9 | USE BasicDemos; 10 | GO 11 | 12 | CREATE TABLE Customers ( 13 | Customer VARCHAR(20) NOT NULL 14 | PRIMARY KEY, 15 | Country VARCHAR(20) NULL 16 | ); 17 | 18 | CREATE TABLE Items ( 19 | Item VARCHAR(20) NOT NULL 20 | PRIMARY KEY 21 | ); 22 | 23 | CREATE TABLE Orders ( 24 | OrderID INTEGER NOT NULL 25 | PRIMARY KEY, 26 | OrderDate DATE NOT NULL, 27 | Customer VARCHAR(20) NOT NULL 28 | REFERENCES Customers(Customer) 29 | ); 30 | 31 | CREATE TABLE OrderItems ( 32 | OrderID INTEGER NOT NULL 33 | REFERENCES Orders(OrderID), 34 | Item VARCHAR(20) NOT NULL 35 | REFERENCES Items(Item), 36 | Quantity INTEGER NOT NULL 37 | CHECK (Quantity > 0), 38 | Price DECIMAL(9,2) NOT NULL 39 | CHECK (Price >=0), 40 | PRIMARY KEY (OrderID, Item) 41 | ); 42 | 43 | INSERT INTO Customers (Customer, Country) 44 | VALUES ('Dave', 'USA'), ('John', 'USA'), ('Gerald', 'Canada'), ('Jose', 'Peru'), ('Tim', NULL); 45 | 46 | INSERT INTO Items (Item) 47 | VALUES ('Pencil'), ('Pen'), ('Marker'), ('Notebook'), ('Ruler'); 48 | 49 | INSERT INTO Orders (OrderID, OrderDate, Customer) 50 | VALUES (1, '20180101', 'Dave'), (2, '20180102', 'John'), (3, '20180103', 'Gerald'), (4, '20180109', 'John'); 51 | 52 | INSERT INTO OrderItems (OrderID, Item, Quantity, Price) 53 | VALUES (1, 'Pen', 2, 1.5), (1, 'Pencil', 1, 0.75), 54 | (2, 'Marker', 3, 3), 55 | (3, 'Pen', 1, 1.5), (3, 'Marker', 1, 3), 56 | (4, 'Pen', 4, 1.5), (4, 'Pencil', 2, 1.25), (4, 'Ruler', 2, 3); 57 | 58 | -------------------------------------------------------------------------------- /Mastering-Basics/Readme.txt: -------------------------------------------------------------------------------- 1 | Demo code for O'Reilly training: "Mastering the basics of relational SQL querying". 2 | -------------------------------------------------------------------------------- /Mastering-Basics/Relational_SQL_MasterPPT.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/ami-levin/OReilly-Training/e6ebe61b129d3e60d244fcb4f126679296d30704/Mastering-Basics/Relational_SQL_MasterPPT.pdf -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Basic Demo Database.sql: -------------------------------------------------------------------------------- 1 | ------------------------------ 2 | -- O'reilly Online Training -- 3 | -- PostgreSQL fundamentals --- 4 | -- Basic Demos Database ------ 5 | ------------------------------ 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | /* 11 | ██████╗ █████╗ ███████╗██╗ ██████╗ ██████╗ ███████╗███╗ ███╗ ██████╗ ███████╗ 12 | ██╔══██╗██╔══██╗██╔════╝██║██╔════╝ ██╔══██╗██╔════╝████╗ ████║██╔═══██╗██╔════╝ 13 | ██████╔╝███████║███████╗██║██║ ██║ ██║█████╗ ██╔████╔██║██║ ██║███████╗ 14 | ██╔══██╗██╔══██║╚════██║██║██║ ██║ ██║██╔══╝ ██║╚██╔╝██║██║ ██║╚════██║ 15 | ██████╔╝██║ ██║███████║██║╚██████╗ ██████╔╝███████╗██║ ╚═╝ ██║╚██████╔╝███████║ 16 | ╚═════╝ ╚═╝ ╚═╝╚══════╝╚═╝ ╚═════╝ ╚═════╝ ╚══════╝╚═╝ ╚═╝ ╚═════╝ ╚══════╝ 17 | */ 18 | 19 | -- DROP DATABASE IF EXISTS basicdemos; 20 | -- CREATE DATABASE basicdemos; 21 | 22 | CREATE TABLE customers ( 23 | customer VARCHAR(20) NOT NULL 24 | PRIMARY KEY, 25 | country VARCHAR(20) NULL 26 | ); 27 | 28 | CREATE TABLE items ( 29 | item VARCHAR(20) NOT NULL 30 | PRIMARY KEY 31 | ); 32 | 33 | CREATE TABLE orders ( 34 | orderid INTEGER NOT NULL 35 | PRIMARY KEY, 36 | orderdate DATE NOT NULL, 37 | customer VARCHAR(20) NOT NULL 38 | REFERENCES customers(customer) 39 | ); 40 | 41 | CREATE TABLE orderitems ( 42 | orderid INTEGER NOT NULL 43 | REFERENCES orders(orderid), 44 | item VARCHAR(20) NOT NULL 45 | REFERENCES items(item), 46 | quantity INTEGER NOT NULL 47 | CHECK (quantity > 0), 48 | price DECIMAL(9,2) NOT NULL 49 | CHECK (price >=0), 50 | PRIMARY KEY (orderid, item) 51 | ); 52 | 53 | INSERT INTO customers (customer, country) 54 | VALUES ('Dave', 'USA'), ('John', 'USA'), ('Gerald', 'Canada'), ('Jose', 'Peru'), ('Tim', NULL); 55 | 56 | INSERT INTO items (item) 57 | VALUES ('Pencil'), ('Pen'), ('Marker'), ('Notebook'), ('Ruler'); 58 | 59 | INSERT INTO orders (orderid, orderdate, customer) 60 | VALUES (1, '20180101', 'Dave'), (2, '20180102', 'John'), (3, '20180103', 'Gerald'), (4, '20180109', 'John'); 61 | 62 | INSERT INTO orderitems (orderid, item, quantity, price) 63 | VALUES (1, 'Pen', 2, 1.5), (1, 'Pencil', 1, 0.75), 64 | (2, 'Marker', 3, 3), 65 | (3, 'Pen', 1, 1.5), (3, 'Marker', 1, 3), 66 | (4, 'Pen', 4, 1.5), (4, 'Pencil', 2, 1.25), (4, 'Ruler', 2, 3); 67 | 68 | -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 1-1.sql: -------------------------------------------------------------------------------- 1 | ------------------------------ 2 | -- O'reilly Online Training -- 3 | -- PostgreSQL fundamentals --- 4 | -- Module 1.1: Architecture -- 5 | ------------------------------ 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- Installation guide walkthrough 11 | -- Tooling overview 12 | 13 | /* 14 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 15 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 16 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 17 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 18 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 19 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 20 | 21 | Download and install PostgreSQL 12 from https://www.enterprisedb.com/downloads/postgresql 22 | See Installation Guide @ https://www.enterprisedb.com/edb-docs/d/postgresql/installation-getting-started/installation-guide-installers/12/toc.html 23 | For Windows and Mac O/S use the GUI installer, see https://www.enterprisedb.com/edb-docs/d/postgresql/installation-getting-started/installation-guide-installers/12/PostgreSQL_Installation_Guide.1.07.html# 24 | You can install all 4 components but no need to launch Stak Builder after installation. 25 | 26 | If for any reason you are unable to install PostgreSQL and have no access to a network or cloud instance, use https://dbfiddle.uk/?rdbms=postgres_12 27 | */ 28 | 29 | -------------------------------------------------------------------------------------- 30 | -------------------------------------------------------------------------------------- 31 | 32 | /* 33 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 34 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 35 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 36 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██╔═══╝ 37 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ███████╗ 38 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚══════╝ 39 | 40 | For local installs, launch PgAdmin4 and connect to your local instance. 41 | Expand Servers -> PostgreSQL 12 -> Databases and select the Postgres database. 42 | Click Tools -> Query Tool 43 | Type "SELECT 'Hello, World!';" and click Execute (lightning icon button) or hit F5. 44 | Make sure you see the output in the lower pane. 45 | 46 | Launch PSQL and connect to your local instance. 47 | At the Postgres=# prompt type "SELECT 'Hello, World!';" and hit . 48 | Make sure you get the result: 49 | ?column? 50 | ------------- 51 | Hello World 52 | (1 row) 53 | 54 | Congratulations! you have successfully installed PostgreSQL! 55 | 56 | If using dbfiddle: 57 | Replace the text "select version();" with "SELECT 'Hello, World!';" and click Run. 58 | Make sure you see the result 59 | ?column? 60 | Hello World 61 | */ 62 | 63 | -------------------------------------------------------------------------------------- 64 | -------------------------------------------------------------------------------------- 65 | 66 | /* 67 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 68 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 69 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 70 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 71 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 72 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 73 | 74 | Additional Reading: 75 | ------------------- 76 | https://www.postgresql.org/docs/12/tutorial-start.html 77 | https://en.wikipedia.org/wiki/Database 78 | https://en.wikipedia.org/wiki/Relational_model 79 | https://en.wikipedia.org/wiki/SQL 80 | https://en.wikipedia.org/wiki/PostgreSQL 81 | https://wiki.postgresql.org/wiki/Main_Page 82 | 83 | Tools: 84 | ------ 85 | https://www.pgadmin.org/ 86 | https://www.postgresql.org/docs/12/app-psql.html 87 | https://dbeaver.io/ 88 | https://dbfiddle.uk/?rdbms=postgres_12 89 | https://www.db-fiddle.com/ 90 | http://sqlfiddle.com 91 | 92 | Cloud providers: 93 | ---------------- 94 | https://aws.amazon.com/rds/postgresql/ 95 | https://aws.amazon.com/rds/aurora/postgresql-features/ 96 | https://azure.microsoft.com/en-us/services/postgresql/ 97 | https://cloud.google.com/sql/docs/postgres/ 98 | */ 99 | -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 1-2.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------ 2 | -- O'reilly Online Training -------- 3 | -- PostgreSQL fundamentals --------- 4 | -- Module 1.2: Creating Databases -- 5 | ------------------------------------ 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- CREATE DATABASE basicdemos; 11 | -- Create / manage databases with PgAdmin 12 | -- BACKUP, ANALYZE, VACUUM 13 | 14 | /* 15 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 16 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 17 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 18 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 19 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 20 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 21 | 22 | Using either PgAdmin or PSQL, create a new database named "basicdemos". 23 | * dbfiddle users skip this phase as you don't have permissions to create databases. 24 | You can only use the default database provided by the service. 25 | 26 | With PgAdmin GUI, right click "Databases", choose "Create" and type in "basicdemos". 27 | View the options tabs but don't change anything, and click "Save". 28 | Alternatively, use the query tool editor window and execute the query: "CREATE DATABASE basicdemos;" 29 | 30 | After creation completes, you will need to right click "Databases" in PgAdmin and click "Refresh" to see it. 31 | 32 | Open a new editor window in PgAdmin by right clicking "basicdemos" -> and click "Query Tool". 33 | Copy / paste the text, or just open the "Basic Demos Database.sql" file directly with PgAdmin. 34 | * NOTE: Make sure the "basicdemos" is selected on the left navigation pane so that the connection will be established to it. 35 | * dbfiddle users copy and paste the entire script to the dbfiddle window and execute it. 36 | 37 | If using PSQL, you must re-establish a new connection to the database using the "\c basicdemos" command. 38 | 39 | Make sure execution succeeds with no errors. 40 | Take a look at the statements, and write down any questions you have. 41 | We will cover these in the next section, but they are mostly plain english. 42 | 43 | You can close the editor window with the database script. 44 | * dbfiddle users must leave the script in the first text box, it will be executed every time you click 'Run'. 45 | */ 46 | 47 | -------------------------------------------------------------------------------------- 48 | -------------------------------------------------------------------------------------- 49 | 50 | /* 51 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 52 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 53 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 54 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██╔═══╝ 55 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ███████╗ 56 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚══════╝ 57 | */ 58 | 59 | -- Execute the following query in a new PgAdmin editor window or using PSQL: 60 | -- dbfiddle users must use a new text box and keep the original script in place. 61 | -- If using PSQL, you may need to re-establish the connection to the database using the "\c basicdemos" command. 62 | -- The prompt name is the current database. 63 | 64 | SELECT * FROM customers; 65 | 66 | -- Expected Result: 67 | /* 68 | customer | country 69 | ------------------------ 70 | Dave | USA 71 | John | USA 72 | Gerald | Canada 73 | Jose | Peru 74 | Tim | 75 | */ 76 | 77 | -------------------------------------------------------------------------------------- 78 | -------------------------------------------------------------------------------------- 79 | 80 | /* 81 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 82 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 83 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 84 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ╚═══██╗ 85 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██████╔╝ 86 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═════╝ 87 | 88 | *NOTE: dbfiddle users skip this exercise 89 | */ 90 | 91 | -- Backup the basicdemos database using PgAdmin: 92 | -- Right click "basicdemos" and click "Backup". 93 | -- Provide a file name and change format to "Plain". 94 | -- Check the destination folder and open the backup file with a text editor. 95 | 96 | -- OPTIONAL: Backup the basicdemos database using pg_dump: 97 | -- Open command shell and navigate to PostgreSQL BIN folder. 98 | -- Execute the command: pg_dump -U postgres basicdemos > "Destination folder\file" 99 | -- Check the destination folder and open the backup file with a text editor. 100 | 101 | -- Open a new query tool editor window and execute the following statements: 102 | VACUUM customers; 103 | 104 | -- Right click "basicdemos", click "Maintenance" and review the various options. 105 | -- Don't execute, click 'Cancel'. 106 | 107 | -------------------------------------------------------------------------------------- 108 | -------------------------------------------------------------------------------------- 109 | 110 | /* 111 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 112 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 113 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 114 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 115 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 116 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 117 | 118 | Additional Reading: 119 | ------------------- 120 | https://www.postgresql.org/docs/12/sql-createdatabase.html 121 | https://www.postgresql.org/docs/12/sql-alterdatabase.html 122 | https://www.postgresql.org/docs/12/sql-dropdatabase.html 123 | https://www.pgadmin.org/ 124 | https://www.postgresql.org/docs/12/app-psql.html 125 | https://www.postgresql.org/docs/12/app-pgdump.html 126 | https://www.postgresql.org/docs/12/routine-vacuuming.html 127 | https://www.postgresql.org/docs/12/sql-vacuum.html 128 | https://www.postgresql.org/docs/12/sql-analyze.html 129 | */ 130 | -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 1-3.sql: -------------------------------------------------------------------------------- 1 | ----------------------------------- 2 | -- O'reilly Online Training ------- 3 | -- PostgreSQL fundamentals -------- 4 | -- Module 1.3: Accessing Objects -- 5 | ----------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | CREATE SCHEMA oreilly; 11 | -- Using public schema 12 | CREATE USER oreilly WITH PASSWORD = 'some_password'; 13 | CREATE TABLE oreilly.customers (customer varchar(20), country varchar(20)); 14 | SELECT * FROM customers; 15 | SELECT * FROM oreilly.customers; 16 | -- assigning permissions (DCL) 17 | 18 | /* 19 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 20 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 21 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 22 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 23 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 24 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 25 | 26 | * NOTE: dbfiddle users skip this exercise 27 | */ 28 | 29 | -- Create a new user called "oreilly" using the query tool editor or PSQL. 30 | 31 | CREATE USER oreilly WITH PASSWORD 'some_password'; 32 | 33 | -- In PgAdmin, right click on Login/Group Roles and click "Refresh". 34 | -- Make sure user oreilly is visible. 35 | 36 | -------------------------------------------------------------------------------------- 37 | -------------------------------------------------------------------------------------- 38 | 39 | /* 40 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 41 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 42 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 43 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██╔═══╝ 44 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ███████╗ 45 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚══════╝ 46 | 47 | * NOTE: dbfiddle users skip this exercise 48 | */ 49 | 50 | -- In PgAdmin or PSQL, execute the query: 51 | -- * NOTE: Make sure your connection is set to the basicdemos database! 52 | 53 | CREATE SCHEMA oreilly; 54 | 55 | -- In PgAdmin, right click "Schemas" (under basicdemos) and click "Refresh". 56 | -- Right click "Schemas" -> "Create" -> "Schema" and view the options but don't save, cancel. 57 | 58 | -- In PgAdmin or PSQL execute the queries: 59 | 60 | CREATE TABLE oreilly.customers (customer varchar(20), country varchar(20)); 61 | 62 | INSERT INTO oreilly.customers VALUES ('your name', 'your country'); 63 | 64 | -------------------------------------------------------------------------------------- 65 | -------------------------------------------------------------------------------------- 66 | 67 | /* 68 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 69 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 70 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 71 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ╚═══██╗ 72 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██████╔╝ 73 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═════╝ 74 | 75 | *NOTE: dbfiddle users skip this exercise 76 | */ 77 | 78 | -- Right click "basicdemos" -> properties. switch to "Security" and click the + sign next to "Privileges". 79 | -- Add "oreilly" as "Grantee", and click the "connect" checkbox under the Privileges tab. 80 | -- Click "Save". 81 | 82 | -- In PgAdmin, expand "basicdemos" -> "Schemas". 83 | -- Right click the "oreilly" schema and click "properties". 84 | -- Switch to "Security" and click the + sign next to "Privileges". 85 | -- Add "oreilly" as Grantee, and the "Usage" privilege. 86 | -- Click "Save". 87 | 88 | -- In PgAdmin, expand "basicdemos" -> "Schemas" -> "oreilly" -> "tables". 89 | -- Right click "customers" and choose "Properties". 90 | -- Switch to "Security" tab and click the + sign next to "Privileges". 91 | -- Add "oreilly" as "Grantee", and click "All" permissions checkbox. 92 | -- Click "Save". 93 | 94 | -- Launch a new PSQL window, type "basicdemos" for database, and "oreilly" as user name, provide your password. 95 | -- Execute the following query: 96 | 97 | SELECT * FROM customers; 98 | 99 | -- Can you explain the result? 100 | 101 | -- Execute the following query: 102 | SELECT * FROM public.customers; 103 | 104 | -- Can you explain the result? 105 | 106 | -------------------------------------------------------------------------------------- 107 | -------------------------------------------------------------------------------------- 108 | 109 | /* 110 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 111 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 112 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 113 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 114 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 115 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 116 | 117 | Additional Reading: 118 | ------------------- 119 | https://www.postgresql.org/docs/12/sql-createdatabase.html 120 | https://www.postgresql.org/docs/12/ddl-schemas.html 121 | https://www.postgresql.org/docs/12/user-manag.html 122 | https://www.postgresql.org/docs/12/sql-createschema.html 123 | https://www.postgresql.org/docs/12/sql-createuser.html 124 | https://www.postgresql.org/docs/12/sql-createrole.html 125 | https://www.postgresql.org/docs/12/client-authentication.html 126 | https://www.postgresql.org/docs/12/sql-grant.html 127 | https://www.postgresql.org/docs/12/sql-revoke.html 128 | */ -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 2-1.sql: -------------------------------------------------------------------------------- 1 | --------------------------------- 2 | -- O'reilly Online Training ----- 3 | -- PostgreSQL fundamentals ------ 4 | -- Module 2.1: Creating Tables -- 5 | --------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- CREATE TABLE / ALTER TABLE DDL and PgAdmin 11 | 12 | /* 13 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 14 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 15 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 16 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 17 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 18 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 19 | 20 | * NOTE: dbfiddle users must use SQL code to perform these tasks, no GUI for you - extra challenge bonus points! 21 | */ 22 | 23 | -- In PgAdmin, expand "Databases" -> "basicdemos" -> "Schemas" -> "oreilly" -> "Tables". 24 | -- Right click on customers and click "Properties". Switch to the Columns tab. 25 | -- Add a third column named "Phone" with a data typs of character varying and a length of 10. 26 | -- Click "Save". 27 | 28 | -- Expand "customers" table, right click on "Columns" and click "Create" -> "Column". 29 | -- Add a 4th column named "gender", switch to "Definition" tab and choose a data type of character and a length of 2. 30 | -- Switch to the "SQL" tab and review the script. 31 | -- Copy the script and paste it into PgAdmin query tool editor window. 32 | -- Click 'Cancel'. 33 | -- Execute the script in PgAdmin, refresh the navigation pane view for the customers table. 34 | 35 | -- What's the difference between executing in PgAdmin query tool and executing from the GUI wizard? 36 | 37 | -------------------------------------------------------------------------------------- 38 | -------------------------------------------------------------------------------------- 39 | 40 | /* 41 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 42 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 43 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 44 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 45 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 46 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 47 | 48 | Additional Reading: 49 | ------------------- 50 | https://www.postgresql.org/docs/12/sql-createtable.html 51 | https://www.postgresql.org/docs/12/sql-altertable.html 52 | https://www.postgresql.org/docs/12/sql-droptable.html 53 | */ -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 2-2.sql: -------------------------------------------------------------------------------- 1 | ------------------------------ 2 | -- O'reilly Online Training -- 3 | -- PostgreSQL fundamentals --- 4 | -- Module 2.2: Constraints --- 5 | ------------------------------ 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- Primary keys 11 | -- Unique constraints 12 | -- NULL constraints 13 | -- Foreign Keys 14 | -- Check constraints 15 | 16 | /* 17 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 18 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 19 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 20 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 21 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 22 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 23 | 24 | * NOTE: dbfiddle users - (almost...) no more restrictions for you in this course! 25 | -- 26 | */ 27 | 28 | -- Alter the oreilly.customers table so that 29 | -- 1. Customer name will identify each customer. 30 | -- 2. Country name will be mandatory. 31 | -- USE THE DOCUMENTATION TO FIGURE OUT THE SYNTAX - https://www.postgresql.org/docs/12/sql-altertable.html 32 | -- **** Scroll down for a solution 33 | 34 | -- 35 | 36 | -- 37 | 38 | -- 39 | 40 | -- 41 | 42 | -- 43 | 44 | -- 45 | 46 | -- 47 | 48 | -- 49 | 50 | -- 51 | 52 | -- 53 | 54 | /* 55 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 56 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 57 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 58 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 59 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 60 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 61 | */ 62 | 63 | 64 | -- 65 | 66 | -- 67 | 68 | -- 69 | 70 | -- 71 | 72 | -- 73 | 74 | -- 75 | 76 | ALTER TABLE oreilly.customers ADD CONSTRAINT PK_Customers PRIMARY KEY(Customer); 77 | ALTER TABLE oreilly.customers ALTER COLUMN Country SET NOT NULL; 78 | 79 | /* 80 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 81 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 82 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 83 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██╔═══╝ 84 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ███████╗ 85 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚══════╝ 86 | */ 87 | 88 | -- Review the basicdemo db scripts CREATE TABLE statements and see that they make sense. 89 | -- Write down your questions, we will have some review time right after this exercise. 90 | 91 | 92 | /* 93 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 94 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 95 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 96 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 97 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 98 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 99 | 100 | Additional Reading: 101 | ------------------- 102 | https://www.postgresql.org/docs/12/ddl-constraints.html 103 | https://www.postgresql.org/docs/12/sql-createtable.html 104 | https://www.postgresql.org/docs/12/sql-altertable.html 105 | */ 106 | -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 2-3.sql: -------------------------------------------------------------------------------- 1 | ------------------------------ 2 | -- O'reilly Online Training -- 3 | -- PostgreSQL fundamentals --- 4 | -- Module 2.3: Data Types ---- 5 | ------------------------------ 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- Data type families 11 | -- Data type conversions 12 | 13 | /* 14 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 15 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 16 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 17 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 18 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 19 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 20 | */ 21 | 22 | -- Change the phone column in oreilly.customers to an integer instead of a string. 23 | -- Add another column to this table for the customer's birth date. 24 | -- You can (and should) add constraints to this column as you see fit. 25 | -- **** Scroll down for a solution 26 | 27 | -- 28 | 29 | -- 30 | 31 | -- 32 | 33 | -- 34 | 35 | -- 36 | 37 | -- 38 | 39 | -- 40 | 41 | -- 42 | 43 | -- 44 | 45 | -- 46 | 47 | /* 48 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 49 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 50 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 51 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 52 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 53 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 54 | */ 55 | 56 | 57 | -- 58 | 59 | -- 60 | 61 | -- 62 | 63 | -- 64 | 65 | -- 66 | 67 | -- 68 | 69 | ALTER TABLE oreilly.customers 70 | ALTER COLUMN phone SET DATA TYPE INT USING phone::integer; 71 | 72 | ALTER TABLE oreilly.customers 73 | ADD COLUMN birthdate DATE 74 | NULL 75 | CHECK (birthdate < '20010101'); 76 | -- CHECK constraint just an example of limiting customers to be born in the year 2000 or before. 77 | -- You can make up your own... 78 | 79 | /* 80 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 81 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 82 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 83 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 84 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 85 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 86 | 87 | Additional Reading: 88 | ------------------- 89 | 90 | https://www.postgresql.org/docs/12/datatype.html 91 | https://www.postgresql.org/docs/12/sql-createtype.html 92 | https://www.postgresql.org/docs/12/typeconv.html 93 | https://www.postgresql.org/docs/12/sql-createdomain.html 94 | */ -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 3-1.sql: -------------------------------------------------------------------------------- 1 | ------------------------------ 2 | -- O'reilly Online Training -- 3 | -- PostgreSQL fundamentals --- 4 | -- Module 3.1: DML/DQL ------- 5 | ------------------------------ 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- INSERT, UPDATE, DELETE, SELECT 11 | 12 | /* 13 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 14 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 15 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 16 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 17 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 18 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 19 | */ 20 | 21 | -- Add the following data to the oreilly.customers table: 22 | -- New customer Jim is a male, he is from Canada, born on Jan 2nd 1984, and his phone number is 12345612, 23 | -- New customer Jill is a female, she is from Germany, born on July 3rd 1991, and her phone number is 09865409 24 | 25 | /* 26 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 27 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 28 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 29 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██╔═══╝ 30 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ███████╗ 31 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚══════╝ 32 | */ 33 | 34 | -- We had an error in the system, all customer's birth date are 1 day off, we need to adjust them to the day after the current day. 35 | -- Use the documentation (hint: https://www.postgresql.org/docs/12/functions-datetime.html) 36 | 37 | 38 | -- **** Scroll down for solutions to both exercises 39 | 40 | -- 41 | 42 | -- 43 | 44 | -- 45 | 46 | -- 47 | 48 | -- 49 | 50 | -- 51 | 52 | -- 53 | 54 | -- 55 | 56 | -- 57 | 58 | -- 59 | 60 | /* 61 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 62 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 63 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 64 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 65 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 66 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 67 | */ 68 | 69 | 70 | -- 71 | 72 | -- 73 | 74 | -- 75 | 76 | -- 77 | 78 | -- 79 | 80 | -- 81 | 82 | INSERT INTO oreilly.customers(customer, country, phone, gender, birthdate) 83 | VALUES ('Jim', 'Canada', 12345612, 'M', '19840102'), 84 | ('Jill', 'Germany', 9865409, 'F', '19910703'); 85 | 86 | UPDATE oreilly.customers 87 | SET birthdate = birthdate + 1; 88 | 89 | /* 90 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 91 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 92 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 93 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 94 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 95 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 96 | 97 | Additional Reading: 98 | ------------------- 99 | https://www.postgresql.org/docs/12/tutorial-populate.html 100 | https://www.postgresql.org/docs/12/tutorial-update.html 101 | https://www.postgresql.org/docs/12/tutorial-delete.html 102 | https://www.postgresql.org/docs/12/sql-insert.html 103 | https://www.postgresql.org/docs/12/sql-update.html 104 | https://www.postgresql.org/docs/12/sql-delete.html 105 | https://www.postgresql.org/docs/12/sql-truncate.html 106 | */ -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 3-2.sql: -------------------------------------------------------------------------------- 1 | ------------------------------ 2 | -- O'reilly Online Training -- 3 | -- PostgreSQL fundamentals --- 4 | -- Module 3.2: SELECT -------- 5 | ------------------------------ 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- SELECT processing order 11 | 12 | /* 13 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 14 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 15 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 16 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 17 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 18 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 19 | */ 20 | 21 | -- No hands-on exercise, just read the first part of the wikipedia page link below. 22 | -- We will learn more of this concept later. 23 | 24 | /* 25 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 26 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 27 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 28 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 29 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 30 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 31 | 32 | Additional Reading: 33 | ------------------- 34 | https://www.postgresql.org/docs/12/sql-select.html 35 | https://en.wikipedia.org/wiki/SQL_syntax#Queries 36 | */ -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 3-3.sql: -------------------------------------------------------------------------------- 1 | ------------------------------ 2 | -- O'reilly Online Training -- 3 | -- PostgreSQL fundamentals --- 4 | -- Module 3.3: JOINs --------- 5 | ------------------------------ 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- CROSS JOIN, INNER JOIN, OUTER JOIN 11 | 12 | /* 13 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 14 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 15 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 16 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 17 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 18 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 19 | */ 20 | 21 | -- Write a query that produces the following result set: 22 | -- * 1 row per order item and include items never ordered (notebook). 23 | 24 | /* 25 | item | orderid | quantity 26 | ------------------------------------- 27 | Pen | 1 | 2 28 | Pencil | 1 | 1 29 | Marker | 2 | 3 30 | Pen | 3 | 1 31 | Marker | 3 | 1 32 | Pen | 4 | 4 33 | Pencil | 4 | 2 34 | Ruler | 4 | 2 35 | Notebook | [null] | [null] 36 | */ 37 | 38 | -- **** Scroll down for solution 39 | 40 | -- 41 | 42 | -- 43 | 44 | -- 45 | 46 | -- 47 | 48 | -- 49 | 50 | -- 51 | 52 | -- 53 | 54 | -- 55 | 56 | -- 57 | 58 | -- 59 | 60 | /* 61 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 62 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 63 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 64 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 65 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 66 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 67 | */ 68 | 69 | -- 70 | 71 | -- 72 | 73 | -- 74 | 75 | -- 76 | 77 | -- 78 | 79 | -- 80 | 81 | SELECT i.item, oi.orderid, oi.quantity 82 | FROM items AS i 83 | LEFT OUTER JOIN 84 | orderitems AS oi 85 | ON i.item = oi.item; 86 | 87 | /* 88 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 89 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 90 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 91 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 92 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 93 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 94 | 95 | Additional Reading: 96 | ------------------- 97 | https://www.postgresql.org/docs/12/tutorial-join.html 98 | https://www.postgresql.org/docs/12/sql-select.html#SQL-FROM 99 | */ -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 3-4.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------- 2 | -- O'reilly Online Training ---------- 3 | -- PostgreSQL fundamentals ----------- 4 | -- Module 3.4: Filtering & Grouping -- 5 | -------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- WHERE and NULLs 11 | -- GROUP BY and HAVING 12 | -- Logical limitations 13 | 14 | /* 15 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 16 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 17 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 18 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 19 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 20 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 21 | */ 22 | 23 | -- Write a query that produces the following result: 24 | -- For each known country, count the number of customers. 25 | /* 26 | country | numberofcustomers 27 | ----------------------------- 28 | Canada | 1 29 | Peru | 1 30 | USA | 2 31 | */ 32 | 33 | -- **** Scroll down for solution 34 | 35 | -- 36 | 37 | -- 38 | 39 | -- 40 | 41 | -- 42 | 43 | -- 44 | 45 | -- 46 | 47 | -- 48 | 49 | -- 50 | 51 | -- 52 | 53 | -- 54 | 55 | /* 56 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 57 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 58 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 59 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 60 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 61 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 62 | */ 63 | 64 | -- 65 | 66 | -- 67 | 68 | -- 69 | 70 | -- 71 | 72 | -- 73 | 74 | -- 75 | 76 | SELECT country, COUNT(*) AS numberofcustomers 77 | FROM customers 78 | WHERE country IS NOT NULL 79 | GROUP BY country; 80 | 81 | /* 82 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 83 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 84 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 85 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 86 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 87 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 88 | 89 | Additional Reading: 90 | ------------------- 91 | https://www.postgresql.org/docs/12/sql-select.html#SQL-WHERE 92 | https://www.postgresql.org/docs/12/sql-select.html#SQL-GROUPBY 93 | https://www.postgresql.org/docs/12/sql-select.html#SQL-HAVING 94 | */ -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 4-1.sql: -------------------------------------------------------------------------------- 1 | ------------------------------ 2 | -- O'reilly Online Training -- 3 | -- PostgreSQL fundamentals --- 4 | -- Module 4.1: Indexing ------ 5 | ------------------------------ 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- Indexes and EXPLAIN plans 11 | 12 | /* 13 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 14 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 15 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 16 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 17 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 18 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 19 | */ 20 | 21 | -- Create an index that will benefit the following query: 22 | SELECT * FROM customers WHERE country = 'USA'; 23 | 24 | 25 | -- **** Scroll down for solution 26 | 27 | -- 28 | 29 | -- 30 | 31 | -- 32 | 33 | -- 34 | 35 | -- 36 | 37 | -- 38 | 39 | -- 40 | 41 | -- 42 | 43 | -- 44 | 45 | -- 46 | 47 | /* 48 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 49 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 50 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 51 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 52 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 53 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 54 | */ 55 | 56 | -- 57 | 58 | -- 59 | 60 | -- 61 | 62 | -- 63 | 64 | -- 65 | 66 | -- 67 | 68 | -- Option one: 69 | CREATE INDEX Index1 ON customers(country); 70 | 71 | -- Even better is 72 | CREATE INDEX Index2 ON customers(country, customer); 73 | 74 | -- Can you see why? 75 | 76 | /* 77 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 78 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 79 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 80 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 81 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 82 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 83 | 84 | Additional Reading: 85 | ------------------- 86 | https://www.postgresql.org/docs/12/indexes.html 87 | https://www.postgresql.org/docs/12/sql-createindex.html 88 | 89 | */ -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 4-2.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------- 2 | -- O'reilly Online Training ----------- 3 | -- PostgreSQL fundamentals ------------ 4 | -- Module 4.2: Operators & functions -- 5 | --------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- Showcase common operators and functions 11 | 12 | /* 13 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 14 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 15 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 16 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 17 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 18 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 19 | */ 20 | 21 | -- Write a query that returns the following result: 22 | /* 23 | customer | country | ordermonth | orderyear 24 | ---------------------------------------------- 25 | Dave USA 1 2018 26 | John USA 1 2018 27 | Gerald Canada 1 2018 28 | John USA 1 2018 29 | */ 30 | 31 | -- Hint - see https://www.postgresql.org/docs/12/functions-datetime.html#FUNCTIONS-DATETIME-EXTRACT 32 | 33 | -- **** Scroll down for solution 34 | 35 | -- 36 | 37 | -- 38 | 39 | -- 40 | 41 | -- 42 | 43 | -- 44 | 45 | -- 46 | 47 | -- 48 | 49 | -- 50 | 51 | -- 52 | 53 | -- 54 | 55 | /* 56 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 57 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 58 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 59 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 60 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 61 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 62 | */ 63 | 64 | -- 65 | 66 | -- 67 | 68 | -- 69 | 70 | -- 71 | 72 | -- 73 | 74 | -- 75 | 76 | SELECT c.customer, 77 | COALESCE(c.country, 'N/A') as country, 78 | CAST(EXTRACT(MONTH FROM o.orderdate) AS INT) AS ordermonth, 79 | CAST(EXTRACT(YEAR FROM o.orderdate) AS INT) AS orderyear 80 | FROM customers AS c 81 | INNER JOIN 82 | orders AS o 83 | ON c.customer = o.customer; 84 | 85 | /* 86 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 87 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 88 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 89 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 90 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 91 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 92 | 93 | Additional Reading: 94 | ------------------- 95 | https://www.postgresql.org/docs/12/functions.html 96 | */ -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/Module 4-3.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'reilly Online Training --------- 3 | -- PostgreSQL fundamentals ---------- 4 | -- Module 4.3: Programming Objects -- 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 7 | -------------------------------------------------------------------------------------- 8 | -------------------------------------------------------------------------------------- 9 | 10 | -- Creating views, stored procedures, triggers and functions 11 | -- Abstraction views 12 | -- Inventory trigger 13 | -- Stored procedures 14 | 15 | /* 16 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 17 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 18 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 19 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 20 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 21 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 22 | */ 23 | 24 | -- This is your wrap up exercise. Use the documentation in the links below. 25 | -- Create a new table called 'log' with the following structure: 26 | -- eventtime TIMESTAMP, tablename VARCHAR(20) 27 | 28 | -- Create a trigger on the customers table to log any insert to the customers table in the log table. 29 | -- Test it by adding a new customer and verifying it is logged. 30 | 31 | -- Can you think of additional functionality that you would add to such a logging mechanism? 32 | 33 | -- **** Scroll down for solution 34 | 35 | -- 36 | 37 | -- 38 | 39 | -- 40 | 41 | -- 42 | 43 | -- 44 | 45 | -- 46 | 47 | -- 48 | 49 | -- 50 | 51 | -- 52 | 53 | -- 54 | 55 | /* 56 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 57 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 58 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 59 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 60 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 61 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 62 | */ 63 | 64 | -- 65 | 66 | -- 67 | 68 | -- 69 | 70 | -- 71 | 72 | -- 73 | 74 | -- 75 | 76 | CREATE TABLE insert_log (event_time TIMESTAMP, table_name VARCHAR(20)); 77 | 78 | CREATE FUNCTION log_customer_insert() 79 | RETURNS TRIGGER AS $$ 80 | BEGIN 81 | INSERT INTO insert_log (event_time, table_name) 82 | SELECT CURRENT_TIMESTAMP, 'customers'; 83 | RETURN NEW; 84 | END; 85 | $$ LANGUAGE plpgsql; 86 | 87 | CREATE TRIGGER customer_insert 88 | AFTER INSERT ON customers 89 | FOR EACH STATEMENT 90 | EXECUTE FUNCTION log_customer_insert(); 91 | 92 | INSERT INTO customers (customer, country) 93 | VALUES ('George', 'Sudan'); 94 | 95 | SELECT * FROM customers; 96 | 97 | SELECT * FROM insert_log; 98 | 99 | /* 100 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 101 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 102 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 103 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 104 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 105 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 106 | 107 | Additional Reading: 108 | ------------------- 109 | https://www.postgresql.org/docs/12/sql-createview.html 110 | https://www.postgresql.org/docs/12/sql-createprocedure.html 111 | https://www.postgresql.org/docs/12/sql-createtrigger.html 112 | https://www.postgresql.org/docs/12/sql-createfunction.html 113 | https://www.postgresql.org/docs/12/plpgsql-trigger.html 114 | https://www.postgresql.org/docs/12/plpgsql.html 115 | */ -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/PostgreSQL Fundamentals.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/ami-levin/OReilly-Training/e6ebe61b129d3e60d244fcb4f126679296d30704/PostgreSQL Fundamentals/PostgreSQL Fundamentals.pdf -------------------------------------------------------------------------------- /PostgreSQL Fundamentals/ReadMe.txt: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'reilly Online Training --------- 3 | -- PostgreSQL fundamentals ---------- 4 | ------------------------------------- 5 | -- https://github.com/ami-levin/OReilly-Training/tree/master/PostgreSQL%20Fundamentals 6 | -------------------------------------------------------------------------------------- 7 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # O'Reilly-Training 2 | Demo code repository 3 | -------------------------------------------------------------------------------- /Relational-Division/1_Create_HR_Demo_Database.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------- 2 | -- O'reilly Online Training --------------------- 3 | -- Advanded SQL Querying - Relational Division -- 4 | -- HR Demo Database Setup ----------------------- 5 | ------------------------------------------------- 6 | -- https://1drv.ms/u/s!ArtNt2j9rxvUyAaTUi75_Bm0q5cK 7 | 8 | -- 1 - Get SQL Server 9 | -- https://www.microsoft.com/en-us/sql-server/sql-server-editions-express 10 | -- https://docs.microsoft.com/en-us/sql/ssms/download-sql-server-management-studio-ssms 11 | -- https://docs.microsoft.com/en-us/sql/azure-data-studio/download 12 | 13 | -- 2 - Use SQLFiddle 14 | -- http://sqlfiddle.com/ 15 | 16 | 17 | -- For local SQL only uncomment 18 | -- USE master 19 | -- GO 20 | -- IF DB_ID('HR') IS NOT NULL DROP DATABASE HR WITH ROLLBACK_IMMEDIATE; 21 | -- CREATE DATABASE HR; 22 | -- GO 23 | 24 | USE HR; 25 | GO 26 | 27 | CREATE TABLE Candidates ( 28 | Candidate 29 | VARCHAR(30) NOT NULL 30 | PRIMARY KEY 31 | ); 32 | 33 | CREATE TABLE Jobs ( 34 | Job 35 | VARCHAR(30) NOT NULL 36 | PRIMARY KEY 37 | ); 38 | 39 | CREATE TABLE SkillCategories ( 40 | Category 41 | VARCHAR(30) NOT NULL 42 | PRIMARY KEY 43 | ); 44 | 45 | CREATE TABLE Skills ( 46 | Skill 47 | VARCHAR(30) NOT NULL 48 | PRIMARY KEY, 49 | Category 50 | VARCHAR(30) NOT NULL 51 | REFERENCES SkillCategories(Category) 52 | ON DELETE NO ACTION 53 | ON UPDATE CASCADE 54 | ); 55 | 56 | CREATE TABLE CandidateSkills ( 57 | Candidate 58 | VARCHAR(30) NOT NULL 59 | REFERENCES Candidates(Candidate) 60 | ON DELETE NO ACTION 61 | ON UPDATE CASCADE, 62 | Skill 63 | VARCHAR(30) NOT NULL 64 | REFERENCES Skills(Skill) 65 | ON DELETE NO ACTION 66 | ON UPDATE CASCADE, 67 | PRIMARY KEY (Candidate, Skill) 68 | ); 69 | 70 | CREATE TABLE JobSkills ( 71 | Job 72 | VARCHAR(30) NOT NULL 73 | REFERENCES Jobs(Job) 74 | ON DELETE NO ACTION 75 | ON UPDATE CASCADE, 76 | Skill 77 | VARCHAR(30) NOT NULL 78 | REFERENCES Skills(Skill) 79 | ON DELETE NO ACTION 80 | ON UPDATE CASCADE, 81 | PRIMARY KEY (Job, Skill) 82 | ); 83 | 84 | INSERT INTO Candidates(Candidate) 85 | VALUES ('Ami'),('Xi'),('DJ'),('Steve'), ('Darrin'); 86 | 87 | INSERT INTO Jobs(Job) 88 | VALUES ('DB Architect'), ('Front End Developer'), ('Office Manager'); 89 | 90 | INSERT INTO SkillCategories(Category) 91 | VALUES ('Professional'), ('Personal'); 92 | 93 | INSERT INTO Skills(Skill, Category) 94 | VALUES ('SQL','Professional'), ('DB Design','Professional'), ('C#','Professional'), ('Python','Professional'), ('Java','Professional'), ('Office','Professional'), 95 | ('Team Player','Personal'), ('Leader','Personal'), ('Passionate','Personal'); 96 | 97 | INSERT INTO JobSkills(Job, Skill) 98 | VALUES ('DB Architect','SQL'), ('DB Architect','DB Design'), ('DB Architect','Python'), ('DB Architect','Team Player'), ('DB Architect','Passionate'), 99 | ('Front End Developer','Java'), ('Front End Developer','C#'), ('Front End Developer','Team Player'), ('Front End Developer','Passionate'), 100 | ('Office Manager','Passionate'), ('Office Manager','Office'); 101 | 102 | INSERT INTO CandidateSkills(Candidate, Skill) 103 | VALUES ('Ami','SQL'), ('Ami','DB Design'), ('Ami','Team Player'), ('Ami','Passionate'), 104 | -- Partial match for DB Architect professional, match for personal skills 105 | ('Xi','SQL'), ('Xi','DB Design'), ('Xi','Python'), ('Xi','Team Player'), ('Xi','Passionate'), 106 | -- Xi is a perfect match for DB Architect 107 | ('DJ','Java'), ('DJ','C#'), ('DJ','Team Player'), ('DJ','Passionate'), ('DJ','Python'), 108 | -- DJ is over qualified for Front End Developer (has extra skills) 109 | ('Steve','Passionate'), ('Steve','Leader'), 110 | -- Steve has no professional skills 111 | ('Darrin','SQL'), ('Darrin','DB Design'), ('Darrin','C#'), ('Darrin','Python'), ('Darrin','Java'), ('Darrin','Office'), ('Darrin','Team Player'), ('Darrin','Leader'), ('Darrin','Passionate'); 112 | -- Darrin Has it all 113 | -- And of course, all candidates are passionate... 114 | 115 | SELECT * 116 | FROM Skills; 117 | 118 | SELECT * 119 | FROM CandidateSkills; 120 | 121 | SELECT * 122 | FROM JobSkills; 123 | 124 | -- Cleanup 125 | /* 126 | DROP TABLE CandidateSkills, JobSkills; 127 | DROP TABLE Skills, Jobs; 128 | DROP TABLE SkillCategories, Candidates; 129 | GO 130 | */ 131 | -------------------------------------------------------------------------------- /Relational-Division/2_Relational_Division_Using_Set_Operators.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------- 2 | -- O'reilly Online Training --------------------- 3 | -- Advanded SQL Querying - Relational Division -- 4 | -- Relationa Division with Set Operators -------- 5 | ------------------------------------------------- 6 | -- https://1drv.ms/u/s!ArtNt2j9rxvUyAejEq7HwxNnePxr 7 | 8 | USE HR; 9 | GO 10 | 11 | -- Candidates that have all skills 12 | 13 | SELECT C.Candidate 14 | FROM Candidates AS C 15 | WHERE NOT EXISTS ( 16 | SELECT S.Skill 17 | FROM Skills AS S 18 | EXCEPT 19 | SELECT CS.Skill 20 | FROM CandidateSkills AS CS 21 | WHERE CS.Candidate = C.Candidate 22 | ); 23 | 24 | 25 | -- Candidates that fit the DB Architect job 26 | 27 | SELECT C.Candidate 28 | FROM Candidates AS C 29 | WHERE NOT EXISTS ( 30 | SELECT JS.Skill 31 | FROM JobSkills AS JS 32 | WHERE JS.Job = 'DB Architect' 33 | EXCEPT 34 | SELECT CS.Skill 35 | FROM CandidateSkills AS CS 36 | WHERE CS.Candidate = C.Candidate 37 | ) 38 | 39 | -- EXERCISE: Modify the query to include only exact fits = no remainder (no additional skills) 40 | 41 | /* 42 | 43 | 44 | ad88888ba 88 88 db 88 45 | d8" "8b "" 88 d88b 88 ,d 46 | Y8, 88 d8'`8b 88 88 47 | `Y8aaaaa, 8b,dPPYba, ,adPPYba, 88 88 ,adPPYba, 8b,dPPYba, d8' `8b 88 ,adPPYba, 8b,dPPYba, MM88MMM 48 | `"""""8b, 88P' "8a a8" "8a 88 88 a8P_____88 88P' "Y8 d8YaaaaY8b 88 a8P_____88 88P' "Y8 88 49 | `8b 88 d8 8b d8 88 88 8PP""""""" 88 d8""""""""8b 88 8PP""""""" 88 88 50 | Y8a a8P 88b, ,a8" "8a, ,a8" 88 88 "8b, ,aa 88 d8' `8b 88 "8b, ,aa 88 88, 51 | "Y88888P" 88`YbbdP"' `"YbbdP"' 88 88 `"Ybbd8"' 88 d8' `8b 88 `"Ybbd8"' 88 "Y888 52 | 88 53 | 88 54 | 55 | */ 56 | 57 | 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 | 70 | 71 | 72 | 73 | 74 | 75 | 76 | 77 | 78 | 79 | 80 | 81 | 82 | AND NOT EXISTS ( 83 | SELECT CS1.Skill 84 | FROM CandidateSkills AS CS1 85 | WHERE CS1.Candidate = C.Candidate 86 | EXCEPT 87 | SELECT JS1.Skill 88 | FROM JobSkills AS JS1 89 | WHERE JS1.Job = 'DB Architect' 90 | ); 91 | 92 | 93 | -------------------------------------------------------------------------------- /Relational-Division/3_Relational_Division_Using_COUNT.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------- 2 | -- O'reilly Online Training --------------------- 3 | -- Advanded SQL Querying - Relational Division -- 4 | -- Relationa Division with COUNT ---------------- 5 | ------------------------------------------------- 6 | -- https://1drv.ms/u/s!ArtNt2j9rxvUyAmBwd_SseaQknHl 7 | 8 | USE HR; 9 | GO 10 | 11 | -- Show all candidates that fit the DB Architect role 12 | 13 | WITH DBArchitectSkills 14 | AS 15 | ( 16 | SELECT JS.Skill 17 | FROM JobSkills AS JS 18 | WHERE JS.Job = 'DB Architect' 19 | ) 20 | SELECT CS.Candidate 21 | FROM CandidateSkills AS CS 22 | INNER JOIN 23 | DBArchitectSkills AS DBS 24 | ON DBS.Skill = CS.Skill 25 | GROUP BY CS.Candidate 26 | HAVING COUNT(*) = (SELECT COUNT(*) FROM DBArchitectSkills) 27 | 28 | -- Note that Darrin shows up... 29 | -- how to limit results to an exact match = no remainder? 30 | 31 | WITH DBArchitectSkills 32 | AS 33 | ( 34 | SELECT JS.Skill 35 | FROM JobSkills AS JS 36 | WHERE JS.Job = 'DB Architect' 37 | ) 38 | SELECT CS.Candidate, COUNT(*), COUNT(DBS.Skill) 39 | FROM CandidateSkills AS CS 40 | LEFT OUTER JOIN 41 | DBArchitectSkills AS DBS 42 | ON DBS.Skill = CS.Skill 43 | GROUP BY CS.Candidate 44 | HAVING COUNT(DBS.Skill) = (SELECT COUNT(*) FROM DBArchitectSkills) 45 | AND 46 | COUNT(*) = COUNT(DBS.Skill) 47 | 48 | 49 | -- Division by empty divisor with EXCEPT vs. COUNT 50 | WITH EmptySkills 51 | AS 52 | ( 53 | SELECT JS.Skill 54 | FROM JobSkills AS JS 55 | WHERE JS.Job = 'Empty' 56 | ) 57 | SELECT CS.Candidate 58 | FROM EmptySkills AS DBS 59 | INNER JOIN 60 | CandidateSkills AS CS 61 | ON DBS.Skill = CS.Skill 62 | GROUP BY CS.Candidate 63 | HAVING COUNT(*) = (SELECT COUNT(*) FROM EmptySkills) 64 | 65 | 66 | WITH EmptySkills 67 | AS 68 | ( 69 | SELECT JS.Skill 70 | FROM JobSkills AS JS 71 | WHERE JS.Job = 'Empty' 72 | ) 73 | SELECT C.Candidate 74 | FROM Candidates AS C 75 | WHERE NOT EXISTS ( 76 | SELECT ES.Skill 77 | FROM EmptySkills AS ES 78 | EXCEPT 79 | SELECT CS.Skill 80 | FROM CandidateSkills AS CS 81 | WHERE CS.Candidate = C.Candidate 82 | ); 83 | 84 | -- Exercise - Show all candidates who are over-qualified (have more than the skills needed) for the Front End Developer job 85 | 86 | /* 87 | 88 | 89 | ad88888ba 88 88 db 88 90 | d8" "8b "" 88 d88b 88 ,d 91 | Y8, 88 d8'`8b 88 88 92 | `Y8aaaaa, 8b,dPPYba, ,adPPYba, 88 88 ,adPPYba, 8b,dPPYba, d8' `8b 88 ,adPPYba, 8b,dPPYba, MM88MMM 93 | `"""""8b, 88P' "8a a8" "8a 88 88 a8P_____88 88P' "Y8 d8YaaaaY8b 88 a8P_____88 88P' "Y8 88 94 | `8b 88 d8 8b d8 88 88 8PP""""""" 88 d8""""""""8b 88 8PP""""""" 88 88 95 | Y8a a8P 88b, ,a8" "8a, ,a8" 88 88 "8b, ,aa 88 d8' `8b 88 "8b, ,aa 88 88, 96 | "Y88888P" 88`YbbdP"' `"YbbdP"' 88 88 `"Ybbd8"' 88 d8' `8b 88 `"Ybbd8"' 88 "Y888 97 | 88 98 | 88 99 | 100 | */ 101 | 102 | 103 | 104 | 105 | 106 | 107 | 108 | 109 | 110 | 111 | 112 | 113 | 114 | 115 | 116 | 117 | 118 | 119 | 120 | 121 | 122 | 123 | 124 | 125 | 126 | WITH FrontEndDeveloperSkills 127 | AS 128 | ( 129 | SELECT Job, Skill 130 | FROM JobSkills 131 | WHERE Job = 'Front End Developer' 132 | ) 133 | SELECT CS.Candidate 134 | FROM CandidateSkills AS CS 135 | LEFT OUTER JOIN 136 | FrontEndDeveloperSkills AS FEDS 137 | ON CS.Skill = FEDS.Skill 138 | GROUP BY CS.Candidate 139 | HAVING COUNT(FEDS.Skill) = (SELECT COUNT(*) FROM FrontEndDeveloperSkills) 140 | AND 141 | COUNT(*) > COUNT(FEDS.Skill); 142 | -------------------------------------------------------------------------------- /Relational-Division/5_Relational_Division_Using_Nested_NOT_EXISTS.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------- 2 | -- O'reilly Online Training --------------------- 3 | -- Advanded SQL Querying - Relational Division -- 4 | -- Relationa Division with Nested NOT EXISTS ---- 5 | ------------------------------------------------- 6 | -- https://1drv.ms/u/s!ArtNt2j9rxvUyApISeBka9eGwWil 7 | 8 | -- What skills are common to all jobs? 9 | 10 | SELECT S.Skill 11 | FROM Skills AS S 12 | WHERE NOT EXISTS ( 13 | SELECT NULL 14 | FROM Jobs AS J 15 | WHERE NOT EXISTS ( 16 | SELECT NULL 17 | FROM JobSkills AS JS 18 | WHERE JS.Job = J.Job 19 | AND 20 | JS.Skill = S.Skill 21 | ) 22 | ); 23 | 24 | -- Which candidate has all professional skills? 25 | 26 | WITH ProfessionalSkills 27 | AS 28 | ( 29 | SELECT S.Skill 30 | FROM Skills AS S 31 | WHERE Category = 'Professional' 32 | ) 33 | SELECT C.Candidate 34 | FROM Candidates AS C 35 | WHERE NOT EXISTS ( 36 | SELECT NULL 37 | FROM ProfessionalSkills AS PS 38 | WHERE NOT EXISTS ( 39 | SELECT NULL 40 | FROM CandidateSkills AS CS 41 | WHERE CS.Skill = PS.Skill 42 | AND 43 | CS.Candidate = C.Candidate 44 | ) 45 | ); 46 | 47 | -- Who shares skills with Ami? 48 | 49 | WITH AmisSkills 50 | AS 51 | ( 52 | SELECT CS.Skill 53 | FROM CandidateSkills AS CS 54 | WHERE Candidate = 'Ami' 55 | ) 56 | SELECT C.Candidate 57 | FROM Candidates AS C 58 | WHERE Candidate <> 'Ami' 59 | AND 60 | NOT EXISTS ( 61 | SELECT NULL 62 | FROM AmisSkills AS AMS 63 | WHERE NOT EXISTS ( 64 | SELECT NULL 65 | FROM CandidateSkills AS CS 66 | WHERE CS.Skill = AMS.Skill 67 | AND 68 | CS.Candidate = C.Candidate 69 | ) 70 | ); 71 | 72 | 73 | -- Exact division with no remainder: 74 | -- Show me all candidates for which there isn't a single skill that Ami has, that they don't, 75 | -- AND that they don't have any skill, that ami doesn't have 76 | 77 | WITH AmisSkills 78 | AS 79 | ( 80 | SELECT CS.Skill 81 | FROM CandidateSkills AS CS 82 | WHERE Candidate = 'Ami' 83 | ) 84 | SELECT C.Candidate 85 | FROM Candidates AS C 86 | WHERE Candidate <> 'Ami' 87 | AND 88 | NOT EXISTS ( 89 | SELECT NULL 90 | FROM AmisSkills AS AMS 91 | WHERE NOT EXISTS ( 92 | SELECT NULL 93 | FROM CandidateSkills AS CS 94 | WHERE CS.Skill = AMS.Skill 95 | AND 96 | CS.Candidate = C.Candidate 97 | ) 98 | ) 99 | AND 100 | NOT EXISTS ( 101 | SELECT NULL 102 | FROM CandidateSkills AS CS1 103 | WHERE CS1.Candidate = C.Candidate 104 | AND 105 | CS1.Skill NOT IN (SELECT Skill FROM AmisSkills) 106 | ); 107 | 108 | -- Exercise - Which jobs share personal skill requirements with the DB Architect job? 109 | 110 | /* 111 | 112 | 113 | ad88888ba 88 88 db 88 114 | d8" "8b "" 88 d88b 88 ,d 115 | Y8, 88 d8'`8b 88 88 116 | `Y8aaaaa, 8b,dPPYba, ,adPPYba, 88 88 ,adPPYba, 8b,dPPYba, d8' `8b 88 ,adPPYba, 8b,dPPYba, MM88MMM 117 | `"""""8b, 88P' "8a a8" "8a 88 88 a8P_____88 88P' "Y8 d8YaaaaY8b 88 a8P_____88 88P' "Y8 88 118 | `8b 88 d8 8b d8 88 88 8PP""""""" 88 d8""""""""8b 88 8PP""""""" 88 88 119 | Y8a a8P 88b, ,a8" "8a, ,a8" 88 88 "8b, ,aa 88 d8' `8b 88 "8b, ,aa 88 88, 120 | "Y88888P" 88`YbbdP"' `"YbbdP"' 88 88 `"Ybbd8"' 88 d8' `8b 88 `"Ybbd8"' 88 "Y888 121 | 88 122 | 88 123 | 124 | */ 125 | 126 | 127 | 128 | 129 | 130 | 131 | 132 | 133 | 134 | 135 | 136 | 137 | 138 | 139 | 140 | 141 | 142 | 143 | 144 | 145 | 146 | 147 | 148 | 149 | 150 | WITH DBArchitectPersonalSkills 151 | AS 152 | ( 153 | SELECT Skill 154 | FROM JobSkills AS S 155 | WHERE S.Skill IN ( 156 | SELECT S.Skill 157 | FROM Skills AS S 158 | WHERE S.Category = 'Personal' 159 | ) 160 | AND 161 | Job = 'DB Architect' 162 | ) 163 | SELECT J.Job 164 | FROM Jobs AS J 165 | WHERE Job <> 'DB Architect' 166 | AND 167 | NOT EXISTS ( 168 | SELECT NULL 169 | FROM DBArchitectPersonalSkills AS DBPS 170 | WHERE NOT EXISTS ( 171 | SELECT NULL 172 | FROM JobSkills AS JS1 173 | WHERE JS1.Job = J.Job 174 | AND 175 | JS1.Skill = DBPS.Skill 176 | ) 177 | ); 178 | 179 | -------------------------------------------------------------------------------- /Relational-Division/6_Advanced_Relational_Division.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------- 2 | -- O'reilly Online Training --------------------- 3 | -- Advanded SQL Querying - Relational Division -- 4 | -- Advanced Relationa Divisions ----------------- 5 | ------------------------------------------------- 6 | -- https://1drv.ms/u/s!ArtNt2j9rxvUyAt99JqZ_63fVdMV 7 | 8 | -- Todd's Division 9 | 10 | -- Show all candidate and jobs, where the candidate meets the job requirements 11 | 12 | -- Using SET operator 13 | SELECT DISTINCT C.Candidate, 14 | J.Job 15 | FROM Candidates AS C 16 | CROSS JOIN -- Assuming all candidates may be a fit for all jobs 17 | -- Replace with CandidateSkills AS CS INNER JOIN JobSkills As JS ON CS.Skill = JS.Skill to eliminate rows without at least one skill match 18 | Jobs AS J 19 | WHERE NOT EXISTS ( 20 | SELECT JS.Skill 21 | FROM JobSkills AS JS 22 | WHERE JS.Job = J.Job 23 | EXCEPT 24 | SELECT CS.Skill 25 | FROM CandidateSkills AS CS 26 | WHERE C.Candidate = CS.Candidate 27 | ) 28 | 29 | -- And to include only exact fits = no remainder (no additional skills), just add 30 | AND NOT EXISTS ( 31 | SELECT CS1.Skill 32 | FROM CandidateSkills AS CS1 33 | WHERE CS1.Candidate = C.Candidate 34 | EXCEPT 35 | SELECT JS1.Skill 36 | FROM JobSkills AS JS1 37 | WHERE JS1.Job = J.Job 38 | ); 39 | 40 | 41 | -- Using Counts 42 | WITH JobSkillCounts AS 43 | ( 44 | SELECT JS1.Job, 45 | COUNT(*) AS NumSkills 46 | FROM JobSkills AS JS1 47 | GROUP BY JS1.Job 48 | ) 49 | SELECT CS.Candidate, 50 | JS.Job 51 | FROM JobSkills AS JS 52 | INNER JOIN 53 | CandidateSkills AS CS 54 | ON JS.Skill = CS.Skill -- optimize the cross join 55 | INNER JOIN 56 | JobSkillCounts 57 | ON JobSkillCounts.Job = JS.Job 58 | GROUP BY CS.Candidate, JS.Job 59 | HAVING COUNT(*) = MAX(JobSkillCounts.NumSkills) 60 | ORDER BY Job, 61 | Candidate; 62 | 63 | -- Another option with NOT EXISTS and NOT IN 64 | SELECT DISTINCT JS.Job, 65 | CS.Candidate 66 | FROM JobSkills AS JS 67 | INNER JOIN 68 | CandidateSkills AS CS 69 | ON JS.Skill = CS.Skill 70 | WHERE NOT EXISTS ( 71 | SELECT NULL 72 | FROM JobSkills AS JS2 73 | WHERE JS2.Job = JS.Job 74 | AND 75 | JS2.Skill 76 | NOT IN ( -- Can replace with NOT EXISTS 77 | SELECT Skill 78 | FROM CandidateSkills AS CS2 79 | WHERE CS2.Candidate = CS.Candidate 80 | )) 81 | ORDER BY Job, 82 | Candidate; 83 | 84 | 85 | -- Another option 86 | WITH MatchedSkillCounts 87 | AS 88 | ( 89 | SELECT CS.Candidate, 90 | JS.Job, 91 | COUNT(*) AS NumMatchedSkills 92 | FROM CandidateSkills AS CS 93 | INNER JOIN 94 | JobSkills AS JS 95 | ON CS.Skill = JS.Skill 96 | GROUP BY CS.Candidate, JS.Job 97 | ), 98 | JobSkillCounts 99 | AS 100 | ( 101 | SELECT JS.Job, 102 | COUNT(*) AS NumSkills 103 | FROM JobSkills AS JS 104 | GROUP BY JS.Job 105 | ) 106 | SELECT MSC.Candidate, 107 | JSC.Job 108 | FROM MatchedSkillCounts AS MSC 109 | INNER JOIN 110 | JobSkillCounts AS JSC 111 | ON MSC.Job = JSC.Job 112 | WHERE MSC.NumMatchedSkills = JSC.NumSkills 113 | 114 | 115 | -- Romley's Division 116 | -- For each candidate and each job, show whether the candidate fits none, some, all, or more than the job requirements. 117 | 118 | -- Add some test data - a candidate with no skills 119 | INSERT INTO Candidates(Candidate) VALUES ('Inco M. Petent'); 120 | 121 | WITH CandidateJobMatch 122 | AS 123 | ( 124 | SELECT CS.Candidate, 125 | JS.Job, 126 | COUNT(*) AS CandidateJobSkillMatchCount 127 | FROM CandidateSkills AS CS 128 | INNER JOIN 129 | JobSkills AS JS 130 | ON CS.Skill = JS.Skill 131 | GROUP BY CS.Candidate, 132 | JS.Job 133 | ), 134 | JobSkillCounts 135 | AS 136 | ( 137 | SELECT JS.Job, 138 | COUNT(*) AS JobSkillCount 139 | FROM JobSkills AS JS 140 | GROUP BY JS.Job 141 | ), 142 | CandidateSkillCounts 143 | AS 144 | ( 145 | SELECT CS.Candidate, 146 | COUNT(*) AS CandidateSkillCount 147 | FROM CandidateSkills AS CS 148 | GROUP BY CS.Candidate 149 | ) 150 | SELECT DISTINCT C.Candidate, 151 | ISNULL(CJM.Job, 'All Jobs') AS Job, 152 | CASE 153 | WHEN CandidateJobSkillMatchCount = JobSkillCount 154 | AND 155 | CandidateSkillCount > CandidateJobSkillMatchCount 156 | THEN 'Over Qualified' 157 | WHEN CandidateJobSkillMatchCount = JobSkillCount 158 | AND 159 | CandidateJobSkillMatchCount = CandidateSkillCount 160 | THEN 'Perfect Fit' 161 | WHEN CandidateJobSkillMatchCount < JobSkillCount 162 | THEN 'Partial Fit' 163 | ELSE 'None' 164 | END AS FitLevel 165 | FROM Candidates AS C 166 | LEFT OUTER JOIN 167 | CandidateSkillCounts AS CSC 168 | ON C.Candidate = CSC.Candidate 169 | LEFT OUTER JOIN 170 | ( 171 | CandidateJobMatch AS CJM 172 | INNER JOIN 173 | JobSkillCounts AS JSC 174 | ON CJM.Job = JSC.Job 175 | ) 176 | ON CSC.Candidate = CJM.Candidate 177 | 178 | 179 | -- Take home exercise: 180 | -- Show all candidates and the associated jobs, 181 | -- where the candidate fits at least 2 jobs in terms of all personal skills, 182 | -- and at least 2 professional skills 183 | 184 | 185 | ------------------------------------------------------------------------------- 186 | ------------------------------------------------------------------------------- 187 | ------------------------------------------------------------------------------- 188 | 189 | 190 | 191 | -- Ordered Division 192 | -- Add Ranks to both JobSkills and CandidateSkills 193 | 194 | ALTER TABLE JobSkills 195 | ADD SkillRank TINYINT NULL; 196 | ALTER TABLE CandidateSkills 197 | ADD SkillRank TINYINT NULL; 198 | GO 199 | 200 | WITH JSkills 201 | AS 202 | ( 203 | SELECT Job, 204 | Skill, 205 | SkillRank, 206 | ROW_NUMBER() OVER (PARTITION BY Job ORDER BY Skill) AS SRank 207 | FROM JobSkills 208 | ) 209 | UPDATE JSkills 210 | SET SkillRank = SRank; 211 | 212 | -- Xi will have a perfect match to DB Architect job 213 | UPDATE CandidateSkills 214 | SET SkillRank = ( 215 | SELECT SkillRank 216 | FROM JobSkills 217 | WHERE JobSkills.Job = 'DB Architect' 218 | AND 219 | Skill = CandidateSkills.Skill 220 | ) 221 | WHERE Candidate = 'Xi'; 222 | 223 | 224 | -- All the other's wont, 225 | -- since the order for the ROW_NUMBER is DESC now 226 | 227 | WITH CSkills 228 | AS 229 | ( 230 | SELECT Candidate, 231 | Skill, 232 | SkillRank, 233 | ROW_NUMBER () OVER (PARTITION BY Candidate ORDER BY Skill DESC) AS SRank 234 | FROM CandidateSkills 235 | ) 236 | UPDATE CSkills 237 | SET SkillRank = SRank 238 | WHERE Candidate <> 'Xi' 239 | 240 | SELECT * 241 | FROM CandidateSkills 242 | ORDER BY Candidate, SkillRank; 243 | 244 | SELECT * 245 | FROM JobSkills 246 | ORDER BY Job, SkillRank; 247 | 248 | -- Find 'perfect' matches (both no remainder division, and matching order) is easy - 249 | -- Just add AND CandidateSkills.SkillRank = JobSkills.SkillRank to the predicate. 250 | -- It's logically the same as creating a skills 'SQL1', 'SQL2'... with the rank added. 251 | 252 | SELECT DISTINCT CS.Candidate, JS.Job 253 | FROM CandidateSkills AS CS 254 | INNER JOIN 255 | JobSkills AS JS 256 | ON CS.Skill = JS.Skill 257 | AND 258 | CS.SkillRank = JS.SkillRank -----<<<--- Added predicate 259 | WHERE NOT EXISTS ( 260 | SELECT NULL 261 | FROM JobSkills AS JS1 262 | WHERE JS1.Job = JS.Job 263 | AND 264 | NOT EXISTS ( 265 | SELECT NULL 266 | FROM CandidateSkills AS CS1 267 | WHERE CS1.Candidate = CS.Candidate 268 | AND 269 | CS1.Skill = JS1.Skill 270 | AND 271 | CS1.SkillRank = JS1.SkillRank -----<<<--- Added predicate 272 | ) 273 | ); 274 | 275 | -- Take home exercise: 276 | -- Find candidates that are passionate and know Python, 277 | -- and also rated Python below Passionate, 278 | -- and not necessarily as the immediate neighbor. = Only Xi 279 | 280 | 281 | 282 | 283 | 284 | 285 | 286 | 287 | 288 | 289 | 290 | 291 | 292 | 293 | 294 | 295 | 296 | 297 | 298 | 299 | 300 | 301 | 302 | 303 | 304 | WITH RequiredSkillsRanks 305 | AS 306 | ( 307 | SELECT * 308 | FROM (VALUES ('Passionate',1), ('Python',2)) AS RequiredSkills(Skill, SkillRank) 309 | ), 310 | PotentialCandidates 311 | AS 312 | ( 313 | SELECT CS.Candidate, 314 | Skill, 315 | SkillRank 316 | FROM CandidateSkills AS CS 317 | WHERE Skill IN (SELECT Skill FROM RequiredSkillsRanks) 318 | AND 319 | NOT EXISTS ( 320 | SELECT NULL 321 | FROM RequiredSkillsRanks AS RS 322 | WHERE NOT EXISTS ( 323 | SELECT NULL 324 | FROM CandidateSkills AS CS1 325 | WHERE CS.Candidate = CS1.Candidate 326 | AND 327 | CS1.Skill = RS.Skill 328 | ) 329 | ) 330 | ), 331 | -- SELECT * FROM PotentialCandidates 332 | -- Assign ROW_NUMBER to relevant skills 333 | PotentialCandidateRanks 334 | AS 335 | ( 336 | SELECT PC.Candidate, 337 | PC.Skill, 338 | RS.SkillRank, 339 | ROW_NUMBER () OVER (PARTITION BY Candidate ORDER BY PC.SkillRank) AS NewSkillRank 340 | FROM PotentialCandidates AS PC 341 | INNER JOIN 342 | RequiredSkillsRanks AS RS 343 | ON RS.Skill = PC.Skill 344 | ) 345 | SELECT DISTINCT Candidate 346 | FROM PotentialCandidateRanks 347 | WHERE SkillRank = NewSkillRank 348 | -------------------------------------------------------------------------------- /Relational-Division/Readme.txt: -------------------------------------------------------------------------------- 1 | Demo code for O'Reilly training, "Advanced SQL Series: Relational Division". 2 | -------------------------------------------------------------------------------- /SQL Server Fundamentals/Basic Demo Database.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------- 2 | -- O'Reilly Online Training ---------- 3 | -- Getting Started with SQL Server --- 4 | -- Basic Demos Database -------------- 5 | -------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ----------------------------------------------------------------------------------------- 8 | 9 | /* 10 | ██████╗ █████╗ ███████╗██╗ ██████╗ ██████╗ ███████╗███╗ ███╗ ██████╗ ███████╗ 11 | ██╔══██╗██╔══██╗██╔════╝██║██╔════╝ ██╔══██╗██╔════╝████╗ ████║██╔═══██╗██╔════╝ 12 | ██████╔╝███████║███████╗██║██║ ██║ ██║█████╗ ██╔████╔██║██║ ██║███████╗ 13 | ██╔══██╗██╔══██║╚════██║██║██║ ██║ ██║██╔══╝ ██║╚██╔╝██║██║ ██║╚════██║ 14 | ██████╔╝██║ ██║███████║██║╚██████╗ ██████╔╝███████╗██║ ╚═╝ ██║╚██████╔╝███████║ 15 | ╚═════╝ ╚═╝ ╚═╝╚══════╝╚═╝ ╚═════╝ ╚═════╝ ╚══════╝╚═╝ ╚═╝ ╚═════╝ ╚══════╝ 16 | */ 17 | 18 | /* 19 | USE master; 20 | GO 21 | 22 | DROP DATABASE IF EXISTS BasicDemos; 23 | CREATE DATABASE BasicDemos; 24 | GO 25 | */ 26 | 27 | USE BasicDemos; 28 | GO 29 | 30 | CREATE TABLE Customers ( 31 | Customer VARCHAR(20) NOT NULL 32 | PRIMARY KEY, 33 | Country VARCHAR(20) NULL 34 | ); 35 | 36 | CREATE TABLE Items ( 37 | Item VARCHAR(20) NOT NULL 38 | PRIMARY KEY 39 | ); 40 | 41 | CREATE TABLE Orders ( 42 | OrderID INTEGER NOT NULL 43 | PRIMARY KEY, 44 | OrderDate DATE NOT NULL, 45 | Customer VARCHAR(20) NOT NULL 46 | REFERENCES Customers(Customer) 47 | ); 48 | 49 | CREATE TABLE OrderItems ( 50 | OrderID INTEGER NOT NULL 51 | REFERENCES Orders(OrderID), 52 | Item VARCHAR(20) NOT NULL 53 | REFERENCES Items(Item), 54 | Quantity INTEGER NOT NULL 55 | CHECK (Quantity > 0), 56 | Price DECIMAL(9,2) NOT NULL 57 | CHECK (Price >=0), 58 | PRIMARY KEY (OrderID, Item) 59 | ); 60 | 61 | INSERT INTO Customers (Customer, Country) 62 | VALUES ('Dave', 'USA'), ('John', 'USA'), ('Gerald', 'Canada'), ('Jose', 'Peru'), ('Tim', NULL); 63 | 64 | INSERT INTO Items (Item) 65 | VALUES ('Pencil'), ('Pen'), ('Marker'), ('Notebook'), ('Ruler'); 66 | 67 | INSERT INTO Orders (OrderID, OrderDate, Customer) 68 | VALUES (1, '20180101', 'Dave'), (2, '20180102', 'John'), (3, '20180103', 'Gerald'), (4, '20180109', 'John'); 69 | 70 | INSERT INTO OrderItems (OrderID, Item, Quantity, Price) 71 | VALUES (1, 'Pen', 2, 1.5), (1, 'Pencil', 1, 0.75), 72 | (2, 'Marker', 3, 3), 73 | (3, 'Pen', 1, 1.5), (3, 'Marker', 1, 3), 74 | (4, 'Pen', 4, 1.5), (4, 'Pencil', 2, 1.25), (4, 'Ruler', 2, 3); 75 | 76 | -- END -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 1-1.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'Reilly Online Training --------- 3 | -- Getting Started with SQL Server -- 4 | -- Module 1.1: Installation --------- 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- Installation walk-through 10 | -- Tooling overview 11 | 12 | /* 13 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 14 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 15 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 16 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 17 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 18 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 19 | 20 | Download and install SQL Server 2017 Express or Developer Edition from https://www.microsoft.com/en-us/sql-server/sql-server-downloads 21 | * NOTE: Enable SQL Authentication on the security settings page and choose a password for the sa account. 22 | * NOTE2: If installing Express edition, change the instance installation to a default instance. 23 | See Installation Guide @ https://docs.microsoft.com/en-us/sql/database-engine/install-windows/install-sql-server 24 | Download one (or more) client tool: 25 | SSMS: https://docs.microsoft.com/en-us/sql/ssms/download-sql-server-management-studio-ssms 26 | Data Studio: https://docs.microsoft.com/en-us/sql/azure-data-studio/download 27 | Download and install SQLCMD if missing 28 | SQLCMD 14: https://www.microsoft.com/en-us/download/details.aspx?id=53591 29 | 30 | If for any reason you are unable to install SQL Server and have no access to a network or cloud instance, use https://db-fiddle.uk/ 31 | */ 32 | 33 | ---------------------------------------------------------------------------------------------------------- 34 | ---------------------------------------------------------------------------------------------------------- 35 | 36 | /* 37 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 38 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 39 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 40 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██╔═══╝ 41 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ███████╗ 42 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚══════╝ 43 | 44 | For local installs, launch SSMS and connect to your local instance. 45 | Choose Windows Authentication as you are a local administrator on your Windows PC (otherwise you wouldn't have been able to install it...). 46 | Open a new editor window using CTRL + N. 47 | Type "SELECT 'Hello, World!';" and click Execute (Green triangle icon button) or hit F5. 48 | Make sure you see the output in the lower pane. 49 | 50 | (No column name) 51 | ---------------- 52 | Hello, World! 53 | 54 | Launch SQLCMD and connect to your local instance. 55 | At the prompt type "SELECT 'Hello, World!';" GO . 56 | Make sure you get the result: 57 | 58 | ------------- 59 | Hello, World! 60 | (1 rows affected) 61 | 62 | Congratulations! 63 | You have successfully installed SQL Server and connected both tools! 64 | 65 | If using db-fiddle: 66 | Replace the text "select version();" with "SELECT 'Hello, World!';" and click Run. 67 | Make sure you see the result 68 | (No column name) 69 | ---------------- 70 | Hello, World! 71 | */ 72 | 73 | ---------------------------------------------------------------------------------------------------------- 74 | ---------------------------------------------------------------------------------------------------------- 75 | 76 | /* 77 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 78 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 79 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 80 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 81 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 82 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 83 | 84 | Additional Reading: 85 | ------------------- 86 | https://en.wikipedia.org/wiki/Database 87 | https://en.wikipedia.org/wiki/Relational_model 88 | https://en.wikipedia.org/wiki/SQL 89 | https://en.wikipedia.org/wiki/Microsoft_SQL_Server 90 | 91 | Tools: 92 | ------ 93 | https://docs.microsoft.com/en-us/sql/ssms/download-sql-server-management-studio-ssms 94 | https://docs.microsoft.com/en-us/sql/azure-data-studio/download 95 | https://www.microsoft.com/en-us/download/details.aspx?id=53591 96 | https://db-fiddle.uk/ <-- Preferred online tool 97 | https://www.db-fiddle.com/ 98 | http://sqlfiddle.com 99 | 100 | Cloud providers: 101 | ---------------- 102 | https://azure.microsoft.com/en-us/services/sql-database/ 103 | https://docs.microsoft.com/en-us/azure/sql-database/sql-database-managed-instance 104 | https://azure.microsoft.com/en-us/services/virtual-machines/sql-server/ 105 | https://aws.amazon.com/rds/sqlserver/ 106 | https://cloud.google.com/sql-server/ 107 | */ 108 | -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 1-2.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'Reilly Online Training --------- 3 | -- Getting Started with SQL Server -- 4 | -- Module 1.2: Creating Databases --- 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- CREATE DATABASE BasicDemos; 10 | -- Create / manage databases with SSMS 11 | -- BACKUP, Defrag, Export 12 | 13 | /* 14 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 15 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 16 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 17 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 18 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 19 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 20 | 21 | Using either SSMS or SQLCMD, create a new database named "BasicDemos". 22 | * NOTE: db-fiddle users skip this phase as you don't have permissions to create databases. 23 | You can only use the default database provided by the service. 24 | 25 | With SSMS, right click "Databases", choose "New database" and type BasicDemos" for the database name. 26 | View the options tabs but don't change anything, and click "OK". 27 | Alternatively, use the query tool editor window and execute the query: */ 28 | 29 | CREATE DATABASE BasicDemos; 30 | 31 | /* 32 | Open a new editor window in SSMS by right clicking "BasicDemos" -> and click "New Query". 33 | Copy / paste the text, or just open the "Basic Demos Database.sql" file directly with SSMS from the "File" -> "Open" -> "File" menu (CTRL + O). 34 | * NOTE: db-fiddle users copy and paste the entire script to the db-fiddle window and execute it. 35 | Skip the CREATE and USE statements. 36 | 37 | Make sure execution succeeds with no errors. 38 | Take a look at the statements, and write down any questions you have. 39 | We will cover these in the next section, but they are mostly plain English. 40 | 41 | You can close the editor window with the database script. 42 | * db-fiddle users must leave the script in the first text box, it will be executed every time you click 'Run'. 43 | */ 44 | 45 | ------------------------------------------------------------------------------------------------------ 46 | ------------------------------------------------------------------------------------------------------ 47 | 48 | /* 49 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 50 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 51 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 52 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██╔═══╝ 53 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ███████╗ 54 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚══════╝ 55 | */ 56 | 57 | -- Execute the following query in a new SSMS editor or using SQLCMD: 58 | -- db-fiddle users must use a new text box and keep the original script in place. 59 | 60 | SELECT * FROM Customers; 61 | 62 | -- Expected Result: 63 | /* 64 | Customer | Country 65 | ------------------------ 66 | Dave | USA 67 | John | USA 68 | Gerald | Canada 69 | Jose | Peru 70 | Tim | 71 | */ 72 | 73 | ------------------------------------------------------------------------------------------------------ 74 | ------------------------------------------------------------------------------------------------------ 75 | 76 | /* 77 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 78 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 79 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 80 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ╚═══██╗ 81 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██████╔╝ 82 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═════╝ 83 | 84 | *NOTE: db-fiddle users skip this exercise 85 | */ 86 | 87 | -- Backup the BasicDemos database using SSMS: 88 | -- Right click "BasicDemos" and choose "Tasks" -> "Backup". 89 | -- Copy or change the destination folder and file name. 90 | -- NOTE: You can't edit the destination file name, you need to remove it and add a new one to backup to a different location. 91 | -- The location shown is the default chosen at installation. 92 | 93 | -- Open a new query tool editor window and execute the following statements: 94 | ALTER TABLE Customers REBUILD; 95 | 96 | -- Right click "BasicDemos", choose "Tasks" -> "Generate Scripts" and review the wizard's options. 97 | -- Feel free to execute, and review the results. 98 | 99 | -- Right click "BasicDemos", choose "Tasks" -> "Export Data" and review the wizard's options. 100 | -- Feel free to execute and review the results. 101 | ------------------------------------------------------------------------------------------------------ 102 | ------------------------------------------------------------------------------------------------------ 103 | 104 | /* 105 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 106 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 107 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 108 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 109 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 110 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 111 | 112 | Additional Reading: 113 | ------------------- 114 | https://docs.microsoft.com/en-us/sql/t-sql/statements/create-database-transact-sql 115 | https://docs.microsoft.com/en-us/sql/t-sql/statements/alter-database-transact-sql 116 | https://docs.microsoft.com/en-us/sql/t-sql/statements/drop-database-transact-sql 117 | https://docs.microsoft.com/en-us/sql/ssms/sql-server-management-studio-ssms 118 | https://docs.microsoft.com/en-us/sql/azure-data-studio/what-is 119 | https://docs.microsoft.com/en-us/sql/t-sql/statements/backup-transact-sql 120 | https://docs.microsoft.com/en-us/sql/t-sql/statements/restore-statements-transact-sql 121 | https://docs.microsoft.com/en-us/sql/integration-services/import-export-data/import-and-export-data-with-the-sql-server-import-and-export-wizard 122 | https://docs.microsoft.com/en-us/sql/ssms/scripting/generate-and-publish-scripts-wizard 123 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 1-3.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'Reilly Online Training --------- 3 | -- Getting Started with SQL Server -- 4 | -- Module 1.3: Accessing Objects ---- 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | CREATE LOGIN OReilly WITH PASSWORD = 'some_password'; 10 | CREATE SCHEMA OReilly; 11 | CREATE USER OReilly FOR LOGIN OReilly WITH DEFAULT_SCHEMA = OReilly; 12 | CREATE TABLE OReilly.Customers (Customer varchar(20), Country varchar(20)); 13 | -- Using dbo schema 14 | SELECT * FROM Customers; 15 | SELECT * FROM OReilly.Customers; 16 | -- assigning permissions (DCL) 17 | 18 | /* 19 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 20 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 21 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 22 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 23 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 24 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 25 | 26 | * NOTE: db-fiddle users skip this exercise 27 | */ 28 | 29 | -- In SSMS or SQLCMD, create a new login called OReilly with a password. 30 | -- Use the following statement, or the GUI as you prefer. 31 | 32 | CREATE LOGIN OReilly WITH PASSWORD = 'some_password'; 33 | 34 | -- In SSMS or SQLCMD, create a new Schema called OReilly. 35 | -- Use the following statement, or the GUI as you prefer. 36 | -- * NOTE: Make sure your connection is set to the BasicDemos database context or the schema will be created in the wrong database! 37 | 38 | CREATE SCHEMA OReilly; 39 | 40 | -- Create a new user called "OReilly" using the query tool editor or SQLCMD. 41 | 42 | CREATE USER OReilly FOR LOGIN OReilly WITH DEFAULT_SCHEMA = OReilly; 43 | 44 | ------------------------------------------------------------------------------------------------------ 45 | ------------------------------------------------------------------------------------------------------ 46 | 47 | /* 48 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 49 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 50 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 51 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██╔═══╝ 52 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ███████╗ 53 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚══════╝ 54 | 55 | * NOTE: db-fiddle users skip this exercise 56 | */ 57 | 58 | -- In SSMS, right click Databases and choose "Refresh". 59 | -- click "Databases" and expand "BasicDemos". 60 | -- Expand "Security" -> "Schemas". 61 | -- Right click "Schemas" and "New Schema". View the options but don't save, cancel. 62 | -- In SSMS or SQLCMD execute the queries: 63 | 64 | CREATE TABLE OReilly.Customers (Customer varchar(20), Country varchar(20)); 65 | 66 | INSERT INTO OReilly.Customers VALUES ('your name', 'your Country'); 67 | 68 | ------------------------------------------------------------------------------------------------------ 69 | ------------------------------------------------------------------------------------------------------ 70 | 71 | /* 72 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 73 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 74 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 75 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ╚═══██╗ 76 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██████╔╝ 77 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═════╝ 78 | 79 | *NOTE: db-fiddle users skip this exercise 80 | */ 81 | 82 | 83 | -- Launch a new SQLCMD window using the following syntax to log on as the OReilly user: 84 | 85 | SQLCMD -U OReilly -P some_password -d BasicDemos 86 | 87 | -- Execute the following query: 88 | 89 | SELECT * FROM Customers; 90 | -- Remember you must add a 'GO' indicator to tell the tool to execute the batch 91 | 92 | -- Can you explain the result? 93 | 94 | -- Execute the following query in SSMS (using the administrative connection, not the OReilly user....) 95 | 96 | GRANT SELECT ON OReilly.Customers TO OReilly; 97 | 98 | -- Execute the previous query again in SQLCMD. 99 | 100 | SELECT * FROM Customers; 101 | 102 | -- Execute the following query: 103 | SELECT * FROM dbo.Customers; 104 | 105 | -- Can you explain the result? 106 | -- Can you fix it? 107 | -- Go ahead and do it... 108 | 109 | ------------------------------------------------------------------------------------------------------ 110 | ------------------------------------------------------------------------------------------------------ 111 | 112 | /* 113 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 114 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 115 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 116 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 117 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 118 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 119 | 120 | Additional Reading: 121 | ------------------- 122 | https://docs.microsoft.com/en-us/sql/t-sql/statements/create-database-transact-sql 123 | https://docs.microsoft.com/en-us/sql/relational-databases/security/authentication-access/create-a-database-schema 124 | https://docs.microsoft.com/en-us/sql/relational-databases/security/security-center-for-sql-server-database-engine-and-azure-sql-database 125 | https://docs.microsoft.com/en-us/sql/t-sql/statements/create-schema-transact-sql 126 | https://docs.microsoft.com/en-us/sql/t-sql/statements/create-user-transact-sql 127 | https://docs.microsoft.com/en-us/sql/t-sql/statements/create-role-transact-sql 128 | https://docs.microsoft.com/en-us/sql/t-sql/statements/grant-transact-sql 129 | https://docs.microsoft.com/en-us/sql/t-sql/statements/revoke-transact-sql 130 | https://docs.microsoft.com/en-us/sql/t-sql/statements/deny-transact-sql 131 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 2-1.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'Reilly Online Training --------- 3 | -- Getting Started with SQL Server -- 4 | -- Module 2.1: Creating Tables ------ 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- CREATE TABLE / ALTER TABLE DDL and SSMS 10 | 11 | /* 12 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 13 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 14 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 15 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 16 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 17 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 18 | 19 | * NOTE: db-fiddle users must use SQL code to perform these tasks, no GUI for you - extra challenge bonus points! 20 | */ 21 | 22 | -- In SSMS, expand "Databases" -> "BasicDemos" -> "Tables". 23 | -- Right click on OReilly.Customers and click "Design". 24 | -- NOTE: you might need to refresh SSMS object explorer's tables node by right click -> "Refresh" for it to show. 25 | 26 | -- Add a third column named "Phone" with a data type of character varying and a length of 10. 27 | -- Click "Save" or hit CTRL + S. 28 | 29 | -- Add a 4th column named "Gender" with a data type of character and a length of 2 (we are inclusive of gender fluidity). 30 | -- DON'T save yet! 31 | -- On the toolbar, click "Table Designer" and choose "Generate change script" and review the script. 32 | -- Copy the script and paste it into a new SSMS query tool editor window. 33 | -- Click 'No'. 34 | -- Execute the script in SSMS, refresh the object explorer pane view. 35 | 36 | -- What's the difference between executing a statement in SSMS query tool and executing it from the GUI wizard? 37 | 38 | ------------------------------------------------------------------------------------------------------ 39 | ------------------------------------------------------------------------------------------------------ 40 | 41 | /* 42 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 43 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 44 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 45 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 46 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 47 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 48 | 49 | Additional Reading: 50 | ------------------- 51 | https://docs.microsoft.com/en-us/sql/t-sql/statements/create-table-transact-sql 52 | https://docs.microsoft.com/en-us/sql/t-sql/statements/alter-table-transact-sql 53 | https://docs.microsoft.com/en-us/sql/t-sql/statements/drop-table-transact-sql 54 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 2-2.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'Reilly Online Training --------- 3 | -- Getting Started with SQL Server -- 4 | -- Module 2.2: Constraints ---------- 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- Primary keys 10 | -- Unique constraints 11 | -- NULL constraints 12 | -- Foreign Keys 13 | -- Check constraints 14 | 15 | /* 16 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 17 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 18 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 19 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 20 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 21 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 22 | 23 | * NOTE: db-fiddle users - from now on, (almost...) no more restrictions for you in this training! 24 | */ 25 | 26 | -- Alter the OReilly.Customers table so that 27 | -- 1. Customer name will identify each Customer. 28 | -- 2. Country name will be mandatory. 29 | -- USE THE DOCUMENTATION TO FIGURE OUT THE SYNTAX - See resources section below. 30 | -- **** Scroll down for a solution 31 | 32 | -- 33 | 34 | -- 35 | 36 | -- 37 | 38 | -- 39 | 40 | -- 41 | 42 | -- 43 | 44 | -- 45 | 46 | -- 47 | 48 | -- 49 | 50 | -- 51 | 52 | /* 53 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 54 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 55 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 56 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 57 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 58 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 59 | */ 60 | 61 | 62 | -- 63 | 64 | -- 65 | 66 | -- 67 | 68 | -- 69 | 70 | -- 71 | 72 | -- 73 | 74 | ALTER TABLE OReilly.Customers ALTER COLUMN Customer VARCHAR(10) NOT NULL; 75 | 76 | ALTER TABLE OReilly.Customers ADD CONSTRAINT PK_Customers PRIMARY KEY(Customer); 77 | 78 | ALTER TABLE OReilly.Customers ALTER COLUMN Country VARCHAR(20) NOT NULL; 79 | 80 | /* 81 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 82 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 83 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 84 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██╔═══╝ 85 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ███████╗ 86 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚══════╝ 87 | */ 88 | 89 | -- Review the basicdemos db scripts CREATE TABLE statements and see that they make sense. 90 | -- Write down your questions, we will review this together after this exercise. 91 | 92 | /* 93 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 94 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 95 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 96 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 97 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 98 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 99 | 100 | Additional Reading: 101 | ------------------- 102 | https://docs.microsoft.com/en-us/sql/relational-databases/tables/primary-and-foreign-key-constraints 103 | https://docs.microsoft.com/en-us/sql/relational-databases/tables/unique-constraints-and-check-constraints 104 | https://docs.microsoft.com/en-us/sql/t-sql/statements/create-table-transact-sql 105 | https://docs.microsoft.com/en-us/sql/t-sql/statements/alter-table-transact-sql 106 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 2-3.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'Reilly Online Training --------- 3 | -- Getting Started with SQL Server -- 4 | -- Module 2.3: Data Types ----------- 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- Data type families 10 | -- Data type conversions 11 | 12 | /* 13 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 14 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 15 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 16 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 17 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 18 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 19 | */ 20 | 21 | -- Change the phone column in OReilly.Customers to an integer instead of a string. 22 | -- You can use either T-SQL queries, or the GUI table designer. 23 | -- Try to insert a row for customer Dan from Poland, a male, with a phone value of '123-456-0891' 24 | -- Can you explain the result? 25 | -- Add another column to the table for the Customer's birth date. 26 | -- Add a constraint to this column as you see fit to enforce a reasonable business rule of your choice. 27 | -- **** Scroll down for a suggested solution 28 | 29 | -- 30 | 31 | -- 32 | 33 | -- 34 | 35 | -- 36 | 37 | -- 38 | 39 | -- 40 | 41 | -- 42 | 43 | -- 44 | 45 | -- 46 | 47 | -- 48 | 49 | /* 50 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 51 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 52 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 53 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 54 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 55 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 56 | */ 57 | 58 | 59 | -- 60 | 61 | -- 62 | 63 | -- 64 | 65 | -- 66 | 67 | -- 68 | 69 | -- 70 | 71 | ALTER TABLE OReilly.Customers 72 | ALTER COLUMN phone INT; 73 | 74 | INSERT INTO OReilly.Customers (Customer, Country, Phone, Gender) 75 | VALUES ('Dan', 'Poland', '123-456-0987', 'M'); 76 | 77 | -- Can you explain why you get this result? 78 | 79 | ALTER TABLE OReilly.Customers 80 | ADD birthdate DATE NULL CHECK (birthdate < '20010101'); 81 | 82 | -- CHECK constraint just an example of limiting Customers to be born in the year 2000 or earlier. 83 | -- You can make up your own... 84 | 85 | /* 86 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 87 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 88 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 89 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 90 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 91 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 92 | 93 | Additional Reading: 94 | ------------------- 95 | https://docs.microsoft.com/en-us/sql/t-sql/data-types/data-types-transact-sql 96 | https://docs.microsoft.com/en-us/sql/t-sql/statements/create-type-transact-sql 97 | https://docs.microsoft.com/en-us/sql/t-sql/data-types/data-type-conversion-database-engine 98 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 3-1.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'Reilly Online Training --------- 3 | -- Getting Started with SQL Server -- 4 | -- Module 3.1: DML/DQL -------------- 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- INSERT, UPDATE, DELETE 10 | 11 | /* 12 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 13 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 14 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 15 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 16 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 17 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 18 | */ 19 | 20 | -- Add the following data to the OReilly.Customers table: 21 | -- New Customer Jim is a male, he is from Canada, born on Jan 2nd 1984, and his phone number is 12345612, 22 | -- New Customer Jill is a female, she is from Germany, born on July 3rd 1991, and her phone number is 09865409 23 | 24 | /* 25 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██████╗ 26 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ╚════██╗ 27 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ █████╔╝ 28 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██╔═══╝ 29 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ███████╗ 30 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚══════╝ 31 | */ 32 | 33 | -- We had an error in the system, all Customer's birth date are 1 day off, we need to adjust them to the day after the current day. 34 | -- Use the documentation (hint: https://docs.microsoft.com/en-us/sql/t-sql/functions/dateadd-transact-sql) 35 | -- **** Scroll down for solutions to both exercises 36 | 37 | -- 38 | 39 | -- 40 | 41 | -- 42 | 43 | -- 44 | 45 | -- 46 | 47 | -- 48 | 49 | -- 50 | 51 | -- 52 | 53 | -- 54 | 55 | -- 56 | 57 | /* 58 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 59 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 60 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 61 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 62 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 63 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 64 | */ 65 | 66 | 67 | -- 68 | 69 | -- 70 | 71 | -- 72 | 73 | -- 74 | 75 | -- 76 | 77 | -- 78 | 79 | INSERT INTO OReilly.Customers(Customer, Country, phone, gender, birthdate) 80 | VALUES ('Jim', 'Canada', 12345612, 'M', '19840102'), 81 | ('Jill', 'Germany', 9865409, 'F', '19910703'); 82 | 83 | UPDATE OReilly.Customers 84 | SET birthdate = DATEADD(DAY, 1, birthdate); 85 | 86 | /* 87 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 88 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 89 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 90 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 91 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 92 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 93 | 94 | Additional Reading: 95 | ------------------- 96 | https://docs.microsoft.com/en-us/sql/t-sql/statements/insert-transact-sql 97 | https://docs.microsoft.com/en-us/sql/t-sql/queries/update-transact-sql 98 | https://docs.microsoft.com/en-us/sql/t-sql/statements/delete-transact-sql 99 | https://docs.microsoft.com/en-us/sql/t-sql/queries/select-transact-sql 100 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 3-2.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'Reilly Online Training --------- 3 | -- Getting Started with SQL Server -- 4 | -- Module 3.2: SELECT --------------- 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- SELECT processing order 10 | 11 | /* 12 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 13 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 14 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 15 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 16 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 17 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 18 | */ 19 | 20 | -- No hands-on exercise, just read the first part of the Wikipedia page link below. 21 | -- We will learn more of this concept later. 22 | 23 | /* 24 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 25 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 26 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 27 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 28 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 29 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 30 | 31 | Additional Reading: 32 | ------------------- 33 | https://en.wikipedia.org/wiki/SQL_syntax#Queries 34 | https://www.itprotoday.com/sql-server/logical-query-processing-what-it-and-what-it-means-you 35 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 3-3.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'Reilly Online Training --------- 3 | -- Getting Started with SQL Server -- 4 | -- Module 3.3: JOINs ---------------- 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- CROSS JOIN, INNER JOIN, OUTER JOIN 10 | 11 | /* 12 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 13 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 14 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 15 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 16 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 17 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 18 | */ 19 | 20 | -- Write a query that produces the following result set: 21 | -- Note - order of the rows is irrelevant 22 | /* 23 | Item | OrderID | Quantity 24 | -------------------------------- 25 | Pen | 1 | 2 26 | Pencil | 1 | 1 27 | Marker | 2 | 3 28 | Marker | 3 | 1 29 | Pen | 3 | 1 30 | Pen | 4 | 4 31 | Pencil | 4 | 2 32 | Ruler | 4 | 2 33 | Notebook| NULL | NULL 34 | */ 35 | 36 | -- **** Scroll down for solution 37 | 38 | -- 39 | 40 | -- 41 | 42 | -- 43 | 44 | -- 45 | 46 | -- 47 | 48 | -- 49 | 50 | -- 51 | 52 | -- 53 | 54 | -- 55 | 56 | -- 57 | 58 | /* 59 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 60 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 61 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 62 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 63 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 64 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 65 | */ 66 | 67 | -- 68 | 69 | -- 70 | 71 | -- 72 | 73 | -- 74 | 75 | -- 76 | 77 | -- 78 | 79 | SELECT I.Item, OI.OrderID, OI.Quantity 80 | FROM Items AS I 81 | LEFT OUTER JOIN 82 | OrderItems AS OI 83 | ON I.Item = OI.Item; 84 | 85 | /* 86 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 87 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 88 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 89 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 90 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 91 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 92 | 93 | Additional Reading: 94 | ------------------- 95 | https://docs.microsoft.com/en-us/sql/t-sql/queries/from-transact-sql 96 | https://www.itprotoday.com/sql-server/logical-query-processing-clause-and-joins 97 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 3-4.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------- 2 | -- O'Reilly Online Training ---------- 3 | -- Getting Started with SQL Server --- 4 | -- Module 3.4: Filtering & Grouping -- 5 | -------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- WHERE and NULLs 10 | -- GROUP BY and HAVING 11 | -- Logical limitations 12 | 13 | /* 14 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 15 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 16 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 17 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 18 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 19 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 20 | */ 21 | 22 | -- Write a query that produces the following result: 23 | /* 24 | Country | NumberOfCustomers 25 | ----------------------------- 26 | Canada | 1 27 | Peru | 1 28 | USA | 2 29 | */ 30 | 31 | -- **** Scroll down for solution 32 | 33 | -- 34 | 35 | -- 36 | 37 | -- 38 | 39 | -- 40 | 41 | -- 42 | 43 | -- 44 | 45 | -- 46 | 47 | -- 48 | 49 | -- 50 | 51 | -- 52 | 53 | /* 54 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 55 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 56 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 57 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 58 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 59 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 60 | */ 61 | 62 | -- 63 | 64 | -- 65 | 66 | -- 67 | 68 | -- 69 | 70 | -- 71 | 72 | -- 73 | 74 | SELECT Country, COUNT(*) AS NumberOfCustomers 75 | FROM Customers 76 | WHERE Country IS NOT NULL 77 | GROUP BY Country; 78 | 79 | /* 80 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 81 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 82 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 83 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 84 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 85 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 86 | 87 | Additional Reading: 88 | ------------------- 89 | https://docs.microsoft.com/en-us/sql/t-sql/queries/where-transact-sql 90 | https://docs.microsoft.com/en-us/sql/t-sql/queries/select-group-by-transact-sql 91 | https://docs.microsoft.com/en-us/sql/t-sql/queries/select-having-transact-sql 92 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 4-1.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'Reilly Online Training --------- 3 | -- Getting Started with SQL Server -- 4 | -- Module 4.1: Indexing ------------- 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- Indexes and execution plans 10 | 11 | /* 12 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 13 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 14 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 15 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 16 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 17 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 18 | */ 19 | 20 | -- Create an index that will benefit the following query: 21 | SELECT * FROM Customers WHERE Country = 'USA'; 22 | 23 | -- **** Scroll down for solution 24 | 25 | -- 26 | 27 | -- 28 | 29 | -- 30 | 31 | -- 32 | 33 | -- 34 | 35 | -- 36 | 37 | -- 38 | 39 | -- 40 | 41 | -- 42 | 43 | -- 44 | 45 | /* 46 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 47 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 48 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 49 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 50 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 51 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 52 | */ 53 | 54 | -- 55 | 56 | -- 57 | 58 | -- 59 | 60 | -- 61 | 62 | -- 63 | 64 | -- 65 | 66 | -- 67 | CREATE INDEX Index1 ON Customers(Country); 68 | 69 | -- Can you prove that it does help the query? 70 | 71 | /* 72 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 73 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 74 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 75 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 76 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 77 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 78 | 79 | Additional Reading: 80 | ------------------- 81 | https://docs.microsoft.com/en-us/sql/relational-databases/sql-server-index-design-guide 82 | https://docs.microsoft.com/en-us/sql/t-sql/statements/create-index-transact-sql 83 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 4-2.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------- 2 | -- O'Reilly Online Training ----------- 3 | -- Getting Started with SQL Server ---- 4 | -- Module 4.2: Operators & functions -- 5 | --------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- Showcase common operators and functions 10 | 11 | /* 12 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 13 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 14 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 15 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 16 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 17 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 18 | */ 19 | 20 | -- Write a query that returns the following result: 21 | /* 22 | Customer | Country | OrderMonth | OrderYear 23 | ---------------------------------------------------- 24 | Dave | USA | 1 | 2018 25 | John | USA | 1 | 2018 26 | Gerald | Canada | 1 | 2018 27 | John | USA | 1 | 2018 28 | */ 29 | 30 | -- Hint - see https://docs.microsoft.com/en-us/sql/t-sql/functions/datepart-transact-sql 31 | https://docs.microsoft.com/en-us/sql/t-sql/functions/month-transact-sql 32 | https://docs.microsoft.com/en-us/sql/t-sql/functions/year-transact-sql 33 | 34 | -- **** Scroll down for solution 35 | 36 | -- 37 | 38 | -- 39 | 40 | -- 41 | 42 | -- 43 | 44 | -- 45 | 46 | -- 47 | 48 | -- 49 | 50 | -- 51 | 52 | -- 53 | 54 | -- 55 | 56 | /* 57 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 58 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 59 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 60 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 61 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 62 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 63 | */ 64 | 65 | -- 66 | 67 | -- 68 | 69 | -- 70 | 71 | -- 72 | 73 | -- 74 | 75 | -- 76 | 77 | SELECT C.Customer, 78 | COALESCE(Country, 'N/A') as Country, 79 | MONTH (O.OrderDate) AS OrderMonth, 80 | YEAR (O.OrderDate) AS OrderYear 81 | FROM Customers AS C 82 | INNER JOIN 83 | Orders AS O 84 | ON C.Customer = O.Customer; 85 | 86 | /* 87 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 88 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 89 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 90 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 91 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 92 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 93 | 94 | Additional Reading: 95 | ------------------- 96 | https://docs.microsoft.com/en-us/sql/t-sql/functions/functions 97 | https://docs.microsoft.com/en-us/sql/t-sql/language-elements/operators-transact-sql 98 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Module 4-3.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------- 2 | -- O'Reilly Online Training --------- 3 | -- Getting Started with SQL Server -- 4 | -- Module 4.3: Programming Objects -- 5 | ------------------------------------- 6 | -- https://github.com/ami-levin/OReilly-Training/tree/master/SQL%20Server%20Fundamentals 7 | ---------------------------------------------------------------------------------------- 8 | 9 | -- Creating views, stored procedures, triggers and functions 10 | 11 | /* 12 | ███████╗██╗ ██╗███████╗██████╗ ██████╗██╗███████╗███████╗ ██╗ 13 | ██╔════╝╚██╗██╔╝██╔════╝██╔══██╗██╔════╝██║██╔════╝██╔════╝ ███║ 14 | █████╗ ╚███╔╝ █████╗ ██████╔╝██║ ██║███████╗█████╗ ╚██║ 15 | ██╔══╝ ██╔██╗ ██╔══╝ ██╔══██╗██║ ██║╚════██║██╔══╝ ██║ 16 | ███████╗██╔╝ ██╗███████╗██║ ██║╚██████╗██║███████║███████╗ ██║ 17 | ╚══════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═════╝╚═╝╚══════╝╚══════╝ ╚═╝ 18 | */ 19 | 20 | -- Create a new table called 'logger' with the following structure: 21 | -- EventTime DATETIME, TableName VARCHAR(20) 22 | 23 | -- Create a trigger on the Customers table to log any insert to the Customers table in the log table. 24 | -- Test it by adding a new Customer and verifying it is logged. 25 | 26 | -- **** Scroll down for solution 27 | 28 | -- 29 | 30 | -- 31 | 32 | -- 33 | 34 | -- 35 | 36 | -- 37 | 38 | -- 39 | 40 | -- 41 | 42 | -- 43 | 44 | -- 45 | 46 | -- 47 | 48 | /* 49 | ███████╗██████╗ ██████╗ ██╗██╗ ███████╗██████╗ █████╗ ██╗ ███████╗██████╗ ████████╗██╗ 50 | ██╔════╝██╔══██╗██╔═══██╗██║██║ ██╔════╝██╔══██╗ ██╔══██╗██║ ██╔════╝██╔══██╗╚══██╔══╝██║ 51 | ███████╗██████╔╝██║ ██║██║██║ █████╗ ██████╔╝ ███████║██║ █████╗ ██████╔╝ ██║ ██║ 52 | ╚════██║██╔═══╝ ██║ ██║██║██║ ██╔══╝ ██╔══██╗ ██╔══██║██║ ██╔══╝ ██╔══██╗ ██║ ╚═╝ 53 | ███████║██║ ╚██████╔╝██║███████╗███████╗██║ ██║ ██║ ██║███████╗███████╗██║ ██║ ██║ ██╗ 54 | ╚══════╝╚═╝ ╚═════╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝╚══════╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚═╝ 55 | */ 56 | 57 | -- 58 | 59 | -- 60 | 61 | -- 62 | 63 | -- 64 | 65 | -- 66 | 67 | -- 68 | 69 | CREATE TABLE Logger (EventTime DATETIME, TableName VARCHAR(20)); 70 | GO 71 | 72 | CREATE TRIGGER Log_Customer_Insert 73 | ON Customers 74 | FOR INSERT 75 | AS 76 | BEGIN 77 | INSERT INTO Logger (EventTime, TableName) 78 | VALUES (GETDATE(), 'Customers'); 79 | END; 80 | 81 | INSERT INTO Customers (Customer, Country) 82 | VALUES ('Test', 'USA'); 83 | 84 | SELECT * FROM Logger; 85 | 86 | /* 87 | ██████╗ ███████╗███████╗ ██████╗ ██╗ ██╗██████╗ ██████╗███████╗███████╗ 88 | ██╔══██╗██╔════╝██╔════╝██╔═══██╗██║ ██║██╔══██╗██╔════╝██╔════╝██╔════╝ 89 | ██████╔╝█████╗ ███████╗██║ ██║██║ ██║██████╔╝██║ █████╗ ███████╗ 90 | ██╔══██╗██╔══╝ ╚════██║██║ ██║██║ ██║██╔══██╗██║ ██╔══╝ ╚════██║ 91 | ██║ ██║███████╗███████║╚██████╔╝╚██████╔╝██║ ██║╚██████╗███████╗███████║ 92 | ╚═╝ ╚═╝╚══════╝╚══════╝ ╚═════╝ ╚═════╝ ╚═╝ ╚═╝ ╚═════╝╚══════╝╚══════╝ 93 | 94 | Additional Reading: 95 | ------------------- 96 | https://docs.microsoft.com/en-us/sql/relational-databases/stored-procedures/stored-procedures-database-engine 97 | https://docs.microsoft.com/en-us/sql/relational-databases/views/views 98 | https://docs.microsoft.com/en-us/sql/relational-databases/triggers/dml-triggers 99 | https://docs.microsoft.com/en-us/sql/relational-databases/user-defined-functions/user-defined-functions 100 | */ -------------------------------------------------------------------------------- /SQL Server Fundamentals/Read Me.txt: -------------------------------------------------------------------------------- 1 | Placeholder 2 | -------------------------------------------------------------------------------- /SQL Server Fundamentals/SQL Server Fundamentals.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/ami-levin/OReilly-Training/e6ebe61b129d3e60d244fcb4f126679296d30704/SQL Server Fundamentals/SQL Server Fundamentals.pdf -------------------------------------------------------------------------------- /Window Functions/Aggregate.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------- 2 | -- O'reilly Online Training ---------------- 3 | -- Advanced SQL Series - Window Functions -- 4 | -- Aggregate Functions --------------------- 5 | -------------------------------------------- 6 | 7 | USE BasicDemos; 8 | GO 9 | 10 | -- COUNT DISTINCT, would be nice... 11 | SELECT *, 12 | COUNT(DISTINCT Item) 13 | OVER ( ORDER BY O.OrderDate 14 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW 15 | ) AS NumOfDifferentItemsPurchasedToDate 16 | FROM Orders AS O 17 | INNER JOIN 18 | OrderItems AS OI 19 | ON O.OrderID = OI.OrderID 20 | ORDER BY O.Customer, 21 | O.OrderDate; 22 | 23 | -- Alternative 24 | WITH OrdersWithSequencedItems 25 | AS 26 | ( 27 | SELECT O.OrderID, 28 | O.OrderDate, 29 | O.Customer, 30 | OI.Item, 31 | ROW_NUMBER() 32 | OVER ( 33 | PARTITION BY OI.Item 34 | ORDER BY O.OrderDate 35 | ) AS ItemSequential 36 | FROM OrderItems AS OI 37 | INNER JOIN 38 | Orders AS O 39 | ON O.OrderID = OI.OrderID 40 | ) 41 | SELECT OrderID, 42 | OrderDate, 43 | Customer, 44 | Item, 45 | COUNT(CASE WHEN ItemSequential = 1 THEN Item ELSE NULL END) 46 | OVER ( ORDER BY OrderDate 47 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW 48 | ) AS NumOfDifferentItemsPurchasedToDate 49 | FROM OrdersWithSequencedItems; 50 | 51 | -------------------------------------------------------------------------------- /Window Functions/Analytic.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------- 2 | -- O'reilly Online Training ---------------- 3 | -- Advanced SQL Series - Window Functions -- 4 | -- Analytic Functions ---------------------- 5 | -------------------------------------------- 6 | 7 | USE TempDB; 8 | GO 9 | 10 | CREATE TABLE Students 11 | ( 12 | Student VARCHAR(20) NOT NULL PRIMARY KEY 13 | ); 14 | 15 | CREATE TABLE Exams 16 | ( 17 | Exam VARCHAR(20) NOT NULL PRIMARY KEY 18 | ); 19 | 20 | CREATE TABLE ExamScores 21 | ( 22 | Student VARCHAR(20) NOT NULL 23 | REFERENCES Students(Student), 24 | Exam VARCHAR(20) NOT NULL 25 | REFERENCES Exams(Exam), 26 | Score TINYINT NOT NULL 27 | CHECK (Score BETWEEN 0 AND 100), 28 | PRIMARY KEY (Student, Exam) 29 | ); 30 | 31 | INSERT INTO Students (Student) 32 | VALUES ('James'), ('Cindy'), ('Sandra'), ('Donald'); 33 | 34 | INSERT INTO Exams (Exam) 35 | VALUES ('Statistics'), ('SQL'), ('C++'), ('Geography'); 36 | 37 | -- TRUNCATE TABLE ExamScores 38 | INSERT INTO ExamScores (Student, Exam, Score) 39 | VALUES ('James', 'Statistics', 68), ('Cindy', 'Statistics', 77), ('Sandra', 'Statistics', 80), 40 | ('James', 'SQL', 100), ('Cindy', 'SQL', 90), ('Sandra', 'SQL', 76), ('Donald', 'SQL', 70), 41 | ('James', 'C++', 96), ('Cindy', 'C++', 100), ('Sandra', 'C++', 88), 42 | ('James', 'Geography', 100), ('Cindy', 'Geography', 85) 43 | 44 | SELECT * 45 | FROM ExamScores 46 | ORDER BY Exam, Score DESC; 47 | 48 | -- Distribution Functions 49 | SELECT Student, 50 | Exam, 51 | Score, 52 | PERCENT_RANK() 53 | OVER( PARTITION BY Exam 54 | ORDER BY Score) AS PercentRank, 55 | CUME_DIST() 56 | OVER( PARTITION BY Exam 57 | ORDER BY Score) AS CummulativeDistribution 58 | FROM ExamScores; 59 | 60 | -- Inverse distribution functions SQL Server 61 | SELECT Student, 62 | Exam, 63 | Score, 64 | PERCENT_RANK() 65 | OVER( PARTITION BY Exam 66 | ORDER BY Score) AS PercentRank, -- For reference 67 | CUME_DIST() 68 | OVER( PARTITION BY Exam 69 | ORDER BY Score) AS CummulativeDistribution, -- For reference 70 | PERCENTILE_CONT(0.5) 71 | WITHIN GROUP (ORDER BY Score) 72 | OVER (PARTITION BY Exam) AS MedianContinous, 73 | PERCENTILE_DISC(0.5) 74 | WITHIN GROUP (ORDER BY Score) 75 | OVER (PARTITION BY Exam) AS MedianDiscrete 76 | FROM ExamScores; 77 | 78 | -- PostgreSQL Aggregate ordered set inverse distribution functions 79 | -- * Oracle supports both as either window functions, or ordered set aggregate functions 80 | 81 | SELECT Exam, 82 | PERCENTILE_CONT(0.5) 83 | WITHIN GROUP (ORDER BY Score) AS MedianContinous, 84 | PERCENTILE_DISC(0.5) 85 | WITHIN GROUP (ORDER BY Score) AS MedianDiscrete 86 | FROM ExamScores 87 | GROUP BY Exam; 88 | 89 | -------------------------------------------------------------------------------- /Window Functions/DemoDB_Script.sql: -------------------------------------------------------------------------------- 1 | -- O'reilly Online Training 2 | -- Relational SQL Querying - Mastering the Basics 3 | -- Demo DB 4 | -------------------------------------- 5 | -- DROP DATABASE BasicDemos; 6 | -- CREATE DATABASE BasicDemos; 7 | -- GO 8 | 9 | USE BasicDemos; 10 | GO 11 | 12 | CREATE TABLE Customers ( 13 | Customer VARCHAR(20) NOT NULL 14 | PRIMARY KEY, 15 | Country VARCHAR(20) NULL 16 | ); 17 | 18 | CREATE TABLE Items ( 19 | Item VARCHAR(20) NOT NULL 20 | PRIMARY KEY 21 | ); 22 | 23 | CREATE TABLE Orders ( 24 | OrderID INTEGER NOT NULL 25 | PRIMARY KEY, 26 | OrderDate DATE NOT NULL, 27 | Customer VARCHAR(20) NOT NULL 28 | REFERENCES Customers(Customer) 29 | ); 30 | 31 | CREATE TABLE OrderItems ( 32 | OrderID INTEGER NOT NULL 33 | REFERENCES Orders(OrderID), 34 | Item VARCHAR(20) NOT NULL 35 | REFERENCES Items(Item), 36 | Quantity INTEGER NOT NULL 37 | CHECK (Quantity > 0), 38 | Price DECIMAL(9,2) NOT NULL 39 | CHECK (Price >=0), 40 | PRIMARY KEY (OrderID, Item) 41 | ); 42 | 43 | INSERT INTO Customers (Customer, Country) 44 | VALUES ('Dave', 'USA'), ('John', 'USA'), ('Gerald', 'Canada'), ('Jose', 'Peru'), ('Tim', NULL); 45 | 46 | INSERT INTO Items (Item) 47 | VALUES ('Pencil'), ('Pen'), ('Marker'), ('Notebook'), ('Ruler'); 48 | 49 | INSERT INTO Orders (OrderID, OrderDate, Customer) 50 | VALUES (1, '20180101', 'Dave'), (2, '20180102', 'John'), (3, '20180103', 'Gerald'), (4, '20180109', 'John'); 51 | 52 | INSERT INTO OrderItems (OrderID, Item, Quantity, Price) 53 | VALUES (1, 'Pen', 2, 1.5), (1, 'Pencil', 1, 0.75), 54 | (2, 'Marker', 3, 3), 55 | (3, 'Pen', 1, 1.5), (3, 'Marker', 1, 3), 56 | (4, 'Pen', 4, 1.5), (4, 'Pencil', 2, 1.25), (4, 'Ruler', 2, 3); 57 | 58 | -------------------------------------------------------------------------------- /Window Functions/Exercise 1 - Windows and Frames.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------- 2 | -- O'reilly Online Training ---------------- 3 | -- Advanced SQL Series - Window Functions -- 4 | -- Exercise 1 - Windows and Frames --------- 5 | -------------------------------------------- 6 | 7 | USE BasicDemos; 8 | GO 9 | 10 | -- Write a query to return daily total quantities per item 11 | -- and Include a running sum of quantities up-to-date 12 | -- Order by Item and date 13 | -- Bonus Question - how would you exclude current day's sales? 14 | -- Scroll down for solution * 15 | 16 | -- Expected Result Set 17 | /* 18 | Item OrderDate NumberOfItemsSoldOnThisDate NumberOfItemsSoldUpToDate 19 | ---- --------- --------------------------- ------------------------- 20 | Marker 2018-01-02 3 3 21 | Marker 2018-01-03 1 4 22 | Pen 2018-01-01 2 2 23 | Pen 2018-01-03 1 3 24 | Pen 2018-01-09 4 7 25 | Pencil 2018-01-01 1 1 26 | Pencil 2018-01-09 2 3 27 | Ruler 2018-01-09 2 2 28 | */ 29 | 30 | 31 | 32 | 33 | 34 | 35 | 36 | 37 | 38 | 39 | 40 | 41 | 42 | 43 | 44 | 45 | 46 | 47 | 48 | 49 | SELECT OI.Item, 50 | O.OrderDate, 51 | SUM(OI.Quantity) AS NumberOfItemsSoldOnThisDate, 52 | SUM(SUM(OI.Quantity)) 53 | OVER ( PARTITION BY OI.Item 54 | ORDER BY O.OrderDate ASC 55 | ROWS BETWEEN UNBOUNDED PRECEDING 56 | AND 57 | CURRENT ROW -- 1 PRECEDING will exclude today's sales 58 | ) AS NumberOfItemsSoldUpToDate 59 | FROM OrderItems AS OI 60 | INNER JOIN 61 | Orders AS O 62 | ON O.OrderID = OI.OrderID 63 | GROUP BY OI.Item, 64 | O.OrderDate 65 | ORDER BY OI.Item, 66 | O.OrderDate; -------------------------------------------------------------------------------- /Window Functions/Exercise 2 - Ranking.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------- 2 | -- O'reilly Online Training ---------------- 3 | -- Advanced SQL Series - Window Functions -- 4 | -- Exercise 2 - Ranking Functions ---------- 5 | -------------------------------------------- 6 | 7 | USE BasicDemos; 8 | GO 9 | 10 | -- Write a query that ranks customers based on their total order values 11 | -- Order so that the highest total order value shows first 12 | -- Scroll down for solution * 13 | 14 | -- Expected result set 15 | /* 16 | Customer TotalOrderValue TotalOrderValueRank 17 | -------- --------------- ------------------- 18 | John 23.50 1 19 | Gerald 4.50 2 20 | Dave 3.75 3 21 | */ 22 | 23 | 24 | 25 | 26 | 27 | 28 | 29 | 30 | 31 | 32 | 33 | 34 | 35 | 36 | 37 | 38 | 39 | 40 | 41 | 42 | 43 | SELECT Customer, 44 | SUM(OI.Quantity * OI.Price) AS TotalOrderValue, 45 | RANK() 46 | OVER ( ORDER BY SUM(OI.Quantity * OI.Price) DESC 47 | ) AS TotalOrderValueRank 48 | FROM OrderItems AS OI 49 | INNER JOIN 50 | Orders AS O 51 | ON O.OrderID = OI.OrderID 52 | GROUP BY O.Customer 53 | ORDER BY TotalOrderValueRank -------------------------------------------------------------------------------- /Window Functions/Exercise 3 - Offset.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------- 2 | -- O'reilly Online Training ---------------- 3 | -- Advanced SQL Series - Window Functions -- 4 | -- Exercise 3 - Offset Functions ----------- 5 | -------------------------------------------- 6 | 7 | USE BasicDemos; 8 | GO 9 | 10 | -- Write a query that returns all orders with details, include their total value, 11 | -- and also include the total of the customer's previous order based on date 12 | -- If it's the customer's first order, show 0 for previous order 13 | -- Scroll down for solution * 14 | 15 | -- Expected result set 16 | /* 17 | OrderID OrderDate Customer OrderTotal CustomersPreviousOrder 18 | ------- --------- -------- ---------- ----------------------- 19 | 1 2018-01-01 Dave 3.75 0.00 20 | 3 2018-01-03 Gerald 4.50 0.00 21 | 2 2018-01-02 John 9.00 0.00 22 | 4 2018-01-09 John 14.50 9.00 23 | */ 24 | 25 | 26 | 27 | 28 | 29 | 30 | 31 | 32 | 33 | 34 | 35 | 36 | 37 | 38 | 39 | 40 | 41 | 42 | 43 | 44 | 45 | WITH OrderTotals 46 | AS 47 | ( 48 | SELECT O.OrderID, 49 | SUM(OI.Quantity * OI.Price) AS OrderTotal 50 | FROM OrderItems AS OI 51 | INNER JOIN 52 | Orders AS O 53 | ON O.OrderID = OI.OrderID 54 | GROUP BY O.OrderID 55 | ) 56 | SELECT O.*, 57 | OT.OrderTotal, 58 | LAG(OT.OrderTotal, 1, 0) 59 | OVER ( PARTITION BY O.Customer 60 | ORDER BY O.OrderDate 61 | ) AS CustomersPreviousOrder 62 | FROM Orders AS O 63 | INNER JOIN 64 | OrderTotals AS OT 65 | ON OT.OrderID = O.OrderID; 66 | 67 | 68 | -------------------------------------------------------------------------------- /Window Functions/Offset.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------- 2 | -- O'reilly Online Training ---------------- 3 | -- Advanced SQL Series - Window Functions -- 4 | -- Offset Functions ------------------------ 5 | -------------------------------------------- 6 | 7 | -- Row offset functions 8 | 9 | SELECT *, 10 | LEAD(Price, 1) 11 | OVER ( ORDER BY OrderID) AS LEAD1, 12 | LEAD (Quantity) 13 | OVER ( PARTITION BY OrderID 14 | ORDER BY Price DESC ) AS LEAD2, 15 | LAG (Item, 1, 'N/A') 16 | OVER ( PARTITION BY OrderID 17 | ORDER BY Quantity ) AS LAG1 18 | FROM OrderItems; 19 | 20 | 21 | 22 | -- Frame offset functions 23 | 24 | SELECT *, 25 | FIRST_VALUE(Price) 26 | OVER ( ORDER BY OrderID 27 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS First1, 28 | LAST_VALUE (Quantity) 29 | OVER ( PARTITION BY Item 30 | ORDER BY Price DESC 31 | ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING ) AS Last1 32 | FROM OrderItems; 33 | 34 | -- SQL Alternatives 35 | 36 | -- This is a take home exercise 37 | -- Tip: It will require assigning row numbers, which we will cover later 38 | 39 | -- PostgreSQL / Oracle / MySQL 8 NTH_VALUE 40 | 41 | SELECT *, 42 | NTH_VALUE(Item, 2) /*FROM FIRST - not supported in PosgreSQL, always default*/ 43 | OVER ( PARTITION BY OrderID 44 | ORDER BY PRICE DESC 45 | ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING 46 | -- Must specify frame or else the default kicks in... 47 | ) AS SecondMostExpensiveItemInOrder 48 | FROM OrderItems; 49 | 50 | -- Offset ordered set functions, not supported with popular engines 51 | 52 | SELECT OrderID, 53 | LAST_VALUE(Item) 54 | WITHIN GROUP(ORDER BY Price ASC) AS MostExpensiveItemInOrder, 55 | FIRST_VALUE(Item) 56 | WITHIN GROUP(ORDER BY Price ASC) AS CheapestItemInOrder 57 | FROM OrderItems 58 | GROUP BY OrderID; 59 | 60 | -------------------------------------------------------------------------------- /Window Functions/Processing Order.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------- 2 | -- O'reilly Online Training ---------------- 3 | -- Advanced SQL Series - Window Functions -- 4 | -- Logical Processing Order ---------------- 5 | -------------------------------------------- 6 | 7 | USE BasicDemos; 8 | GO 9 | 10 | -- What is the expected result of this query? 11 | SELECT * 12 | FROM OrderItems 13 | WHERE Item <> 'Pen' 14 | AND 15 | MAX(Price) 16 | OVER (PARTITION BY OrderID) > 2; 17 | 18 | -- Better: 19 | WITH OrdersWithMaxPriceOver2 20 | AS 21 | ( 22 | SELECT OrderID, MAX(Price) AS MaxOrderPrice 23 | FROM OrderItems 24 | GROUP BY OrderID 25 | HAVING MAX(Price) > 2 26 | ) 27 | SELECT OI.*, 28 | OWM.MaxOrderPrice 29 | FROM OrderItems AS OI 30 | INNER JOIN 31 | OrdersWithMaxPriceOver2 AS OWM 32 | ON OWM.OrderID = OI.OrderID 33 | WHERE Item <> 'Pen'; 34 | 35 | -- What is the expected result of this query? 36 | SELECT OrderID, 37 | SUM(Quantity * Price) AS OrderTotal, 38 | 100.00 * SUM(Quantity * Price) / SUM(Quantity * Price) OVER () AS PercentOfGrandTotal 39 | FROM OrderItems 40 | GROUP BY OrderID; 41 | 42 | -- Alternative 1 43 | SELECT OrderID, 44 | SUM(Quantity * Price) AS OrderTotal, 45 | SUM(Quantity * Price) / SUM(SUM(Quantity * Price)) OVER () AS PercentOfGrandTotal 46 | FROM OrderItems 47 | GROUP BY OrderID; 48 | 49 | -- Alternative 2 50 | SELECT OrderID, 51 | SUM(Quantity * Price) AS OrderTotal, 52 | SUM(Quantity * Price) / X.GrandTotal AS PercentOfGrandTotal 53 | FROM OrderItems 54 | CROSS APPLY 55 | (SELECT SUM(Quantity * Price) FROM OrderItems) AS X(GrandTotal) -- What if we add OVER() ? 56 | GROUP BY OrderID, X.GrandTotal; 57 | 58 | -- What is the expected result of this query? 59 | SELECT Item, 60 | MAX(Price) 61 | OVER (PARTITION BY Item, OrderID) 62 | FROM OrderItems 63 | GROUP BY Item; 64 | 65 | -- Better: 66 | SELECT Item, 67 | OrderID, 68 | MAX(MAX(Price)) 69 | OVER (PARTITION BY Item, OrderID) AS MaxPricePerOrderPerItem 70 | FROM OrderItems 71 | GROUP BY Item, 72 | OrderID; 73 | -------------------------------------------------------------------------------- /Window Functions/ROWS-RANGE.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------- 2 | -- O'reilly Online Training ---------------- 3 | -- Advanced SQL Series - Window Functions -- 4 | -- ROWS vs, RANGE Framing ------------------ 5 | -------------------------------------------- 6 | 7 | USE BasicDemos; 8 | GO 9 | 10 | SELECT *, 11 | SUM(Quantity) 12 | OVER ( PARTITION BY Item 13 | ORDER BY Price 14 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS RowsSumQty, 15 | SUM(Quantity) 16 | OVER ( PARTITION BY Item 17 | ORDER BY Price 18 | RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS RangeSumQty 19 | FROM OrderItems 20 | ORDER BY Item, Price 21 | 22 | -- What is the expected output of this query? 23 | SELECT SUM(Quantity) 24 | OVER ( PARTITION BY Item 25 | ORDER BY Price ) 26 | FROM OrderItems; 27 | -- Always specify frame EXPLICITLY!!! 28 | 29 | -- Getting Immediate Neighbour Rows 30 | SELECT *, 31 | MAX(Item) 32 | OVER ( PARTITION BY O.Customer 33 | ORDER BY O.OrderID, OI.Item 34 | ROWS BETWEEN 1 PRECEDING AND 1 PRECEDING 35 | ) AS PreviousItem , 36 | MAX(Item) 37 | OVER ( PARTITION BY O.Customer 38 | ORDER BY O.OrderID, OI.Item 39 | ROWS BETWEEN 1 FOLLOWING AND 1 FOLLOWING 40 | ) AS NextItem, 41 | AVG(1.0 * OI.Quantity) 42 | OVER ( PARTITION BY O.Customer 43 | ORDER BY O.OrderID, OI.Item 44 | ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING 45 | ) AS AverageQuantityForCurrentPreviousAndNextItemsPerOrder 46 | FROM OrderItems AS OI 47 | INNER JOIN 48 | Orders AS O 49 | ON O.OrderID = OI.OrderID 50 | ORDER BY O.Customer, O.OrderID, OI.Item 51 | 52 | -- Frame using Intervals (Maybe in PostgreSQL 11 - It is still in Beta...) 53 | SELECT *, 54 | SUM(OI.Quantity) 55 | OVER ( PARTITION BY Item 56 | ORDER BY O.OrderDate 57 | RANGE BETWEEN '1 DAY' PRECEDING AND '1 DAY' PRECEDING 58 | ) AS ItemSalesOnPreviousDay 59 | FROM OrderItems AS OI 60 | INNER JOIN 61 | Orders AS O 62 | ON O.OrderID = OI.OrderID 63 | ORDER BY OI.Item, 64 | O.OrderDate; 65 | 66 | -- Current alternative 67 | SELECT *, 68 | ( SELECT SUM(OI2.Quantity) 69 | FROM OrderItems AS OI2 70 | INNER JOIN 71 | Orders AS O2 72 | ON O2.OrderID = OI2.OrderID 73 | WHERE OI2.Item = OI.Item 74 | AND 75 | CAST(O2.OrderDate AS DATE) = DATEADD(DAY, -1, O.OrderDate) 76 | ) AS ItemSalesOnPreviousDay 77 | FROM OrderItems AS OI 78 | INNER JOIN 79 | Orders AS O 80 | ON O.OrderID = OI.OrderID 81 | ORDER BY OI.Item, 82 | O.OrderDate; 83 | /* 84 | -- FILTER clause in PostgreSQL 85 | SELECT *, 86 | MAX(Quantity) 87 | OVER (PARTITION BY OrderID) AS MaxQuantityForOrder, 88 | MAX(Quantity) 89 | FILTER (WHERE Quantity < (SELECT MAX(Quantity) FROM OrderItems)) -- Remove highest 'outlier' 90 | OVER (PARTITION BY OrderID) AS AdjustedMaxQuantityForOrder 91 | FROM OrderItems; 92 | */ 93 | 94 | -- Alternative using CASE 95 | SELECT *, 96 | MAX(Quantity) 97 | OVER (PARTITION BY OrderID) AS MaxQuantityForOrder, 98 | MAX(CASE WHEN Quantity < (SELECT MAX(Quantity) FROM OrderItems) THEN Quantity ELSE NULL END) 99 | OVER (PARTITION BY OrderID) AS AdjustedMaxQuantityForOrder 100 | FROM OrderItems; 101 | 102 | -------------------------------------------------------------------------------- /Window Functions/Ranking.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------- 2 | -- O'reilly Online Training ---------------- 3 | -- Advanced SQL Series - Window Functions -- 4 | -- Ranking Functions ----------------------- 5 | -------------------------------------------- 6 | 7 | -- Ordered set functions 8 | -- SQL Server - Aggregate ordered set function 9 | 10 | SELECT OrderID, 11 | STRING_AGG(Item, ', ') WITHIN GROUP(ORDER BY Quantity DESC) AS ConcatenatedItems 12 | FROM OrderItems 13 | GROUP BY OrderID 14 | 15 | -- PostgreSQL / Oracle Hypothetical ordered set function 16 | /* 17 | SELECT OrderID, 18 | COUNT(*) AS NumRows, 19 | MAX(Quantity) AS MaximalQuantity, 20 | MIN(Quantity) AS MinimalQuantity, 21 | RANK(2) WITHIN GROUP (ORDER BY Quantity DESC) AS hypotheticalRank 22 | FROM OrderItems 23 | GROUP BY OrderID; 24 | */ 25 | 26 | -- Window Ranking Functions 27 | 28 | -- RANK 29 | SELECT *, 30 | RANK() 31 | OVER ( ORDER BY OrderID ) AS RK1, 32 | RANK() 33 | OVER ( PARTITION BY OrderID 34 | ORDER BY Price DESC ) AS RK2, 35 | RANK() 36 | OVER ( PARTITION BY Item 37 | ORDER BY Quantity ASC ) AS RK3 38 | FROM OrderItems 39 | ORDER BY OrderID, 40 | Item 41 | 42 | -- Solution with sub queries 43 | SELECT OI.*, 44 | ( SELECT COUNT(*) + 1 45 | FROM OrderItems AS OI2 46 | WHERE OI2.OrderID < OI.OrderID 47 | ) AS RK1, 48 | ( SELECT COUNT(*) + 1 49 | FROM OrderItems AS OI2 50 | WHERE OI2.OrderID = OI.OrderID 51 | AND 52 | OI.Price < OI2.Price 53 | ) AS RK2, 54 | ( SELECT COUNT(*) + 1 55 | FROM OrderItems AS OI2 56 | WHERE OI2.Item = OI.Item 57 | AND 58 | OI.Quantity > OI2.Quantity 59 | ) AS RK3 60 | FROM OrderItems AS OI 61 | ORDER BY OI.OrderID, OI.Item 62 | 63 | -- DENSE RANK 64 | SELECT *, 65 | DENSE_RANK() OVER (ORDER BY OrderID) AS DRK1, 66 | DENSE_RANK() OVER (PARTITION BY OrderID ORDER BY Price DESC) AS DRK2, 67 | DENSE_RANK() OVER (PARTITION BY Item ORDER BY Quantity ASC) AS DRK3 68 | FROM OrderItems 69 | ORDER BY OrderID, Item 70 | 71 | -- Solution with sub queries 72 | SELECT OI.*, 73 | ( SELECT COUNT(DISTINCT OI2.OrderID) + 1 74 | FROM OrderItems AS OI2 75 | WHERE OI2.OrderID < OI.OrderID 76 | ) AS DRK1, 77 | ( SELECT COUNT(DISTINCT OI2.Price) + 1 78 | FROM OrderItems AS OI2 79 | WHERE OI2.OrderID = OI.OrderID 80 | AND 81 | OI.Price < OI2.Price 82 | ) AS DRK2, 83 | ( SELECT COUNT(DISTINCT OI2.Quantity) + 1 84 | FROM OrderItems AS OI2 85 | WHERE OI2.Item = OI.Item 86 | AND 87 | OI.Quantity > OI2.Quantity 88 | ) AS DRK3 89 | FROM OrderItems AS OI 90 | ORDER BY OI.OrderID, 91 | OI.Item 92 | 93 | -- ROW_NUMBER 94 | SELECT *, 95 | ROW_NUMBER() 96 | OVER ( ORDER BY OrderID) AS RN1, 97 | ROW_NUMBER() 98 | OVER ( PARTITION BY OrderID 99 | ORDER BY Price DESC) AS RN2, 100 | ROW_NUMBER() 101 | OVER ( PARTITION BY Item 102 | ORDER BY Quantity ASC) AS RN3 103 | FROM OrderItems 104 | ORDER BY OrderID, 105 | Item 106 | 107 | -- Solution with sub queries 108 | SELECT OI.*, 109 | ( SELECT COUNT(*) 110 | FROM OrderItems AS OI2 111 | WHERE OI2.OrderID < OI.OrderID 112 | OR -- Must have tie breaker... 113 | ( OI2.OrderID = OI.OrderID 114 | AND 115 | OI.Item >= OI2.Item 116 | ) 117 | ) AS RN1, 118 | ( SELECT COUNT(*) 119 | FROM OrderItems AS OI2 120 | WHERE OI2.OrderID = OI.OrderID 121 | AND 122 | ( OI.Price < OI2.Price 123 | OR -- Must have tie breaker, even though our sample data happens to be unique... 124 | ( OI.Price = OI2.Price 125 | AND 126 | OI.Item >= OI2.Item 127 | ) 128 | ) 129 | ) AS RN2, 130 | ( SELECT COUNT(*) 131 | FROM OrderItems AS OI2 132 | WHERE OI2.Item = OI.Item 133 | AND 134 | ( OI.Quantity > OI2.Quantity 135 | OR -- Must have tie breaker, even though our sample data happens to be unique... 136 | ( OI.Quantity = OI2.Quantity 137 | AND 138 | OI.OrderID >= OI2.OrderID 139 | ) 140 | ) 141 | 142 | ) AS RN3 143 | FROM OrderItems AS OI 144 | ORDER BY OI.OrderID, 145 | OI.Item 146 | 147 | -- NTILE 148 | SELECT *, 149 | NTILE (3) OVER (ORDER BY OrderID) AS NT1, 150 | NTILE (2) OVER (PARTITION BY OrderID ORDER BY Price DESC ) AS NT2, 151 | NTILE (4) OVER (PARTITION BY Item ORDER BY Quantity ASC) AS NT3 152 | FROM OrderItems 153 | ORDER BY OrderID, Item; 154 | 155 | -- Solution with sub queries 156 | 157 | -- This is your take home challenge #1 158 | -- If you give up after 1 week of trying, 159 | -- send me an Email to amilevin@gmail.com with what you got so far. 160 | -- Alternatively, go to https://www.safaribooksonline.com/library/view/microsoft-sql-server/9780735671591/ch02.html#ntile 161 | -- for Itzik Ben-Gan's solution 162 | -------------------------------------------------------------------------------- /Window Functions/Readme.txt: -------------------------------------------------------------------------------- 1 | Demo code for O'Reilly Online Training, "Advanced SQL Series: Window Functions" 2 | -------------------------------------------------------------------------------- /Window Functions/Window and Frame.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------- 2 | -- O'reilly Online Training ---------------- 3 | -- Advanced SQL Series - Window Functions -- 4 | -- Window and Frame ------------------------ 5 | -------------------------------------------- 6 | 7 | USE BasicDemos; 8 | GO 9 | 10 | -- Show highest price ever 11 | SELECT *, 12 | ( 13 | SELECT MAX(OI2.Price) 14 | FROM OrderItems AS OI2 15 | ) AS HighestPriceEver 16 | FROM OrderItems AS OI; 17 | 18 | SELECT *, 19 | MAX(Price) 20 | OVER () AS HighestPriceEver 21 | FROM OrderItems; 22 | 23 | -- Show highest price for order 24 | SELECT *, 25 | ( 26 | SELECT MAX(OI2.Price) 27 | FROM OrderItems AS OI2 28 | WHERE OI.OrderID = OI2.OrderID 29 | ) AS HighestPriceForOrder 30 | FROM OrderItems AS OI 31 | ORDER BY OI.OrderID; 32 | 33 | SELECT *, 34 | MAX(Price) 35 | OVER (PARTITION BY OrderID) HigestPriceForOrder 36 | FROM OrderItems 37 | ORDER BY OrderID; 38 | 39 | -- Show highest price for item 40 | SELECT *, 41 | ( 42 | SELECT MAX(OI2.Price) 43 | FROM OrderItems AS OI2 44 | WHERE OI.Item = OI2.Item 45 | ) AS HighestPriceForItem 46 | FROM OrderItems AS OI 47 | ORDER BY OI.Item; 48 | 49 | SELECT *, 50 | MAX(Price) 51 | OVER (PARTITION BY Item) HighestPriceForItem 52 | FROM OrderItems 53 | ORDER BY Item; 54 | 55 | -- Show higest price for item for all previous orders up to and including the current one 56 | SELECT *, 57 | ( 58 | SELECT MAX(OI2.Price) 59 | FROM OrderItems AS OI2 60 | WHERE OI.Item = OI2.Item 61 | AND 62 | OI2.OrderID <= OI.OrderID 63 | ) AS HighestPriceSoFar 64 | FROM OrderItems AS OI 65 | ORDER BY OI.Item, OI.OrderID; 66 | 67 | SELECT *, 68 | MAX(Price) 69 | OVER( PARTITION BY Item 70 | ORDER BY OrderID 71 | ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW 72 | ) AS HighestPriceSoFar 73 | FROM OrderItems 74 | ORDER BY Item, OrderID 75 | 76 | --------------------------------------------------------------------------------