├── .github
├── CONTRIBUTING.md
├── ISSUE_TEMPLATE.md
└── PULL_REQUEST_TEMPLATE.md
├── Instructions
├── Demos
│ ├── 01-module-1-demos.md
│ ├── 02-module-2-demos.md
│ ├── 03-module-3-demos.md
│ ├── 05-module-4-demos.md
│ └── 06-module-5-demos.md
└── Labs
│ ├── 00-setup.md
│ ├── 00a-setup-azure.md
│ ├── 00b-setup-fabric.md
│ ├── 01-get-started-with-tsql.md
│ ├── 02-filter-sort.md
│ ├── 03a-joins.md
│ ├── 03b-subqueries.md
│ ├── 04-built-in-functions.md
│ ├── 05-modify-data.md
│ ├── 06-use-table-expressions.md
│ ├── 07-combine-query-results.md
│ ├── 08-create-window-query-functions.md
│ ├── 09-transform-data.md
│ ├── 10-program-with-tsql.md
│ ├── 11-create-stored-procedures.md
│ ├── 12-implement-error-handling.md
│ ├── 13-implement-transitions-in-tsql.md
│ └── images
│ └── adventureworks-erd.png
├── LICENSE
├── Scripts
├── adventureworkslt.sql
├── module01-demos.sql
├── module02-demos.sql
├── module03-demos.sql
├── module04-demos.sql
└── module05-demos.sql
├── _build.yml
├── _config.yml
├── index.md
└── readme.md
/.github/CONTRIBUTING.md:
--------------------------------------------------------------------------------
1 | # Contributing to Microsoft Learning Repositories
2 |
3 | MCT contributions are a key part of keeping the lab and demo content current as the Azure platform changes. We want to make it as easy as possible for you to contribute changes to the lab files. Here are a few guidelines to keep in mind as you contribute changes.
4 |
5 | ## GitHub Use & Purpose
6 |
7 | Microsoft Learning is using GitHub to publish the lab steps and lab scripts for courses that cover cloud services like Azure. Using GitHub allows the course’s authors and MCTs to keep the lab content current with Azure platform changes. Using GitHub allows the MCTs to provide feedback and suggestions for lab changes, and then the course authors can update lab steps and scripts quickly and relatively easily.
8 |
9 | > When you prepare to teach these courses, you should ensure that you are using the latest lab steps and scripts by downloading the appropriate files from GitHub. GitHub should not be used to discuss technical content in the course, or how to prep. It should only be used to address changes in the labs.
10 |
11 | It is strongly recommended that MCTs and Partners access these materials and in turn, provide them separately to students. Pointing students directly to GitHub to access Lab steps as part of an ongoing class will require them to access yet another UI as part of the course, contributing to a confusing experience for the student. An explanation to the student regarding why they are receiving separate Lab instructions can highlight the nature of an always-changing cloud-based interface and platform. Microsoft Learning support for accessing files on GitHub and support for navigation of the GitHub site is limited to MCTs teaching this course only.
12 |
13 | > As an alternative to pointing students directly to the GitHub repository, you can point students to the GitHub Pages website to view the lab instructions. The URL for the GitHub Pages website can be found at the top of the repository.
14 |
15 | To address general comments about the course and demos, or how to prepare for a course delivery, please use the existing MCT forums.
16 |
17 | ## Additional Resources
18 |
19 | A user guide has been provided for MCTs who are new to GitHub. It provides steps for connecting to GitHub, downloading and printing course materials, updating the scripts that students use in labs, and explaining how you can help ensure that this course’s content remains current.
20 |
21 |
22 |
--------------------------------------------------------------------------------
/.github/ISSUE_TEMPLATE.md:
--------------------------------------------------------------------------------
1 | # Module: 00
2 | ## Lab/Demo: 00
3 | ### Task: 00
4 | #### Step: 00
5 |
6 | Description of issue
7 |
8 | Repro steps:
9 |
10 | 1.
11 | 1.
12 | 1.
--------------------------------------------------------------------------------
/.github/PULL_REQUEST_TEMPLATE.md:
--------------------------------------------------------------------------------
1 | # Module: 00
2 | ## Lab/Demo: 00
3 |
4 | Fixes # .
5 |
6 | Changes proposed in this pull request:
7 |
8 | -
9 | -
10 | -
--------------------------------------------------------------------------------
/Instructions/Demos/01-module-1-demos.md:
--------------------------------------------------------------------------------
1 | ---
2 | demo:
3 | title: 'Module 1 Demonstrations'
4 | module: 'Module 1: Getting Started with Transact-SQL'
5 | ---
6 |
7 | # Module 1 Demonstrations
8 |
9 | This file contains guidance for demonstrations you can use to help students understand key concepts taught in the module.
10 |
11 | ## Explore the lab environment
12 |
13 | Throughout the course, students use a hosted environment that includes **Azure Data Studio** and a local instance of SQL Server Express containing a simplified version of the **adventureworks** sample database.
14 |
15 | 1. Start the hosted lab environment (for any lab in this course), and log in if necessary.
16 | 2. Start Azure Data Studio, and in the **Connections** tab, select the **AdventureWorks** connection. This will connect to the SQL Server instance and show the objects in the **adventureworks** database.
17 | 3. Expand the **Tables** folder to see the tables that are defined in the database. Note that there are a few tables in the **dbo** schema, but most of the tables are defined in a schema named **SalesLT**.
18 | 4. Expand the **SalesLT.Product** table and then expand its **Columns** folder to see the columns in this table. Each column has a name, a data type, an indication of whether it can contain *null* values, and in some cases an indication that the columns is used as a primary key (PK) or foreign key (FK).
19 | 5. Right-click the **SalesLT.Product** table and use the **SELECT TOP (1000)** option to create and run a new query script that retrieves the first 1000 rows from the table.
20 | 6. Review the query results, which consist of 1000 rows - each row representing a product that is sold by the fictitious *Adventure Works Cycles* company.
21 | 7. Close the **SQLQuery_1** pane that contains the query and its results.
22 | 8. Explore the other tables in the database, which contain information about product details, customers, and sales orders.
23 | 9. In Azure Data Studio, create a new query (you can do this from the **File** menu or on the *welcome* page).
24 | 10. In the new **SQLQuery_...** pane, use the **Connect** button to connect the query to the **AdventureWorks** saved connection (do this even if the query was already connected by clicking **Disconnect** first - it's useful for students to see how to connect to the saved connection!).
25 | 11. In the query editor, enter the following code:
26 |
27 | ```
28 | SELECT * FROM SalesLT.Product;
29 | ```
30 |
31 | 12. Use the **⏵Run** button to run the query, and and after a few seconds, review the results, which includes all fields for all products.
32 | 13. in the results pane, select the **Messages** tab. This tab provides output messages from the query, and is a useful way to check the number of rows returned by the query.
33 |
34 | ## Run basic SELECT queries
35 |
36 | Use these example queries at appropriate points during the module presentation.
37 |
38 | 1. In Azure Data Studio, open the file at **https://raw.githubusercontent.com/MicrosoftLearning/dp-080-Transact-SQL/master/Scripts/module01-demos.sql**
39 | 2. Connect the script to the saved **AdventureWorks** connection.
40 | 3. Select and run each query when relevant (when text is selected in the script editor, the **⏵Run** button runs only the selected text).
41 |
--------------------------------------------------------------------------------
/Instructions/Demos/02-module-2-demos.md:
--------------------------------------------------------------------------------
1 | ---
2 | demo:
3 | title: 'Module 2 Demonstrations'
4 | module: 'Module 2: Sorting and Filtering Query Results'
5 | ---
6 |
7 | # Module 2 Demonstrations
8 |
9 | This file contains guidance for demonstrations you can use to help students understand key concepts taught in the module.
10 |
11 | > **Tip**: You can use the hosted lab environment for any lab in this course to perform these demo's.
12 |
13 | 1. In Azure Data Studio, open the file at **https://raw.githubusercontent.com/MicrosoftLearning/dp-080-Transact-SQL/master/Scripts/module02-demos.sql**
14 | 2. Connect the script to the saved **AdventureWorks** connection.
15 | 3. Select and run each query when relevant (when text is selected in the script editor, the **⏵Run** button runs only the selected text).
16 |
--------------------------------------------------------------------------------
/Instructions/Demos/03-module-3-demos.md:
--------------------------------------------------------------------------------
1 | ---
2 | demo:
3 | title: 'Module 3 Demonstrations'
4 | module: 'Module 3: Using Joins and Subqueries'
5 | ---
6 |
7 | # Module 3 Demonstrations
8 |
9 | This file contains guidance for demonstrations you can use to help students understand key concepts taught in the module.
10 |
11 | > **Tip**: You can use the hosted lab environment for any lab in this course to perform these demo's.
12 |
13 | 1. In Azure Data Studio, open the file at **https://raw.githubusercontent.com/MicrosoftLearning/dp-080-Transact-SQL/master/Scripts/module03-demos.sql**
14 | 2. Connect the script to the saved **AdventureWorks** connection.
15 | 3. Select and run each query when relevant (when text is selected in the script editor, the **⏵Run** button runs only the selected text).
16 |
--------------------------------------------------------------------------------
/Instructions/Demos/05-module-4-demos.md:
--------------------------------------------------------------------------------
1 | ---
2 | demo:
3 | title: 'Module 4 Demonstrations'
4 | module: 'Module 4: Using Built-in Functions'
5 | ---
6 |
7 | # Module 4 Demonstrations
8 |
9 | This file contains guidance for demonstrations you can use to help students understand key concepts taught in the module.
10 |
11 | > **Tip**: You can use the hosted lab environment for any lab in this course to perform these demo's.
12 |
13 | 1. In Azure Data Studio, open the file at **https://raw.githubusercontent.com/MicrosoftLearning/dp-080-Transact-SQL/master/Scripts/module04-demos.sql**
14 | 2. Connect the script to the saved **AdventureWorks** connection.
15 | 3. Select and run each query when relevant (when text is selected in the script editor, the **⏵Run** button runs only the selected text).
16 |
--------------------------------------------------------------------------------
/Instructions/Demos/06-module-5-demos.md:
--------------------------------------------------------------------------------
1 | ---
2 | demo:
3 | title: 'Module 5 Demonstrations'
4 | module: 'Module 5: Modifying Data'
5 | ---
6 |
7 | # Module 5 Demonstrations
8 |
9 | This file contains guidance for demonstrations you can use to help students understand key concepts taught in the module.
10 |
11 | > **Tip**: You can use the hosted lab environment for any lab in this course to perform these demo's.
12 |
13 | 1. In Azure Data Studio, open the file at **https://raw.githubusercontent.com/MicrosoftLearning/dp-080-Transact-SQL/master/Scripts/module05-demos.sql**
14 | 2. Connect the script to the saved **AdventureWorks** connection.
15 | 3. Select and run each query when relevant (when text is selected in the script editor, the **⏵Run** button runs only the selected text).
16 |
--------------------------------------------------------------------------------
/Instructions/Labs/00-setup.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Lab Environment Setup - Local SQL Server'
4 | module: 'Setup'
5 | ---
6 |
7 | # Lab Environment Setup
8 |
9 | > **Note**: The following information provides a guide for what you need to install if you want to try the labs using SQL Server on your own computer. However, please note that these guidelines are provided as-is with no warranty. Due to the variability of operating system configuration and additionally installed software, Microsoft cannot provide support for your own lab environment.
10 |
11 | ## Base Operating System
12 |
13 | The setup for these labs has been tested on Microsoft Windows 11 with the latest updates applied as of April 8th 2024.
14 |
15 | The required software for the labs can also be installed on Linux and Apple Mac computers, but this configuration has not been tested.
16 |
17 | ## Microsoft SQL Server Express 2022
18 |
19 | 1. Download Microsoft SQL Server Express 2022 from [the Microsoft download center](https://www.microsoft.com/en-us/download/details.aspx?id=104781).
20 | 2. Run the downloaded installer and select the **Basic** installation option.
21 |
22 | ## Microsoft Azure Data Studio
23 |
24 | 1. Download and install Azure Data Studio from the [Azure Data Studio documentation](https://docs.microsoft.com/sql/azure-data-studio/download-azure-data-studio), following the appropriate instructions for your operating system.
25 |
26 | ## AdventureWorks LT Database
27 |
28 | The labs use a lightweight version of the AdventureWorks sample database. Note that this is not the same as the official sample database, so use the following instructions to create it.
29 |
30 | 1. Download the **[adventureworkslt.sql](../../Scripts/adventureworkslt.sql)** script, and save it on your local computer.
31 | 2. Start Azure Data Studio, and open the **adventureworkslt.sql** script file you downloaded.
32 | 3. In the script pane, connect to your SQL Server Express server server using the following information:
33 | - **Connection type**: SQL Server
34 | - **Server**: localhost\SQLExpress
35 | - **Authentication Type**: Windows Authentication
36 | - **Database**: master
37 | - **Server group**: <Default>
38 | - **Name**: *leave blank*
39 | 4. Ensure the **master** database is selected, and then run the script to create the **adventureworks** database. This will take a few minutes.
40 | 5. After the database has been created, on the **Connections** pane, in the **Servers** section, create a new connection with the following settings:
41 | - **Connection type**: SQL Server
42 | - **Server**: localhost\SQLExpress
43 | - **Authentication Type**: Windows Authentication
44 | - **Database**: adventureworks
45 | - **Server group**: <Default>
46 | - **Name**: AdventureWorks
47 |
48 | ## Explore the *AdventureWorks* database
49 |
50 | We'll use the **AdventureWorks** database in this lab, so let's start by exploring it in Azure Data Studio.
51 |
52 | 1. Start Azure Data Studio if it's not already started, and in the **Connections** tab, select the **AdventureWorks** connection by clicking on the arrow just to the left of the name. This will connect to the SQL Server instance and show the objects in the **AdventureWorks** database.
53 | 2. Expand the **Tables** folder to see the tables that are defined in the database. Note that there are a few tables in the **dbo** schema, but most of the tables are defined in a schema named **SalesLT**.
54 | 3. Expand the **SalesLT.Product** table and then expand its **Columns** folder to see the columns in this table. Each column has a name, a data type, an indication of whether it can contain *null* values, and in some cases an indication that the columns is used as a primary key (PK) or foreign key (FK).
55 | 4. Right-click the **SalesLT.Product** table and use the **SELECT TOP (1000)** option to create and run a new query script that retrieves the first 1000 rows from the table.
56 | 5. Review the query results, which consist of 1000 rows - each row representing a product that is sold by the fictitious *Adventure Works Cycles* company.
57 | 6. Close the **SQLQuery_1** pane that contains the query and its results.
58 | 7. Explore the other tables in the database, which contain information about product details, customers, and sales orders. The tables are related through primary and foreign keys, as shown here (you may need to resize the pane to see them clearly):
59 |
60 | 
61 |
62 | > **Note**: If you're familiar with the standard **AdventureWorks** sample database, you may notice that in this lab we are using a simplified version that makes it easier to focus on learning Transact-SQL syntax.
--------------------------------------------------------------------------------
/Instructions/Labs/00a-setup-azure.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Lab Environment Setup - Azure SQL Database'
4 | module: 'Setup'
5 | ---
6 |
7 | # Lab Environment Setup
8 |
9 | You can complete the Transact-SQL exercises in a sample database in Microsoft Azure SQL Database. Use the instructions in this page to prepare a suitable Azure SQL Database environment.
10 |
11 | > **Note**: You will need a [Microsoft Azure subscription](https://azure.microsoft.com/free) in which you have sufficient permissions to create and configure the required resources.
12 |
13 | ## Provision Azure SQL Database
14 |
15 | First, you need to provision an instance of Azure SQL Database with a sample database that you can query.
16 |
17 | 1. In a web browser, navigate to the [Azure portal](https://portal.azure.com) at `https://portal.azure.com` and sign in using the credentials associated with your Azure subscription.
18 | 1. On the **Home** page, create a **SQL Database** resource with the following settings (be sure to select the **sample** database option on the **Additional settings** tab!):
19 | - **Basics**:
20 | - **Subscription**: *Select your Azure subscription*
21 | - **Resource group**: *Create or select a resource group where you want to create the SQL Database resource*
22 | - **Database name**: `Adventureworks`
23 | - **Server**: Create a new server with the following settings:
24 | - **Server name**: *A unique name*
25 | - **Location**: *Select any available region*
26 | - **Authentication method**: Use Microsoft Entra-only authentication
27 | - **Select Microsoft Entra admin**: *Select your own user account*
28 | - **Want to use SQL elastic pool?**: No
29 | - **Workload environment**: Development
30 | - **Compute + storage**: General purpose - serverless *(with the default configuration)*
31 | - **Backup storage redundancy**: Locally-redundant backup storage
32 | - **Networking**:
33 | - **Connectivity method**: Public endpoint
34 | - **Firewall rules**:
35 | - **Allow Azure services and resources to access this server**: Yes
36 | - **Add current client IP address**: Yes
37 | - **Connection policy**: Default
38 | - **Minimum TLS version**: TLS 1.2
39 | - **Security**:
40 | - **Enable Microsoft Defender for SQL**: Not now
41 | - **Ledger**: Not configured
42 | - **Server identity**: Not configured
43 | - **Transparent data encryption key management**:
44 | - **Server level key**: Service-managed key selected
45 | - **Database level key**: Not configured
46 | - **Enable secure enclaves**: Off
47 | - **Additional settings**:
48 | - **Use existing data**: Sample *(Confirm that **AdventureWorksLT** database will be created)*
49 | - **Tags**:
50 | - None
51 | 1. Wait for deployment to complete. Then go to the **Adventureworks** SQL Database resource you deployed.
52 |
53 | ## Open the query editor
54 |
55 | The query editor is a browser-based interface that you can use to run Transact-SQL statements in your database.
56 |
57 | 1. In the Azure portal, on the page for your **Adventureworks** SQL Database, in the pane on the left, select **Query editor**.
58 | 1. On the welcome page, sign into your database using Entra authentication (if necessary, allow access from your client IP address first).
59 | 1. In the query editor, expand the **Tables** folder to view the tables in the database.
60 |
61 | > **Note**: If you're familiar with the standard **AdventureWorks** sample database for Microsoft SQL Server, you may notice that we are using a simplified, lightweight (*LT*) version with fewer tables.
62 |
63 | 1. In the **Query 1** pane, enter the following Transact-SQL code:
64 |
65 | ```sql
66 | SELECT * FROM SalesLT.Product;
67 | ```
68 |
69 | 1. Use the **▷ Run** button to run the query, and and after a few seconds, review the results, which includes all columns for all products.
70 | 1. Close the Query editor page, discarding your changes if prompted.
71 |
72 | Now that you've created the database and learned how to use the query editor to run Transact-SQL code, you can return to the query editor in the Azure Portal at any time to complete the lab exercises.
73 |
74 | > **Tip**: When you've finished with the database, delete the resources you created in your Azure subscription to avoid unnecessary charges.
75 |
--------------------------------------------------------------------------------
/Instructions/Labs/00b-setup-fabric.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Lab Environment Setup - Microsoft Fabric'
4 | module: 'Setup'
5 | ---
6 |
7 | # Lab Environment Setup
8 |
9 | You can complete the Transact-SQL exercises in a sample database in Microsoft Fabric. Use the instructions in this page to prepare a suitable Fabric Database environment.
10 |
11 | > **Note**: You need access to [Microsoft Fabric](https://learn.microsoft.com/fabric/get-started/fabric-trial) with sufficient permissions to create a Fabric Database to complete this exercise.
12 |
13 | ## Create a workspace
14 |
15 | Before working with data in Fabric, create a workspace.
16 |
17 | 1. Open the [Microsoft Fabric home page](https://app.fabric.microsoft.com/home?experience=fabric) at `https://app.fabric.microsoft.com/home?experience=fabric`, signing in with your credentials if prompted.
18 | 1. Create a new **Workspace** with a name of your choice, selecting a licensing mode in the **Advanced** section that includes Fabric capacity (*Trial*, *Premium*, or *Fabric*).
19 | 1. When your new workspace opens, it should be empty.
20 |
21 | ## Provision Fabric Database
22 |
23 | Now, you need to provision an instance of Fabric Database with a sample database that you can query.
24 |
25 | 1. In your new empty workspace, create a new **SQL Database** item named `Adventureworks`.
26 | 1. When the new **Adventureworks** database has been created, select the **Sample data** option to import the sample database schema and data.
27 |
28 | Wait for the sample data to be imported. This may take a few minutes.
29 |
30 | 1. After the data has been imported, refresh the **Adventureworks** database node in the **Explorer** pane and then expand it to see the tables under the **SalesLT** schema.
31 |
32 | > **Note**: If you're familiar with the standard **AdventureWorks** sample database for Microsoft SQL Server, you may notice that we are using a simplified, lightweight (*LT*) version with fewer tables.
33 |
34 | ## Open the query editor
35 |
36 | The query editor is a browser-based interface that you can use to run Transact-SQL statements in your database.
37 |
38 | 1. In your **Adventureworks** Fabric database, create a new query.
39 | 1. In the **SQL query 1** pane, enter the following Transact-SQL code:
40 |
41 | ```sql
42 | SELECT * FROM SalesLT.Product;
43 | ```
44 |
45 | 1. Use the **▷ Run** button to run the query, and and after a few seconds, review the results, which includes all columns for all products.
46 | 1. Close the Query editor page.
47 |
48 | Now that you've created the database and learned how to use the query editor to run Transact-SQL code, you can return to the query editor in your Fabric workspace at any time to complete the lab exercises.
49 |
50 | > **Tip**: When you've finished with the database, delete the workspace you created to avoid unnecessary charges.
51 |
--------------------------------------------------------------------------------
/Instructions/Labs/01-get-started-with-tsql.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Get Started with Transact-SQL'
4 | module: 'Module 1: Getting Started with Transact-SQL'
5 | ---
6 |
7 | # Get Started with Transact-SQL
8 |
9 | In this exercise, you will use some basic SELECT queries to retrieve data from the **AdventureWorks** database.
10 |
11 | > **Note**: This exercise assumes you have created the sample **AdventureWorks** database.
12 |
13 | ## Use SELECT queries to retrieve data
14 |
15 | The SELECT statement is the primary Transact-SQL statement used to query tables in a database.
16 |
17 | 1. Open a query editor for your **AdventureWorks** database, and create a new query.
18 | 1. In the query editor, enter the following code:
19 |
20 | ```sql
21 | SELECT * FROM SalesLT.Product;
22 | ```
23 |
24 | 1. Run the query, and and after a few seconds, review the results, which includes all columns for all products.
25 | 1. In the query editor, modify the query as follows:
26 |
27 | ```sql
28 | SELECT Name, StandardCost, ListPrice
29 | FROM SalesLT.Product;
30 | ```
31 |
32 | 1. Re-run the query, and and after a few seconds, review the results, which this time include only the **Name**, **StandardCost**, and **ListPrice** columns for all products.
33 | 1. Modify the query as shown below to include an expression that results in a calculated column, and then re-run the query:
34 |
35 | ```sql
36 | SELECT Name, ListPrice - StandardCost
37 | FROM SalesLT.Product;
38 | ```
39 |
40 | 1. Note that the results this time include the **Name** column and an unnamed numeric column containing the result of subtracting the **StandardCost** from the **ListPrice**.
41 | 1. Modify the query as shown below to assign names to the columns in the results, and then re-run the query.
42 |
43 | ```sql
44 | SELECT Name AS ProductName, ListPrice - StandardCost AS Markup
45 | FROM SalesLT.Product;
46 | ```
47 |
48 | 1. Note that the results now include columns named **ProductName** and **Markup**. The **AS** keyword has been used to assign an *alias* for each column in the results.
49 | 1. Replace the existing query with the following code, which also includes an expression that produces a calculated column in the results:
50 |
51 | ```sql
52 | SELECT ProductNumber, Color, Size, Color + ', ' + Size AS ProductDetails
53 | FROM SalesLT.Product;
54 | ```
55 |
56 | 1. Run the query, and note that the **+** operator in the calculated **ProductDetails** column is used to *concatenate* the **Color** and **Size** column values (with a literal comma between them). The behavior of this operator is determined by the data types of the columns - had they been numeric values, the **+** operator would have *added* them. Note also that some results are *NULL* - we'll explore NULL values later in this lab.
57 |
58 | ## Work with data types
59 |
60 | As you just saw, columns in a table are defined as specific data types, which affects the operations you can perform on them.
61 |
62 | 1. Replace the existing query with the following code, and run it:
63 |
64 | ```sql
65 | SELECT ProductID + ': ' + Name AS ProductName
66 | FROM SalesLT.Product;
67 | ```
68 |
69 | 2. Note that this query returns an error. The **+** operator can be used to *concatenate* text-based values, or *add* numeric values; but in this case there's one numeric value (**ProductID**) and one text-based value (**Name**), so it's unclear how the operator should be applied.
70 | 3. Modify the query as follows, and re-run it:
71 |
72 | ```sql
73 | SELECT CAST(ProductID AS varchar(5)) + ': ' + Name AS ProductName
74 | FROM SalesLT.Product;
75 | ```
76 |
77 | 4. Note that the effect of the **CAST** function is to change the numeric **ProductID** column into a **varchar** (variable-length character data) value that can be concatenated with other text-based values.
78 |
79 | 5. Modify the query to replace the **CAST** function with a **CONVERT** function as shown below, and then re-run it:
80 |
81 | ```sql
82 | SELECT CONVERT(varchar(5), ProductID) + ': ' + Name AS ProductName
83 | FROM SalesLT.Product;
84 | ```
85 |
86 | 6. Note that the results of using **CONVERT** are the same as for **CAST**. The **CAST** function is an ANSI standard part of the SQL language that is available in most database systems, while **CONVERT** is a SQL Server specific function.
87 |
88 | 7. Another key difference between the two functions is that **CONVERT** includes an additional parameter that can be useful for formatting date and time values when converting them to text-based data. For example, replace the existing query with the following code and run it.
89 |
90 | ```sql
91 | SELECT SellStartDate,
92 | CONVERT(nvarchar(30), SellStartDate) AS ConvertedDate,
93 | CONVERT(nvarchar(30), SellStartDate, 126) AS ISO8601FormatDate
94 | FROM SalesLT.Product;
95 | ```
96 |
97 | 8. Replace the existing query with the following code, and run it.
98 |
99 | ```sql
100 | SELECT Name, CAST(Size AS Integer) AS NumericSize
101 | FROM SalesLT.Product;
102 | ```
103 |
104 | 9. Note that an error is returned because some **Size** values are not numeric (for example, some item sizes are indicated as *S*, *M*, or *L*).
105 |
106 | 10. Modify the query to use a **TRY_CAST** function, as shown here.
107 |
108 | ```sql
109 | SELECT Name, TRY_CAST(Size AS Integer) AS NumericSize
110 | FROM SalesLT.Product;
111 | ```
112 |
113 | 11. Run the query and note that the numeric **Size** values are converted successfully to integers, but that non-numeric sizes are returned as *NULL*.
114 |
115 | ## Handle NULL values
116 |
117 | We've seen some examples of queries that return *NULL* values. *NULL* is generally used to denote a value that is *unknown*. Note that this is not the same as saying the value is *none* - that would imply that you *know* that the value is zero or an empty string!
118 |
119 | 1. Modify the existing query as shown here:
120 |
121 | ```sql
122 | SELECT Name, ISNULL(TRY_CAST(Size AS Integer),0) AS NumericSize
123 | FROM SalesLT.Product;
124 | ```
125 |
126 | 2. Run the query and view the results. Note that the **ISNULL** function replaces *NULL* values with the specified value, so in this case, sizes that are not numeric (and therefore can't be converted to integers) are returned as **0**.
127 |
128 | In this example, the **ISNULL** function is applied to the output of the inner **TRY_CAST** function, but you can also use it to deal with *NULL* values in the source table.
129 |
130 | 3. Replace the query with the following code to handle *NULL* values for **Color** and **Size** values in the source table:
131 |
132 | ```sql
133 | SELECT ProductNumber, ISNULL(Color, '') + ', ' + ISNULL(Size, '') AS ProductDetails
134 | FROM SalesLT.Product;
135 | ```
136 |
137 | The **ISNULL** function replaces *NULL* values with a specified literal value. Sometimes, you may want to achieve the opposite result by replacing an explicit value with *NULL*. To do this, you can use the **NULLIF** function.
138 |
139 | 4. Try the following query, which replaces the **Color** value "Multi" to *NULL*.
140 |
141 | ```sql
142 | SELECT Name, NULLIF(Color, 'Multi') AS SingleColor
143 | FROM SalesLT.Product;
144 | ```
145 |
146 | In some scenarios, you might want to compare multiple columns and find the first one that isn't *NULL*. For example, suppose you want to track the status of a product's availability based on the dates recorded when it was first offered for sale or removed from sale. A product that is currently available will have a **SellStartDate**, but the **SellEndDate** value will be *NULL*. When a product is no longer sold, a date is entered in its **SellEndDate** column. To find the first non-*NULL* column, you can use the **COALESCE** function.
147 |
148 | 5. Use the following query to find the first non-*NULL* date for product selling status.
149 |
150 | ```sql
151 | SELECT Name, COALESCE(SellEndDate, SellStartDate) AS StatusLastUpdated
152 | FROM SalesLT.Product;
153 | ```
154 |
155 | The previous query returns the last date on which the product selling status was updated, but doesn't actually tell us the sales status itself. To determine that, we'll need to check the dates to see if the **SellEndDate** is *NULL*. To do this, you can use a **CASE** expression in the **SELECT** clause to check for *NULL* **SellEndDate** values. The **CASE** expression has two variants: a *simple* **CASE** that evaluates a specific column or value, or a *searched* **CASE** that evaluates one or more expressions.
156 |
157 | In this example, our **CASE** expression must determine if the **SellEndDate** column is *NULL*. Typically, when you are trying to check the value of a column you can use the **=** operator; for example the predicate **SellEndDate = '01/01/2005'** returns **True** if the **SellEndDate** value is *01/01/2005*, and **False** otherwise. However, when dealing with *NULL* values, the default behavior may not be what you expect. Remember that *NULL* actually means *unknown*, so using the **=** operator to compare two unknown values always results in a value of *NULL* - semantically, it's impossible to know if one unknown value is the same as another. To check to see if a value is *NULL*, you must use the **IS NULL** predicate; and conversely to check that a value is not *NULL* you can use the **IS NOT NULL** predicate.
158 |
159 | 6. Run the following query, which includes *searched* **CASE** that uses an **IS NULL** expression to check for *NULL* **SellEndDate** values.
160 |
161 | ```sql
162 | SELECT Name,
163 | CASE
164 | WHEN SellEndDate IS NULL THEN 'Currently for sale'
165 | ELSE 'No longer available'
166 | END AS SalesStatus
167 | FROM SalesLT.Product;
168 | ```
169 |
170 | The previous query used a *searched* **CASE** expression, which begins with a **CASE** keyword, and includes one or more **WHEN...THEN** expressions with the values and predicates to be checked. An **ELSE** expression provides a value to use if none of the **WHEN** conditions are matched, and the **END** keyword denotes the end of the **CASE** expression, which is aliased to a column name for the result using an **AS** expression.
171 |
172 | In some queries, it's more appropriate to use a *simple* **CASE** expression that applies multiple **WHERE...THEN** predictes to the same value.
173 |
174 | 7. Run the following query to see an example of a *simple* **CASE** expression that produced different results depending on the **Size** column value.
175 |
176 | ```sql
177 | SELECT Name,
178 | CASE Size
179 | WHEN 'S' THEN 'Small'
180 | WHEN 'M' THEN 'Medium'
181 | WHEN 'L' THEN 'Large'
182 | WHEN 'XL' THEN 'Extra-Large'
183 | ELSE ISNULL(Size, 'n/a')
184 | END AS ProductSize
185 | FROM SalesLT.Product;
186 | ```
187 |
188 | 8. Review the query results and note that the **ProductSize** column contains the text-based description of the size for *S*, *M*, *L*, and *XL* sizes; the measurement value for numeric sizes, and *n/a* for any other sizes values.
189 |
190 | ## Challenges
191 |
192 | Now that you've seen some examples of **SELECT** statements that retrieve data from a table, it's time to try to compose some queries of your own.
193 |
194 | > **Tip**: Try to determine the appropriate queries for yourself. If you get stuck, suggested answers are provided at the end of this lab.
195 |
196 | ### Challenge 1: Retrieve customer data
197 |
198 | Adventure Works Cycles sells directly to retailers, who then sell products to consumers. Each retailer that is an Adventure Works customer has provided a named contact for all communication from Adventure Works. The sales manager at Adventure Works has asked you to generate some reports containing details of the company’s customers to support a direct sales campaign.
199 |
200 | 1. Retrieve customer details
201 | - Familiarize yourself with the **SalesLT.Customer** table by writing a Transact-SQL query that retrieves all columns for all customers.
202 | 2. Retrieve customer name data
203 | - Create a list of all customer contact names that includes the title, first name, middle name (if any), last name, and suffix (if any) of all customers.
204 | 3. Retrieve customer names and phone numbers
205 | - Each customer has an assigned salesperson. You must write a query to create a call sheet that lists:
206 | - The salesperson
207 | - A column named **CustomerName** that displays how the customer contact should be greeted (for example, *Mr Smith*)
208 | - The customer’s phone number.
209 |
210 | ### Challenge 2: Retrieve customer order data
211 |
212 | As you continue to work with the Adventure Works customer data, you must create queries for reports that have been requested by the sales team.
213 |
214 | 1. Retrieve a list of customer companies
215 | - You have been asked to provide a list of all customer companies in the format *Customer ID* : *Company Name* - for example, *78: Preferred Bikes*.
216 | 2. Retrieve a list of sales order revisions
217 | - The **SalesLT.SalesOrderHeader** table contains records of sales orders. You have been asked to retrieve data for a report that shows:
218 | - The purchase order number and revision number in the format * ()* – for example *PO348186287 (2)*.
219 | - The order date converted to ANSI standard *102* format (*yyyy.mm.dd* – for example *2015.01.31*).
220 |
221 | ### Challenge 3: Retrieve customer contact details
222 |
223 | Some records in the database include missing or unknown values that are returned as NULL. You must create some queries that handle these NULL values appropriately.
224 |
225 | 1. Retrieve customer contact names with middle names if known
226 | - You have been asked to write a query that returns a list of customer names. The list must consist of a single column in the format *first last* (for example *Keith Harris*) if the middle name is unknown, or *first middle last* (for example *Jane M. Gates*) if a middle name is known.
227 | 2. Retrieve primary contact details
228 | - Customers may provide Adventure Works with an email address, a phone number, or both. If an email address is available, then it should be used as the primary contact method; if not, then the phone number should be used. You must write a query that returns a list of customer IDs in one column, and a second column named **PrimaryContact** that contains the email address if known, and otherwise the phone number.
229 |
230 | **IMPORTANT**: In the sample data provided, there are no customer records without an email address. Therefore, to verify that your query works as expected, run the following **UPDATE** statement to remove some existing email addresses before creating your query:
231 |
232 | ```sql
233 | UPDATE SalesLT.Customer
234 | SET EmailAddress = NULL
235 | WHERE CustomerID % 7 = 1;
236 | ```
237 |
238 | 3. Retrieve shipping status
239 | - You have been asked to create a query that returns a list of sales order IDs and order dates with a column named **ShippingStatus** that contains the text *Shipped* for orders with a known ship date, and *Awaiting Shipment* for orders with no ship date.
240 |
241 | **IMPORTANT**: In the sample data provided, there are no sales order header records without a ship date. Therefore, to verify that your query works as expected, run the following UPDATE statement to remove some existing ship dates before creating your query.
242 |
243 | ```sql
244 | UPDATE SalesLT.SalesOrderHeader
245 | SET ShipDate = NULL
246 | WHERE SalesOrderID > 71899;
247 | ```
248 |
249 | ## Challenge Solutions
250 |
251 | This section contains suggested solutions for the challenge queries.
252 |
253 | ### Challenge 1
254 |
255 | 1. Retrieve customer details:
256 |
257 | ```sql
258 | SELECT * FROM SalesLT.Customer;
259 | ```
260 |
261 | 2. Retrieve customer name data:
262 |
263 | ```sql
264 | SELECT Title, FirstName, MiddleName, LastName, Suffix
265 | FROM SalesLT.Customer;
266 | ```
267 |
268 | 3. Retrieve customer names and phone numbers:
269 |
270 | ```sql
271 | SELECT Salesperson, ISNULL(Title,'') + ' ' + LastName AS CustomerName, Phone
272 | FROM SalesLT.Customer;
273 | ```
274 |
275 | ### Challenge 2
276 |
277 | 1. Retrieve a list of customer companies:
278 |
279 | ```sql
280 | SELECT CAST(CustomerID AS varchar) + ': ' + CompanyName AS CustomerCompany
281 | FROM SalesLT.Customer;
282 | ```
283 |
284 | 2. Retrieve a list of sales order revisions:
285 |
286 | ```sql
287 | SELECT PurchaseOrderNumber + ' (' + STR(RevisionNumber, 1) + ')' AS OrderRevision,
288 | CONVERT(nvarchar(30), OrderDate, 102) AS OrderDate
289 | FROM SalesLT.SalesOrderHeader;
290 | ```
291 |
292 | ### Challenge 3
293 |
294 | 1. Retrieve customer contact names with middle names if known:
295 |
296 | ```sql
297 | SELECT FirstName + ' ' + ISNULL(MiddleName + ' ', '') + LastName AS CustomerName
298 | FROM SalesLT.Customer;
299 | ```
300 |
301 | 2. Retrieve primary contact details:
302 |
303 | ```sql
304 | SELECT CustomerID, COALESCE(EmailAddress, Phone) AS PrimaryContact
305 | FROM SalesLT.Customer;
306 | ```
307 |
308 | 3. Retrieve shipping status:
309 |
310 | ```sql
311 | SELECT SalesOrderID, OrderDate,
312 | CASE
313 | WHEN ShipDate IS NULL THEN 'Awaiting Shipment'
314 | ELSE 'Shipped'
315 | END AS ShippingStatus
316 | FROM SalesLT.SalesOrderHeader;
317 | ```
318 |
--------------------------------------------------------------------------------
/Instructions/Labs/02-filter-sort.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Sort and Filter Query Results'
4 | module: 'Module 2: Sorting and Filtering Query Results'
5 | ---
6 |
7 | # Sort and Filter Query Results
8 |
9 | In this exercise, you'll use the Transact-SQL **SELECT** statement to query and filter data in the **AdventureWorks** database.
10 |
11 | > **Note**: This exercise assumes you have created the sample **AdventureWorks** database.
12 |
13 | ## Sort results using the ORDER BY clause
14 |
15 | It's often useful to sort query results into a particular order.
16 |
17 | 1. Open a query editor for your **AdventureWorks** database, and create a new query.
18 | 1. Type the following query to return the **Name** and **ListPrice** of all products:
19 |
20 | ```sql
21 | SELECT Name, ListPrice
22 | FROM SalesLT.Product;
23 | ```
24 |
25 | 1. Run the query and note that the results are presented in no particular order.
26 | 1. Modify the query to add an **ORDER BY** clause that sorts the results by **Name**, as shown here:
27 |
28 | ```sql
29 | SELECT Name, ListPrice
30 | FROM SalesLT.Product
31 | ORDER BY Name;
32 | ```
33 |
34 | 1. Run the query and review the results. This time the products are listed in alphabetical order by **Name**.
35 | 1. Modify the query as shown below to sort the results by **ListPrice**.
36 |
37 | ```sql
38 | SELECT Name, ListPrice
39 | FROM SalesLT.Product
40 | ORDER BY ListPrice;
41 | ```
42 |
43 | 1. Run the query and note that the results are listed in ascending order of **ListPrice**. By default, the **ORDER BY** clause applies an ascending sort order to the specified field.
44 | 1. Modify the query as shown below to sort the results into descending order of **ListPrice**.
45 |
46 | ```sql
47 | SELECT Name, ListPrice
48 | FROM SalesLT.Product
49 | ORDER BY ListPrice DESC;
50 | ```
51 |
52 | 1. Run the query and note that the results now show the most expensive items first.
53 | 1. Modify the query as shown below to sort the results into descending order of **ListPrice**, and then into ascending order of **Name**.
54 |
55 | ```sql
56 | SELECT Name, ListPrice
57 | FROM SalesLT.Product
58 | ORDER BY ListPrice DESC, Name ASC;
59 | ```
60 |
61 | 1. Run the query and review the results. Note that they are sorted into descending order of **ListPrice**, and each set of products with the same price is sorted in ascending order of **Name**.
62 |
63 | ## Restrict results using TOP
64 |
65 | Sometimes you only want to return a specific number of rows. For example, you might want to find the twenty most expensive products.
66 |
67 | 1. Modify the existing query to return the **Name** and **ListPrice** of all products:
68 |
69 | ```sql
70 | SELECT TOP (20) Name, ListPrice
71 | FROM SalesLT.Product
72 | ORDER BY ListPrice DESC;
73 | ```
74 |
75 | 2. Run the query and note that the results contain the first twenty products in descending order of **ListPrice**. Typically, you include an **ORDER BY** clause when using the **TOP** parameter; otherwise the query just returns the first specified number of rows in an arbitrary order.
76 | 3. Modify the query to add the **WITH TIES** parameter as shown here, and re-run it.
77 |
78 | ```sql
79 | SELECT TOP (20) WITH TIES Name, ListPrice
80 | FROM SalesLT.Product
81 | ORDER BY ListPrice DESC;
82 | ```
83 |
84 | 4. This time, there are 21 rows in the results, because there are multiple products that share the same price, one of which wasn't included when ties were ignored by the previous query.
85 | 5. Modify the query to add the **PERCENT** parameter as shown here, and re-run it.
86 |
87 | ```sql
88 | SELECT TOP (20) PERCENT WITH TIES Name, ListPrice
89 | FROM SalesLT.Product
90 | ORDER BY ListPrice DESC;
91 | ```
92 |
93 | 6. Note that this time the results contain the 20% most expensive products.
94 |
95 | ## Retrieve pages of results with OFFSET and FETCH
96 |
97 | User interfaces and reports often present large volumes of data as pages, you make them easier to navigate on a screen.
98 |
99 | 1. Modify the existing query to return product **Name** and **ListPrice** values:
100 |
101 | ```sql
102 | SELECT Name, ListPrice
103 | FROM SalesLT.Product
104 | ORDER BY Name OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY;
105 | ```
106 |
107 | 2. Run the query and note the effect of the **OFFSET** and **FETCH** parameters of the **ORDER BY** clause. The results start at the 0 position (the beginning of the result set) and include only the next 10 rows, essentially defining the first page of results with 10 rows per page.
108 | 3. Modify the query as shown here, and run it to retrieve the next page of results.
109 |
110 | ```sql
111 | SELECT Name, ListPrice
112 | FROM SalesLT.Product
113 | ORDER BY Name OFFSET 10 ROWS FETCH NEXT 10 ROWS ONLY;
114 | ```
115 |
116 | ## Use the ALL and DISTINCT options
117 |
118 | Often, multiple rows in a table may contain the same values for a given subset of fields. For example, a table of products might contain a **Color** field that identifies the color of a given product. It's not unreasonable to assume that there may be multiple products of the same color. Similarly, the table might contain a **Size** field; and again it's not unreasonable to assume that there may be multiple products of the same size; or even multiple products with the same combination of size and color.
119 |
120 | 1. Start Azure Data Studio, and create a new query (you can do this from the **File** menu or on the *welcome* page).
121 | 2. In the new **SQLQuery_...** pane, use the **Connect** button to connect the query to the **AdventureWorks** saved connection.
122 | 3. In the query editor, enter the following code:
123 |
124 | ```sql
125 | SELECT Color
126 | FROM SalesLT.Product;
127 | ```
128 |
129 | 4. Use the **⏵Run** button to run the query, and and after a few seconds, review the results, which includes the color of each product in the table.
130 |
131 | 5. Modify the query as follows, and re-run it.
132 |
133 | ```sql
134 | SELECT ALL Color
135 | FROM SalesLT.Product;
136 | ```
137 |
138 | The results should be the same as before. The **ALL** parameter is the default behavior, and is applied implicitly to return a row for every record that meets the query criteria.
139 |
140 | 6. Modify the query to replace **ALL** with **DISTINCT**, as shown here:
141 |
142 | ```sql
143 | SELECT DISTINCT Color
144 | FROM SalesLT.Product;
145 | ```
146 |
147 | 7. Run the modified query and note that the results include one row for each unique **Color** value. This ability to remove duplicates from the results can often be useful - for example to retrieve values in order to populate a drop-down list of color options in a user interface.
148 |
149 | 9. Modify the query to add the **Size** field as shown here:
150 |
151 | ```sql
152 | SELECT DISTINCT Color, Size
153 | FROM SalesLT.Product;
154 | ```
155 |
156 | 8. Run the modified query and note that it returns each unique combination of color and size.
157 |
158 | ## Filter results with the WHERE clause
159 |
160 | Most queries for application development or reporting involve filtering the data to match specified criteria. You typically apply filtering criteria as a predicate in a **WHERE** clause of a query.
161 |
162 | 1. In Azure Data Studio, replace the existing query with the following code:
163 |
164 | ```sql
165 | SELECT Name, Color, Size
166 | FROM SalesLT.Product
167 | WHERE ProductModelID = 6
168 | ORDER BY Name;
169 | ```
170 |
171 | 2. Run the query and review the results, which contain the **Name**, **Color**, and **Size** for each product with a **ProductModelID** value of *6* (this is the ID for the *HL Road Frame* product model, of which there are multiple variants).
172 | 3. Replace the query with the following code, which uses the *not equal* (<>) operator, and run it.
173 |
174 | ```sql
175 | SELECT Name, Color, Size
176 | FROM SalesLT.Product
177 | WHERE ProductModelID <> 6
178 | ORDER BY Name;
179 | ```
180 |
181 | 4. Review the results, noting that they contain all products with a **ProductModelID** other than **6**.
182 | 5. Replace the query with the following code, and run it.
183 |
184 | ```sql
185 | SELECT Name, ListPrice
186 | FROM SalesLT.Product
187 | WHERE ListPrice > 1000.00
188 | ORDER BY ListPrice;
189 | ```
190 |
191 | 6. Review the results, noting that they contain all products with a **ListPrice** greater than 1000.00.
192 | 7. Modify the query as follows, and run it.
193 |
194 | ```sql
195 | SELECT Name, ListPrice
196 | FROM SalesLT.Product
197 | WHERE Name LIKE 'HL Road Frame %';
198 | ```
199 |
200 | 8. Review the results, noting that the **LIKE** operator enables you to match string patterns. The **%** character in the predicate is a wildcard for one or more characters, so the query returns all rows where the **Name** is *HL Road Frame* followed by any string.
201 |
202 | The **LIKE** operator can be used to define complex pattern matches based on regular expressions, which can be useful when dealing with string data that follows a predictable pattern.
203 |
204 | 9. Modify the query as follows, and run it.
205 |
206 | ```sql
207 | SELECT Name, ListPrice
208 | FROM SalesLT.Product
209 | WHERE ProductNumber LIKE 'FR-_[0-9][0-9]_-[0-9][0-9]';
210 | ```
211 |
212 | 10. Review the results. This time the results include products with a **ProductNumber** that matches patterns similar to FR-*xNNx*-*NN* (in which *x* is a letter and *N* is a numeral).
213 |
214 | **Tip**: To learn more about pattern-matching with the **LIKE** operator, see the [Transact-SQL documentation](https://docs.microsoft.com/sql/t-sql/language-elements/like-transact-sql).
215 |
216 | 11. Modify the query as follows, and run it.
217 |
218 | ```sql
219 | SELECT Name, ListPrice
220 | FROM SalesLT.Product
221 | WHERE SellEndDate IS NOT NULL;
222 | ```
223 |
224 | 12. Note that to filter based on *NULL* values you must use **IS NULL** (or **IS NOT NULL**) you cannot compare a *NULL* value using the **=** operator.
225 | 13. Now try the following query, which uses the **BETWEEN** operator to define a filter based on values within a defined range.
226 |
227 | ```sql
228 | SELECT Name
229 | FROM SalesLT.Product
230 | WHERE SellEndDate BETWEEN '2006/1/1' AND '2006/12/31';
231 | ```
232 |
233 | 14. Review the results, which contain products that the company stopped selling in 2006.
234 |
235 | 15. Run the following query, which retrieves products with a **ProductCategoryID** value that is in a specified list.
236 |
237 | ```sql
238 | SELECT ProductCategoryID, Name, ListPrice
239 | FROM SalesLT.Product
240 | WHERE ProductCategoryID IN (5,6,7);
241 | ```
242 |
243 | 16. Now try the following query, which uses the **AND** operator to combine two criteria.
244 |
245 | ```sql
246 | SELECT ProductCategoryID, Name, ListPrice, SellEndDate
247 | FROM SalesLT.Product
248 | WHERE ProductCategoryID IN (5,6,7) AND SellEndDate IS NULL;
249 | ```
250 |
251 | 17. Try the following query, which filters the results to include rows that match one (or both) of two criteria.
252 |
253 | ```sql
254 | SELECT Name, ProductCategoryID, ProductNumber
255 | FROM SalesLT.Product
256 | WHERE ProductNumber LIKE 'FR%' OR ProductCategoryID IN (5,6,7);
257 | ```
258 |
259 | ## Challenges
260 |
261 | Now that you've seen some examples of filtering and sorting data, it's your chance to put what you've learned into practice.
262 |
263 | > **Tip**: Try to determine the appropriate queries for yourself. If you get stuck, suggested answers are provided at the end of this lab.
264 |
265 | ### Challenge 1: Retrieve data for transportation reports
266 |
267 | The logistics manager at Adventure Works has asked you to generate some reports containing details of the company’s customers to help to reduce transportation costs.
268 |
269 | 1. Retrieve a list of cities
270 | - Initially, you need to produce a list of all of you customers' locations. Write a Transact-SQL query that queries the **SalesLT.Address** table and retrieves the values for **City** and **StateProvince**, removing duplicates and sorted in ascending order of city.
271 | 2. Retrieve the heaviest products
272 | - Transportation costs are increasing and you need to identify the heaviest products. Retrieve the names of the top ten percent of products by weight.
273 |
274 | ### Challenge 2: Retrieve product data
275 |
276 | The Production Manager at Adventure Works would like you to create some reports listing details of the products that you sell.
277 |
278 | 1. Retrieve product details for product model 1
279 | - Initially, you need to find the names, colors, and sizes of the products with a product model ID 1.
280 | 2. Filter products by color and size
281 | - Retrieve the product number and name of the products that have a color of *black*, *red*, or *white* and a size of *S* or *M*.
282 | 3. Filter products by product number
283 | - Retrieve the product number, name, and list price of products whose product number begins *BK-*
284 | 4. Retrieve specific products by product number
285 | - Modify your previous query to retrieve the product number, name, and list price of products whose product number begins *BK-* followed by any character other than *R*, and ends with a *-* followed by any two numerals.
286 |
287 | ## Challenge Solutions
288 |
289 | This section contains suggested solutions for the challenge queries.
290 |
291 | ### Challenge 1
292 |
293 | 1. Retrieve a list of cities:
294 |
295 | ```sql
296 | SELECT DISTINCT City, StateProvince
297 | FROM SalesLT.Address
298 | ORDER BY City
299 | ```
300 |
301 | 2. Retrieve the heaviest products:
302 |
303 | ```sql
304 | SELECT TOP (10) PERCENT WITH TIES Name
305 | FROM SalesLT.Product
306 | ORDER BY Weight DESC;
307 | ```
308 |
309 | ### Challenge 2
310 |
311 | 1. Retrieve product details for product model 1:
312 |
313 | ```sql
314 | SELECT Name, Color, Size
315 | FROM SalesLT.Product
316 | WHERE ProductModelID = 1;
317 | ```
318 |
319 | 2. Filter products by color and size:
320 |
321 | ```sql
322 | SELECT ProductNumber, Name
323 | FROM SalesLT.Product
324 | WHERE Color IN ('Black','Red','White') AND Size IN ('S','M');
325 | ```
326 |
327 | 3. Filter products by product number:
328 |
329 | ```sql
330 | SELECT ProductNumber, Name, ListPrice
331 | FROM SalesLT.Product
332 | WHERE ProductNumber LIKE 'BK-%';
333 | ```
334 |
335 | 4. Retrieve specific products by product number:
336 |
337 | ```sql
338 | SELECT ProductNumber, Name, ListPrice
339 | FROM SalesLT.Product
340 | WHERE ProductNumber LIKE 'BK-[^R]%-[0-9][0-9]';
341 | ```
342 |
--------------------------------------------------------------------------------
/Instructions/Labs/03a-joins.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Query Multiple Tables with Joins'
4 | module: 'Module 3: Using Joins and Subqueries'
5 | ---
6 |
7 | # Query Multiple Tables with Joins
8 |
9 | In this exercise, you'll use the Transact-SQL **SELECT** statement to query multiple tables in the **Adventureworks** database.
10 |
11 | > **Note**: This exercise assumes you have created the sample **AdventureWorks** database.
12 |
13 | ## Use inner joins
14 |
15 | An inner join is used to find related data in two tables. For example, suppose you need to retrieve data about a product and its category from the **SalesLT.Product** and **SalesLT.ProductCategory** tables. You can find the relevant product category record for a product based on its **ProductCategoryID** field; which is a foreign-key in the product table that matches a primary key in the product category table.
16 |
17 | 1. Open a query editor for your **AdventureWorks** database, and create a new query.
18 | 1. In the query editor, enter the following code:
19 |
20 | ```sql
21 | SELECT SalesLT.Product.Name AS ProductName, SalesLT.ProductCategory.Name AS Category
22 | FROM SalesLT.Product
23 | INNER JOIN SalesLT.ProductCategory
24 | ON SalesLT.Product.ProductCategoryID = SalesLT.ProductCategory.ProductCategoryID;
25 | ```
26 |
27 | 1. Run the query, and after a few seconds, review the results, which include the **ProductName** from the products table and the corresponding **Category** from the product category table. Because the query uses an **INNER** join, any products that do not have corresponding categories, and any categories that contain no products are omitted from the results.
28 |
29 | 1. Modify the query as follows to remove the **INNER** keyword, and re-run it.
30 |
31 | ```sql
32 | SELECT SalesLT.Product.Name AS ProductName, SalesLT.ProductCategory.Name AS Category
33 | FROM SalesLT.Product
34 | JOIN SalesLT.ProductCategory
35 | ON SalesLT.Product.ProductCategoryID = SalesLT.ProductCategory.ProductCategoryID;
36 | ```
37 |
38 | The results should be the same as before. **INNER** joins are the default kind of join.
39 |
40 | 1. Modify the query to assign aliases to the tables in the **JOIN** clause, as shown here:
41 |
42 | ```sql
43 | SELECT p.Name AS ProductName, c.Name AS Category
44 | FROM SalesLT.Product AS p
45 | JOIN SalesLT.ProductCategory AS c
46 | ON p.ProductCategoryID = c.ProductCategoryID;
47 | ```
48 |
49 | 1. Run the modified query and confirm that it returns the same results as before. The use of table aliases can greatly simplify a query, particularly when multiple joins must be used.
50 |
51 | 1. Replace the query with the following code, which retrieves sales order data from the **SalesLT.SalesOrderHeader**, **SalesLT.SalesOrderDetail**, and **SalesLT.Product** tables:
52 |
53 | ```sql
54 | SELECT oh.OrderDate, oh.PurchaseOrderNumber, p.Name AS ProductName, od.OrderQty, od.UnitPrice
55 | FROM SalesLT.SalesOrderHeader AS oh
56 | JOIN SalesLT.SalesOrderDetail AS od
57 | ON od.SalesOrderID = oh.SalesOrderID
58 | JOIN SalesLT.Product AS p
59 | ON od.ProductID = p.ProductID
60 | ORDER BY oh.OrderDate, oh.SalesOrderID, od.SalesOrderDetailID;
61 | ```
62 |
63 | 1. Run the modified query and note that it returns data from all three tables.
64 |
65 | ## Use outer joins
66 |
67 | An outer join is used to retrieve all rows from one table, and any corresponding rows from a related table. In cases where a row in the outer table has no corresponding rows in the related table, *NULL* values are returned for the related table fields. For example, suppose you want to retrieve a list of all customers and any orders they have placed, including customers who have registered but never placed an order.
68 |
69 | 1. Replace the existing query with the following code:
70 |
71 | ```sql
72 | SELECT c.FirstName, c.LastName, oh.PurchaseOrderNumber
73 | FROM SalesLT.Customer AS c
74 | LEFT OUTER JOIN SalesLT.SalesOrderHeader AS oh
75 | ON c.CustomerID = oh.CustomerID
76 | ORDER BY c.CustomerID;
77 | ```
78 |
79 | 2. Run the query and note that the results contain data for every customer. If a customer has placed an order, the order number is shown. Customers who have registered but not placed an order are shown with a *NULL* order number.
80 |
81 | Note the use of the **LEFT** keyword. This identifies which of the tables in the join is the *outer* table (the one from which all rows should be preserved). In this case, the join is between the **Customer** and **SalesOrderHeader** tables, so a **LEFT** join designates **Customer** as the outer table. Had a **RIGHT** join been used, the query would have returned all records from the **SalesOrderHeader** table and only matching data from the **Customer** table (in other words, all orders including those for which there was no matching customer record). You can also use a **FULL** outer join to preserve unmatched rows from *both* sides of the join (all customers, including those who haven't placed an order; and all orders, including those with no matching customer), though in practice this is used less frequently.
82 |
83 | 3. Modify the query to remove the **OUTER** keyword, as shown here:
84 |
85 | ```sql
86 | SELECT c.FirstName, c.LastName, oh.PurchaseOrderNumber
87 | FROM SalesLT.Customer AS c
88 | LEFT JOIN SalesLT.SalesOrderHeader AS oh
89 | ON c.CustomerID = oh.CustomerID
90 | ORDER BY c.CustomerID;
91 | ```
92 |
93 | 4. Run the query and review the results, which should be the same as before. Using the **LEFT** (or **RIGHT**) keyword automatically identifies the join as an **OUTER** join.
94 | 5. Modify the query as shown below to take advantage of the fact that it identifies non-matching rows and return only the customers who have not placed any orders.
95 |
96 | ```sql
97 | SELECT c.FirstName, c.LastName, oh.PurchaseOrderNumber
98 | FROM SalesLT.Customer AS c
99 | LEFT JOIN SalesLT.SalesOrderHeader AS oh
100 | ON c.CustomerID = oh.CustomerID
101 | WHERE oh.SalesOrderNumber IS NULL
102 | ORDER BY c.CustomerID;
103 | ```
104 |
105 | 6. Run the query and review the results, which contain data for customers who have not placed any orders.
106 | 7. Replace the query with the following one, which uses outer joins to retrieve data from three tables.
107 |
108 | ```sql
109 | SELECT p.Name As ProductName, oh.PurchaseOrderNumber
110 | FROM SalesLT.Product AS p
111 | LEFT JOIN SalesLT.SalesOrderDetail AS od
112 | ON p.ProductID = od.ProductID
113 | LEFT JOIN SalesLT.SalesOrderHeader AS oh
114 | ON od.SalesOrderID = oh.SalesOrderID
115 | ORDER BY p.ProductID;
116 | ```
117 |
118 | 8. Run the query and note that the results include all products, with order numbers for any that have been purchased. This required a sequence of joins from **Product** to **SalesOrderDetail** to **SalesOrderHeader**. Note that when you join multiple tables like this, after an outer join has been specified in the join sequence, all subsequent outer joins must be of the same direction (**LEFT** or **RIGHT**).
119 | 9. Modify the query as shown below to add an inner join to return category information. When mixing inner and outer joins, it can be helpful to be explicit about the join types by using the **INNER** and **OUTER** keywords.
120 |
121 | ```sql
122 | SELECT p.Name As ProductName, c.Name AS Category, oh.PurchaseOrderNumber
123 | FROM SalesLT.Product AS p
124 | LEFT OUTER JOIN SalesLT.SalesOrderDetail AS od
125 | ON p.ProductID = od.ProductID
126 | LEFT OUTER JOIN SalesLT.SalesOrderHeader AS oh
127 | ON od.SalesOrderID = oh.SalesOrderID
128 | INNER JOIN SalesLT.ProductCategory AS c
129 | ON p.ProductCategoryID = c.ProductCategoryID
130 | ORDER BY p.ProductID;
131 | ```
132 |
133 | 10. Run the query and review the results, which include product names, categories, and sales order numbers.
134 |
135 | ## Use a cross join
136 |
137 | A *cross* join matches all possible combinations of rows from the tables being joined. In practice, it's rarely used; but there are some specialized cases where it is useful.
138 |
139 | 1. Replace the existing query with the following code:
140 |
141 | ```sql
142 | SELECT p.Name, c.FirstName, c.LastName, c.EmailAddress
143 | FROM SalesLT.Product AS p
144 | CROSS JOIN SalesLT.Customer AS c;
145 | ```
146 |
147 | 2. Run the query and note that the results contain a row for every product and customer combination (which might be used to create a mailing campaign in which an indivdual advertisement for each product is emailed to each customer - a strategy that may not endear the company to its customers!).
148 |
149 | ## Use a self join
150 |
151 | A *self* join isn't actually a specific kind of join, but it's a technique used to join a table to itself by defining two instances of the table, each with its own alias. This approach can be useful when a row in the table includes a foreign key field that references the primary key of the same table; for example in a table of employees where an employee's manager is also an employee, or a table of product categories where each category might be a subcategory of another category.
152 |
153 | 1. Replace the existing query with the following code, which includes a self join between two instances of the **SalesLT.ProductCategory** table (with aliases **cat** and **pcat**):
154 |
155 | ```sql
156 | SELECT pcat.Name AS ParentCategory, cat.Name AS SubCategory
157 | FROM SalesLT.ProductCategory AS cat
158 | JOIN SalesLT.ProductCategory pcat
159 | ON cat.ParentProductCategoryID = pcat.ProductCategoryID
160 | ORDER BY ParentCategory, SubCategory;
161 | ```
162 |
163 | 2. Run the query and review the results, which reflect the hierarchy of parent and sub categories.
164 |
165 | ## Challenges
166 |
167 | Now that you've seen some examples of joins, it's your turn to try retrieving data from multiple tables for yourself.
168 |
169 | > **Tip**: Try to determine the appropriate queries for yourself. If you get stuck, suggested answers are provided at the end of this lab.
170 |
171 | ### Challenge 1: Generate invoice reports
172 |
173 | Adventure Works Cycles sells directly to retailers, who must be invoiced for their orders. You have been tasked with writing a query to generate a list of invoices to be sent to customers.
174 |
175 | 1. Retrieve customer orders
176 | - As an initial step towards generating the invoice report, write a query that returns the company name from the **SalesLT.Customer** table, and the purchase order number and total due (calculated as the sub-total + tax + freight) from the **SalesLT.SalesOrderHeader** table.
177 | 2. Retrieve customer orders with addresses
178 | - Extend your customer orders query to include the *Main Office* address for each customer, including the full street address, city, state or province, postal code, and country or region
179 | - **Tip**: Note that each customer can have multiple addressees in the **SalesLT.Address** table, so the database developer has created the **SalesLT.CustomerAddress** table to enable a many-to-many relationship between customers and addresses. Your query will need to include both of these tables, and should filter the results so that only *Main Office* addresses are included.
180 |
181 | ### Challenge 2: Retrieve customer data
182 |
183 | As you continue to work with the Adventure Works customer and sales data, you must create queries for reports that have been requested by the sales team.
184 |
185 | 1. Retrieve a list of all customers and their orders
186 | - The sales manager wants a list of all customer companies and their contacts (first name and last name), showing the purchase order number and total due for each order they have placed. Customers who have not placed any orders should be included at the bottom of the list with NULL values for the purchase order number and total due.
187 | 2. Retrieve a list of customers with no address
188 | - A sales employee has noticed that Adventure Works does not have address information for all customers. You must write a query that returns a list of customer IDs, company names, contact names (first name and last name), and phone numbers for customers with no address stored in the database.
189 |
190 | ### Challenge 3: Create a product catalog
191 |
192 | The marketing team has asked you to retrieve data for a new product catalog.
193 |
194 | 1. Retrieve product information by category
195 | - The product catalog will list products by parent category and subcategory, so you must write a query that retrieves the parent category name, subcategory name, and product name fields for the catalog.
196 |
197 | ## Challenge Solutions
198 |
199 | This section contains suggested solutions for the challenge queries.
200 |
201 | ### Challenge 1
202 |
203 | 1. Retrieve customer orders:
204 |
205 | ```sql
206 | SELECT c.CompanyName,
207 | oh.PurchaseOrderNumber,
208 | oh.SubTotal + oh.TaxAmt + oh.Freight As TotalDue
209 | FROM SalesLT.Customer AS c
210 | JOIN SalesLT.SalesOrderHeader AS oh
211 | ON oh.CustomerID = c.CustomerID;
212 | ```
213 |
214 | 2. Retrieve customer orders with addresses:
215 |
216 | ```sql
217 | SELECT c.CompanyName,
218 | a.AddressLine1,
219 | ISNULL(a.AddressLine2, '') AS AddressLine2,
220 | a.City,
221 | a.StateProvince,
222 | a.PostalCode,
223 | a.CountryRegion,
224 | oh.PurchaseOrderNumber,
225 | oh.SubTotal + oh.TaxAmt + oh.Freight As TotalDue
226 | FROM SalesLT.Customer AS c
227 | JOIN SalesLT.SalesOrderHeader AS oh
228 | ON oh.CustomerID = c.CustomerID
229 | JOIN SalesLT.CustomerAddress AS ca
230 | ON c.CustomerID = ca.CustomerID
231 | JOIN SalesLT.Address AS a
232 | ON ca.AddressID = a.AddressID
233 | WHERE ca.AddressType = 'Main Office';
234 | ```
235 |
236 | ### Challenge 2
237 |
238 | 1. Retrieve a list of all customers and their orders:
239 |
240 | ```sql
241 | SELECT c.CompanyName, c.FirstName, c.LastName,
242 | oh.PurchaseOrderNumber,
243 | oh.SubTotal + oh.TaxAmt + oh.Freight As TotalDue
244 | FROM SalesLT.Customer AS c
245 | LEFT JOIN SalesLT.SalesOrderHeader AS oh
246 | ON c.CustomerID = oh.CustomerID
247 | ORDER BY oh.PurchaseOrderNumber DESC;
248 | ```
249 |
250 | 2. Retrieve a list of customers with no address:
251 |
252 | ```sql
253 | SELECT c.CompanyName, c.FirstName, c.LastName, c.Phone
254 | FROM SalesLT.Customer AS c
255 | LEFT JOIN SalesLT.CustomerAddress AS ca
256 | ON c.CustomerID = ca.CustomerID
257 | WHERE ca.AddressID IS NULL;
258 | ```
259 |
260 | ### Challenge 3
261 |
262 | 1. Retrieve product information by category:
263 |
264 | ```sql
265 | SELECT pcat.Name AS ParentCategory, cat.Name AS SubCategory, prd.Name AS ProductName
266 | FROM SalesLT.ProductCategory pcat
267 | JOIN SalesLT.ProductCategory AS cat
268 | ON pcat.ProductCategoryID = cat.ParentProductCategoryID
269 | JOIN SalesLT.Product AS prd
270 | ON prd.ProductCategoryID = cat.ProductCategoryID
271 | ORDER BY ParentCategory, SubCategory, ProductName;
272 | ```
273 |
--------------------------------------------------------------------------------
/Instructions/Labs/03b-subqueries.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Use Subqueries'
4 | module: 'Module 3: Using Joins and Subqueries'
5 | ---
6 |
7 | # Use Subqueries
8 |
9 | In this exercise, you'll use subqueries to retrieve data from tables in the **adventureworks** database.
10 |
11 | > **Note**: This exercise assumes you have created the sample **AdventureWorks** database.
12 |
13 | ## Use simple subqueries
14 |
15 | A subquery is a query that is nested within another query. The subquery is often referred to as the *inner* query, and the query within which it is nested is referred to as the *outer* query.
16 |
17 | 1. Open a query editor for your **AdventureWorks** database, and create a new query.
18 | 1. In the query editor, enter the following code:
19 |
20 | ```sql
21 | SELECT MAX(UnitPrice)
22 | FROM SalesLT.SalesOrderDetail;
23 | ```
24 |
25 | 1. Run the query, and and after a few seconds, review the results, which consists of the maximum **UnitPrice** in the **SalesLT.SalesOrderDetail** (the highest price for which any individual product has been sold).
26 |
27 | 1. Modify the query as follows to use the query you just ran as a subquery in an outer query that retrieves products with a **ListPrice** higher than the maximum selling price.
28 |
29 | ```sql
30 | SELECT Name, ListPrice
31 | FROM SalesLT.Product
32 | WHERE ListPrice >
33 | (SELECT MAX(UnitPrice)
34 | FROM SalesLT.SalesOrderDetail);
35 | ```
36 |
37 | 1. Run the query and review the results, which include all products that have a **listPrice** that is higher than the maximum price for which any product has been sold.
38 | 1. Replace the existing query with the following code:
39 |
40 | ```sql
41 | SELECT DISTINCT ProductID
42 | FROM SalesLT.SalesOrderDetail
43 | WHERE OrderQty >= 20;
44 | ```
45 |
46 | 1. Run the query and note that it returns the **ProductID** for each product that has been ordered in quantities of 20 or more.
47 | 1. Modify the query as follows to use it in a subquery that finds the names of the products that have been ordered in quantities of 20 or more.
48 |
49 | ```sql
50 | SELECT Name FROM SalesLT.Product
51 | WHERE ProductID IN
52 | (SELECT DISTINCT ProductID
53 | FROM SalesLT.SalesOrderDetail
54 | WHERE OrderQty >= 20);
55 | ```
56 |
57 | 1. Run the query and note that it returns the product names.
58 | 1. Replace the query with the following code:
59 |
60 | ```sql
61 | SELECT DISTINCT Name
62 | FROM SalesLT.Product AS p
63 | JOIN SalesLT.SalesOrderDetail AS o
64 | ON p.ProductID = o.ProductID
65 | WHERE OrderQty >= 20;
66 | ```
67 |
68 | 1. Run the query and note that it returns the same results. Often you can achieve the same outcome with a subquery or a join, and often a subquery approach can be more easily interpreted by a developer looking at the code than a complex join query because the operation can be broken down into discrete components. In most cases, the performance of equivalent join or subquery operations is similar, but in some cases where existence checks need to be performed, joins perform better.
69 |
70 | ## Use correlated subqueries
71 |
72 | So far, the subqueries we've used have been independent of the outer query. In some cases, you might need to use an inner subquery that references a value in the outer query. Conceptually, the inner query runs once for each row returned by the outer query (which is why correlated subqueries are sometimes referred to as *repeating subqueries*).
73 |
74 | 1. Replace the existing query with the following code:
75 |
76 | ```sql
77 | SELECT od.SalesOrderID, od.ProductID, od.OrderQty
78 | FROM SalesLT.SalesOrderDetail AS od
79 | ORDER BY od.ProductID;
80 | ```
81 |
82 | 2. Run the query and note that the results contain the order ID, product ID, and quantity for each sale of a product.
83 | 3. Modify the query as follows to filter it using a subquery in the **WHERE** clause that retrieves the maximum purchased quantity for each product retrieved by the outer query. Note that the inner query references a table alias that is declared in the outer query.
84 |
85 | ```sql
86 | SELECT od.SalesOrderID, od.ProductID, od.OrderQty
87 | FROM SalesLT.SalesOrderDetail AS od
88 | WHERE od.OrderQty =
89 | (SELECT MAX(OrderQty)
90 | FROM SalesLT.SalesOrderDetail AS d
91 | WHERE od.ProductID = d.ProductID)
92 | ORDER BY od.ProductID;
93 | ```
94 |
95 | 4. Run the query and review the results, which should only contain product order records for which the quantity ordered is the maximum ordered for that product.
96 | 5. Replace the query with the following code:
97 |
98 | ```sql
99 | SELECT o.SalesOrderID, o.OrderDate, o.CustomerID
100 | FROM SalesLT.SalesOrderHeader AS o
101 | ORDER BY o.SalesOrderID;
102 | ```
103 |
104 | 6. Run the query and note that it returns the order ID, order date, and customer ID for each order that has been placed.
105 | 7. Modify the query as follows to retrieve the company name for each customer using a correlated subquery in the **SELECT** clause.
106 |
107 | ```sql
108 | SELECT o.SalesOrderID, o.OrderDate,
109 | (SELECT CompanyName
110 | FROM SalesLT.Customer AS c
111 | WHERE c.CustomerID = o.CustomerID) AS CompanyName
112 | FROM SalesLT.SalesOrderHeader AS o
113 | ORDER BY o.SalesOrderID;
114 | ```
115 |
116 | 8. Run the query, and verify that the company name is returned for each customer found by the outer query.
117 |
118 | ## Challenges
119 |
120 | Now it's your opportunity to try using subqueries to retrieve data.
121 |
122 | > **Tip**: Try to determine the appropriate queries for yourself. If you get stuck, suggested answers are provided at the end of this lab.
123 |
124 | ### Challenge 1: Retrieve product price information
125 |
126 | Adventure Works products each have a standard cost price that indicates the cost of manufacturing the product, and a list price that indicates the recommended selling price for the product. This data is stored in the **SalesLT.Product** table. Whenever a product is ordered, the actual unit price at which it was sold is also recorded in the **SalesLT.SalesOrderDetail** table. You must use subqueries to compare the cost and list prices for each product with the unit prices charged in each sale.
127 |
128 | 1. Retrieve products whose list price is higher than the average unit price.
129 | - Retrieve the product ID, name, and list price for each product where the list price is higher than the average unit price for all products that have been sold.
130 | - **Tip**: Use the **AVG** function to retrieve an average value.
131 | 2. Retrieve Products with a list price of 100 or more that have been sold for less than 100.
132 | - Retrieve the product ID, name, and list price for each product where the list price is 100 or more, and the product has been sold for less than 100.
133 |
134 | ### Challenge 2: Analyze profitability
135 |
136 | The standard cost of a product and the unit price at which it is sold determine its profitability. You must use correlated subqueries to compare the cost and average selling price for each product.
137 |
138 | 1. Retrieve the cost, list price, and average selling price for each product
139 | - Retrieve the product ID, name, cost, and list price for each product along with the average unit price for which that product has been sold.
140 | 2. Retrieve products that have an average selling price that is lower than the cost.
141 | - Filter your previous query to include only products where the cost price is higher than the average selling price.
142 |
143 | ## Challenge Solutions
144 |
145 | This section contains suggested solutions for the challenge queries.
146 |
147 | ### Challenge 1
148 |
149 | 1. Retrieve products whose list price is higher than the average unit price:
150 |
151 | ```sql
152 | SELECT ProductID, Name, ListPrice
153 | FROM SalesLT.Product
154 | WHERE ListPrice >
155 | (SELECT AVG(UnitPrice)
156 | FROM SalesLT.SalesOrderDetail)
157 | ORDER BY ProductID;
158 | ```
159 |
160 | 2. Retrieve Products with a list price of 100 or more that have been sold for less than 100:
161 |
162 | ```sql
163 | SELECT ProductID, Name, ListPrice
164 | FROM SalesLT.Product
165 | WHERE ProductID IN
166 | (SELECT ProductID
167 | FROM SalesLT.SalesOrderDetail
168 | WHERE UnitPrice < 100.00)
169 | AND ListPrice >= 100.00
170 | ORDER BY ProductID;
171 | ```
172 |
173 | ### Challenge 2
174 |
175 | 1. Retrieve the cost, list price, and average selling price for each product:
176 |
177 | ```sql
178 | SELECT p.ProductID, p.Name, p.StandardCost, p.ListPrice,
179 | (SELECT AVG(o.UnitPrice)
180 | FROM SalesLT.SalesOrderDetail AS o
181 | WHERE p.ProductID = o.ProductID) AS AvgSellingPrice
182 | FROM SalesLT.Product AS p
183 | ORDER BY p.ProductID;
184 | ```
185 |
186 | 2. Retrieve products that have an average selling price that is lower than the cost:
187 |
188 | ```sql
189 | SELECT p.ProductID, p.Name, p.StandardCost, p.ListPrice,
190 | (SELECT AVG(o.UnitPrice)
191 | FROM SalesLT.SalesOrderDetail AS o
192 | WHERE p.ProductID = o.ProductID) AS AvgSellingPrice
193 | FROM SalesLT.Product AS p
194 | WHERE StandardCost >
195 | (SELECT AVG(od.UnitPrice)
196 | FROM SalesLT.SalesOrderDetail AS od
197 | WHERE p.ProductID = od.ProductID)
198 | ORDER BY p.ProductID;
199 | ```
200 |
--------------------------------------------------------------------------------
/Instructions/Labs/04-built-in-functions.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Use Built-in Functions'
4 | module: 'Module 4: Using Built-in Functions'
5 | ---
6 |
7 | # Use Built-in Functions
8 |
9 | In this exercise, you'll use built-in functions to retrieve and aggregate data in the **Adventureworks** database.
10 |
11 | > **Note**: This exercise assumes you have created the sample **AdventureWorks** database.
12 |
13 | ## Scalar functions
14 |
15 | Transact-SQL provides a large number of functions that you can use to extract additional information from your data. Most of these functions are *scalar* functions that return a single value based on one or more input parameters, often a data field.
16 |
17 | **Tip**: We don't have enough time in this exercise to explore every function available in Transact-SQL. To learn more about the functions covered in this exercise, and more, view the [Transact-SQL documentation](https://docs.microsoft.com/sql/t-sql/functions/functions).
18 |
19 | 1. Open a query editor for your **AdventureWorks** database, and create a new query.
20 | 1. In the query editor, enter the following code:
21 |
22 | ```sql
23 | SELECT YEAR(SellStartDate) AS SellStartYear, ProductID, Name
24 | FROM SalesLT.Product
25 | ORDER BY SellStartYear;
26 | ```
27 |
28 | 1. Run the query, and and after a few seconds, review the results, noting that the **YEAR** function has retrieved the year from the **SellStartDate** field.
29 |
30 | 1. Modify the query as follows to use some additional scalar functions that operate on *datetime* values.
31 |
32 | ```sql
33 | SELECT YEAR(SellStartDate) AS SellStartYear,
34 | DATENAME(mm,SellStartDate) AS SellStartMonth,
35 | DAY(SellStartDate) AS SellStartDay,
36 | DATENAME(dw, SellStartDate) AS SellStartWeekday,
37 | DATEDIFF(yy,SellStartDate, GETDATE()) AS YearsSold,
38 | ProductID,
39 | Name
40 | FROM SalesLT.Product
41 | ORDER BY SellStartYear;
42 | ```
43 |
44 | 1. Run the query and review the results.
45 |
46 | Note that the **DATENAME** function returns a different value depending on the *datepart* parameter that is passed to it. In this example, **mm** returns the month name, and **dw** returns the weekday name.
47 |
48 | Note also that the **DATEDIFF** function returns the specified time interval between and start date and an end date. In this case the interval is measured in years (**yy**), and the end date is determined by the **GETDATE** function; which when used with no parameters returns the current date and time.
49 |
50 | 1. Replace the existing query with the following code.
51 |
52 | ```sql
53 | SELECT CONCAT(FirstName + ' ', LastName) AS FullName
54 | FROM SalesLT.Customer;
55 | ```
56 |
57 | 1. Run the query and note that it returns the concatenated first and last name for each customer.
58 | 1. Replace the query with the following code to explore some more functions that manipulate string-based values.
59 |
60 | ```sql
61 | SELECT UPPER(Name) AS ProductName,
62 | ProductNumber,
63 | ROUND(Weight, 0) AS ApproxWeight,
64 | LEFT(ProductNumber, 2) AS ProductType,
65 | SUBSTRING(ProductNumber,CHARINDEX('-', ProductNumber) + 1, 4) AS ModelCode,
66 | SUBSTRING(ProductNumber, LEN(ProductNumber) - CHARINDEX('-', REVERSE(RIGHT(ProductNumber, 3))) + 2, 2) AS SizeCode
67 | FROM SalesLT.Product;
68 | ```
69 |
70 | 1. Run the query and note that it returns the following data:
71 | - The product name, converted to upper case by the **UPPER** function.
72 | - The product number, which is a string code that encapsulates details of the product.
73 | - The weight of the product, rounded to the nearest whole number by using the **ROUND** function.
74 | - The product type, which is indicated by the first two characters of the product number, starting from the left (using the **LEFT** function).
75 | - The model code, which is extracted from the product number by using the **SUBSTRING** function, which extracts the four characters immediately following the first *-* character, which is found using the **CHARINDEX** function.
76 | - The size code, which is extracted using the **SUBSTRING** function to extract the two characters following the last *-* in the product code. The last *-* character is found by taking the total length (**LEN**) of the product ID and finding its index (**CHARINDEX**) in the reversed (**REVERSE**) first three characters from the right (**RIGHT**). This example shows how you can combine functions to apply fairly complex logic to extract the values you need.
77 |
78 | ## Use logical functions
79 |
80 | *Logical* functions are used to apply logical tests to values, and return an appropriate value based on the results of the logical evaluation.
81 |
82 | 1. Replace the existing query with the following code.
83 |
84 | ```sql
85 | SELECT Name, Size AS NumericSize
86 | FROM SalesLT.Product
87 | WHERE ISNUMERIC(Size) = 1;
88 | ```
89 |
90 | 2. Run the query and note that the results only products with a numeric size.
91 | 3. Replace the query with the following code, which nests the **ISNUMERIC** function used previously in an **IIF** function; which in turn evaluates the result of the **ISNUMERIC** function and returns *Numeric* if the result is **1** (*true*), and *Non-Numeric* otherwise.
92 |
93 | ```sql
94 | SELECT Name, IIF(ISNUMERIC(Size) = 1, 'Numeric', 'Non-Numeric') AS SizeType
95 | FROM SalesLT.Product;
96 | ```
97 |
98 | 4. Run the query and review the results.
99 | 5. Replace the query with the following code:
100 |
101 | ```sql
102 | SELECT prd.Name AS ProductName,
103 | cat.Name AS Category,
104 | CHOOSE (cat.ParentProductCategoryID, 'Bikes','Components','Clothing','Accessories') AS ProductType
105 | FROM SalesLT.Product AS prd
106 | JOIN SalesLT.ProductCategory AS cat
107 | ON prd.ProductCategoryID = cat.ProductCategoryID;
108 | ```
109 |
110 | 6. Run the query and note that the **CHOOSE** function returns the value in the ordinal position in a list based on the a specified index value. The list index is 1-based so in this query the function returns *Bikes* for category 1, *Components* for category 2, and so on.
111 |
112 | ## Use aggregate functions
113 |
114 | *Aggregate* functions return an aggregated value, such as a sum, count, average, minimum, or maximum.
115 |
116 | 1. Replace the existing query with the following code.
117 |
118 | ```sql
119 | SELECT COUNT(*) AS Products,
120 | COUNT(DISTINCT ProductCategoryID) AS Categories,
121 | AVG(ListPrice) AS AveragePrice
122 | FROM SalesLT.Product;
123 | ```
124 |
125 | 2. Run the query and note that the following aggregations are returned:
126 | - The number of products in the table. This is returned by using the **COUNT** function to count the number of rows (**\***).
127 | - The number of categories. This is returned by using rhe **COUNT** function to count the number of distinct category IDs in the table.
128 | - The average price of a product. This is returned by using the **AVG** function with the **ListPrice** field.
129 | 3. Replace the query with the following code.
130 |
131 | ```sql
132 | SELECT COUNT(p.ProductID) AS BikeModels, AVG(p.ListPrice) AS AveragePrice
133 | FROM SalesLT.Product AS p
134 | JOIN SalesLT.ProductCategory AS c
135 | ON p.ProductCategoryID = c.ProductCategoryID
136 | WHERE c.Name LIKE '%Bikes';
137 | ```
138 |
139 | 4. Run the query, noting that it returns the number of models and the average price for products with category names that end in "bikes".
140 |
141 | ## Group aggregated results with the GROUP BY clause
142 |
143 | Aggregate functions are especially useful when combined with the **GROUP BY** clause to calculate aggregations for different groups of data.
144 |
145 | 1. Replace the existing query with the following code.
146 |
147 | ```sql
148 | SELECT Salesperson, COUNT(CustomerID) AS Customers
149 | FROM SalesLT.Customer
150 | GROUP BY Salesperson
151 | ORDER BY Salesperson;
152 | ```
153 |
154 | 2. Run the query and note that it returns the number of customers assigned to each salesperson.
155 | 3. Replace the query with the following code:
156 |
157 | ```sql
158 | SELECT c.Salesperson, SUM(oh.SubTotal) AS SalesRevenue
159 | FROM SalesLT.Customer c
160 | JOIN SalesLT.SalesOrderHeader oh
161 | ON c.CustomerID = oh.CustomerID
162 | GROUP BY c.Salesperson
163 | ORDER BY SalesRevenue DESC;
164 | ```
165 |
166 | 4. Run the query, noting that it returns the total sales revenue for each salesperson who has completed any sales.
167 | 5. Modify the query as follows to use an outer join:
168 |
169 | ```sql
170 | SELECT c.Salesperson, ISNULL(SUM(oh.SubTotal), 0.00) AS SalesRevenue
171 | FROM SalesLT.Customer c
172 | LEFT JOIN SalesLT.SalesOrderHeader oh
173 | ON c.CustomerID = oh.CustomerID
174 | GROUP BY c.Salesperson
175 | ORDER BY SalesRevenue DESC;
176 | ```
177 |
178 | 6. Run the query, noting that it returns the sales totals for salespeople who have sold items, and 0.00 for those who haven't.
179 |
180 | ## Filter groups with the HAVING clause
181 |
182 | After grouping data, you may want to filter the results to include only the groups that meet specified criteria. For example, you may want to return only salespeople with more than 100 customers.
183 |
184 | 1. Replace the existing query with the following code, which you may think would return salespeople with more than 100 customers (but you'd be wrong, as you will see!)
185 |
186 | ```sql
187 | SELECT Salesperson, COUNT(CustomerID) AS Customers
188 | FROM SalesLT.Customer
189 | WHERE COUNT(CustomerID) > 100
190 | GROUP BY Salesperson
191 | ORDER BY Salesperson;
192 | ```
193 |
194 | 2. Run the query and note that it returns an error. The **WHERE** clause is applied *before* the aggregations and the **GROUP BY** clause, so you can't use it to filter on the aggregated value.
195 | 3. Modify the query as follows to add a **HAVING** clause, which is applied *after* the aggregations and **GROUP BY** clause.
196 |
197 | ```sql
198 | SELECT Salesperson, COUNT(CustomerID) AS Customers
199 | FROM SalesLT.Customer
200 | GROUP BY Salesperson
201 | HAVING COUNT(CustomerID) > 100
202 | ORDER BY Salesperson;
203 | ```
204 |
205 | 4. Run the query, and note that it returns only salespeople who have more than 100 customers assigned to them.
206 |
207 | ## Challenges
208 |
209 | Now it's time to try using functions to retrieve data in some queries of your own.
210 |
211 | > **Tip**: Try to determine the appropriate queries for yourself. If you get stuck, suggested answers are provided at the end of this lab.
212 |
213 | ### Challenge 1: Retrieve order shipping information
214 |
215 | The operations manager wants reports about order shipping based on data in the **SalesLT.SalesOrderHeader** table.
216 |
217 | 1. Retrieve the order ID and freight cost of each order.
218 | - Write a query to return the order ID for each order, together with the the **Freight** value rounded to two decimal places in a column named **FreightCost**.
219 | 2. Add the shipping method.
220 | - Extend your query to include a column named **ShippingMethod** that contains the **ShipMethod** field, formatted in lower case.
221 | 3. Add shipping date details.
222 | - Extend your query to include columns named **ShipYear**, **ShipMonth**, and **ShipDay** that contain the year, month, and day of the **ShipDate**. The **ShipMonth** value should be displayed as the month name (for example, *June*)
223 |
224 | ### Challenge 2: Aggregate product sales
225 |
226 | The sales manager would like reports that include aggregated information about product sales.
227 |
228 | 1. Retrieve total sales by product
229 | - Write a query to retrieve a list of the product names from the **SalesLT.Product** table and the total number of sales of each product, calculated as the sum of **OrderQty** from the **SalesLT.SalesOrderDetail** table, with the results sorted in descending order of total sales.
230 | 2. Filter the product sales list to include only products that cost over 1,000
231 | - Modify the previous query to include only sales of products that have a list price of more than 1000.
232 | 3. Filter the product sales groups to include only products for which over 20 have been sold
233 | - Modify the previous query to only include only product groups with a total order quantity greater than 20.
234 |
235 | ## Challenge Solutions
236 |
237 | This section contains suggested solutions for the challenge queries.
238 |
239 | ### Challenge 1
240 |
241 | 1. Retrieve the order ID and freight cost of each order:
242 |
243 | ```sql
244 | SELECT SalesOrderID,
245 | ROUND(Freight, 2) AS FreightCost
246 | FROM SalesLT.SalesOrderHeader;
247 | ```
248 |
249 | 2. Add the shipping method:
250 |
251 | ```sql
252 | SELECT SalesOrderID,
253 | ROUND(Freight, 2) AS FreightCost,
254 | LOWER(ShipMethod) AS ShippingMethod
255 | FROM SalesLT.SalesOrderHeader;
256 | ```
257 |
258 | 3. Add shipping date details:
259 |
260 | ```sql
261 | SELECT SalesOrderID,
262 | ROUND(Freight, 2) AS FreightCost,
263 | LOWER(ShipMethod) AS ShippingMethod,
264 | YEAR(ShipDate) AS ShipYear,
265 | DATENAME(mm, ShipDate) AS ShipMonth,
266 | DAY(ShipDate) AS ShipDay
267 | FROM SalesLT.SalesOrderHeader;
268 | ```
269 |
270 | ### Challenge 2
271 |
272 | The product manager would like reports that include aggregated information about product sales.
273 |
274 | 1. Retrieve total sales by product:
275 |
276 | ```sql
277 | SELECT p.Name,SUM(o.OrderQty) AS TotalSales
278 | FROM SalesLT.SalesOrderDetail AS o
279 | JOIN SalesLT.Product AS p
280 | ON o.ProductID = p.ProductID
281 | GROUP BY p.Name
282 | ORDER BY TotalSales DESC;
283 | ```
284 |
285 | 2. Filter the product sales list to include only products that cost over 1,000:
286 |
287 | ```sql
288 | SELECT p.Name,SUM(o.OrderQty) AS TotalSales
289 | FROM SalesLT.SalesOrderDetail AS o
290 | JOIN SalesLT.Product AS p
291 | ON o.ProductID = p.ProductID
292 | WHERE p.ListPrice > 1000
293 | GROUP BY p.Name
294 | ORDER BY TotalSales DESC;
295 | ```
296 |
297 | 3. Filter the product sales groups to include only products for which over 20 have been sold:
298 |
299 | ```sql
300 | SELECT p.Name,SUM(o.OrderQty) AS TotalSales
301 | FROM SalesLT.SalesOrderDetail AS o
302 | JOIN SalesLT.Product AS p
303 | ON o.ProductID = p.ProductID
304 | WHERE p.ListPrice > 1000
305 | GROUP BY p.Name
306 | HAVING SUM(o.OrderQty) > 20
307 | ORDER BY TotalSales DESC;
308 | ```
309 |
--------------------------------------------------------------------------------
/Instructions/Labs/05-modify-data.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Modify Data'
4 | module: 'Module 5: Modifying Data'
5 | ---
6 |
7 | # Modify Data
8 |
9 | In this exercise, you'll insert, update, and delete data in the **Adventureworks** database.
10 |
11 | > **Note**: This exercise assumes you have created the sample **AdventureWorks** database.
12 |
13 | ## Insert data
14 |
15 | You use the **INSERT** statement to insert data into a table.
16 |
17 | 1. Open a query editor for your **AdventureWorks** database, and create a new query.
18 | 1. In the query editor, enter the following code to create a new table named **SalesLT.CallLog**, which we'll use in this exercise.
19 |
20 | ```sql
21 | CREATE TABLE SalesLT.CallLog
22 | (
23 | CallID int IDENTITY PRIMARY KEY NOT NULL,
24 | CallTime datetime NOT NULL DEFAULT GETDATE(),
25 | SalesPerson nvarchar(256) NOT NULL,
26 | CustomerID int NOT NULL REFERENCES SalesLT.Customer(CustomerID),
27 | PhoneNumber nvarchar(25) NOT NULL,
28 | Notes nvarchar(max) NULL
29 | );
30 | ```
31 |
32 | 1. Run the code and create the table. Don't worry too much about the details of the **CREATE TABLE** statement - it creates a table with some fields that we'll use in subsequent tasks to insert, update, and delete data.
33 | 1. Create a new query, so you have two query panes, and in the new pane, enter the following code to query the **SalesLT.CallLog** you just created.
34 |
35 | ```sql
36 | SELECT * FROM SalesLT.CallLog;
37 | ```
38 |
39 | 1. Run the **SELECT** query and view the results, which show the columns in the new table but no rows, because the table is empty.
40 | 1. Switch back to the query pane containing the **CREATE TABLE** statement, and replace it with the following **INSERT** statement to insert a new row into the **SalesLT.CallLog** table.
41 |
42 | ```sql
43 | INSERT INTO SalesLT.CallLog
44 | VALUES
45 | ('2015-01-01T12:30:00', 'adventure-works\pamela0', 1, '245-555-0173', 'Returning call re: enquiry about delivery');
46 | ```
47 |
48 | 1. Run the query and review the message, which should indicate that 1 row was affected.
49 | 1. Switch to the query pane containing the **SELECT** query and run it. Note that the results contain the row you inserted. The **CallID** column is an *identity* column that is automatically incremented (so the first row has the value **1**), and the remaining columns contain the values you specified in the **INSERT** statement
50 | 1. Switch back to the query pane containing the **INSERT** statement, and replace it with the following code to insert another row. This time, the **INSERT** statement takes advantage of the fact that the table has a default value defined for the **CallTime** field, and allows *NULL* values in the **Notes** field.
51 |
52 | ```sql
53 | INSERT INTO SalesLT.CallLog
54 | VALUES
55 | (DEFAULT, 'adventure-works\david8', 2, '170-555-0127', NULL);
56 | ```
57 |
58 | 1. Run the query and review the message, which should indicate that 1 row was affected.
59 | 1. Switch to the query pane containing the **SELECT** query and run it. Note that the second row has been inserted, with the default value for the **CallTime** field (the current time when the row was inserted) and *NULL* for the **Notes** field.
60 | 1. Switch back to the query pane containing the **INSERT** statement, and replace it with the following code to insert another row. This time, the **INSERT** statement explicitly lists the columns into which the new values will be inserted. The columns not specified in the statement support either default or *NULL* values, so they can be omitted.
61 |
62 | ```sql
63 | INSERT INTO SalesLT.CallLog (SalesPerson, CustomerID, PhoneNumber)
64 | VALUES
65 | ('adventure-works\jillian0', 3, '279-555-0130');
66 | ```
67 |
68 | 1. Run the query and review the message, which should indicate that 1 row was affected.
69 | 1. Switch to the query pane containing the **SELECT** query and run it. Note that the third row has been inserted, once again using the default value for the **CallTime** field and *NULL* for the **Notes** field.
70 | 1. Switch back to the query pane containing the **INSERT** statement, and replace it with the following code, which inserts two rows of data into the **SalesLT.CallLog** table.
71 |
72 | ```sql
73 | INSERT INTO SalesLT.CallLog
74 | VALUES
75 | (DATEADD(mi,-2, GETDATE()), 'adventure-works\jillian0', 4, '710-555-0173', NULL),
76 | (DEFAULT, 'adventure-works\shu0', 5, '828-555-0186', 'Called to arrange deliver of order 10987');
77 | ```
78 |
79 | 1. Run the query and review the message, which should indicate that 2 rows were affected.
80 | 1. Switch to the query pane containing the **SELECT** query and run it. Note that two new rows have been added to the table.
81 | 1. Switch back to the query pane containing the **INSERT** statement, and replace it with the following code, which inserts the results of a **SELECT** query into the **SalesLT.CallLog** table.
82 |
83 | ```sql
84 | INSERT INTO SalesLT.CallLog (SalesPerson, CustomerID, PhoneNumber, Notes)
85 | SELECT SalesPerson, CustomerID, Phone, 'Sales promotion call'
86 | FROM SalesLT.Customer
87 | WHERE CompanyName = 'Big-Time Bike Store';
88 | ```
89 |
90 | 1. Run the query and review the message, which should indicate that 2 rows were affected.
91 | 1. Switch to the query pane containing the **SELECT** query and run it. Note that two new rows have been added to the table. These are the rows that were retrieved by the **SELECT** query.
92 | 1. Switch back to the query pane containing the **INSERT** statement, and replace it with the following code, which inserts a row and then uses the **SCOPE_IDENTITY** function to retrieve the most recent *identity* value that has been assigned in the database (to any table), and also the **IDENT_CURRENT** function, which retrieves the latest *identity* value in the specified table.
93 |
94 | ```sql
95 | INSERT INTO SalesLT.CallLog (SalesPerson, CustomerID, PhoneNumber)
96 | VALUES
97 | ('adventure-works\josé1', 10, '150-555-0127');
98 |
99 | SELECT SCOPE_IDENTITY() AS LatestIdentityInDB,
100 | IDENT_CURRENT('SalesLT.CallLog') AS LatestCallID;
101 | ```
102 |
103 | 1. Run the code and review the results, which should be two numeric values, both the same.
104 | 1. Switch to the query pane containing the **SELECT** query and run it to validate that the new row that has been inserted has a **CallID** value that matches the *identity* value returned when you inserted it.
105 | 1. Switch back to the query pane containing the **INSERT** statement, and replace it with the following code, which enables explicit insertion of *identity* values and inserts a new row with a specified **CallID** value, before disabling explicit *identity* insertion again.
106 |
107 | ```sql
108 | SET IDENTITY_INSERT SalesLT.CallLog ON;
109 |
110 | INSERT INTO SalesLT.CallLog (CallID, SalesPerson, CustomerID, PhoneNumber)
111 | VALUES
112 | (20, 'adventure-works\josé1', 11, '926-555-0159');
113 |
114 | SET IDENTITY_INSERT SalesLT.CallLog OFF;
115 | ```
116 |
117 | 1. Run the code and review the results, which should affect 1 row.
118 | 1. Switch to the query pane containing the **SELECT** query and run it to validate that a new row has been inserted with the specific **CallID** value you specified in the **INSERT** statement (9).
119 |
120 | ## Update data
121 |
122 | To modify existing rows in a table, use the **UPDATE** statement.
123 |
124 | 1. On the query pane containing the **INSERT** statement, replace the existing code with the following code.
125 |
126 | ```sql
127 | UPDATE SalesLT.CallLog
128 | SET Notes = 'No notes'
129 | WHERE Notes IS NULL;
130 | ```
131 |
132 | 2. Run the **UPDATE** statement and review the message, which should indicate the number of rows affected.
133 | 3. Switch to the query pane containing the **SELECT** query and run it. Note that the rows that previously had *NULL* values for the **Notes** field now contain the text *No notes*.
134 | 4. Switch back to the query pane containing the **UPDATE** statement, and replace it with the following code, which updates multiple columns.
135 |
136 | ```sql
137 | UPDATE SalesLT.CallLog
138 | SET SalesPerson = '', PhoneNumber = ''
139 | ```
140 |
141 | 5. Run the **UPDATE** statement and note the number of rows affected.
142 | 6. Switch to the query pane containing the **SELECT** query and run it. Note that *all* rows have been updated to remove the **SalesPerson** and **PhoneNumber** fields - this emphasizes the danger of accidentally omitting a **WHERE** clause in an **UPDATE** statement.
143 | 7. Switch back to the query pane containing the **UPDATE** statement, and replace it with the following code, which updates the **SalesLT.CallLog** table based on the results of a **SELECT** query.
144 |
145 | ```sql
146 | UPDATE SalesLT.CallLog
147 | SET SalesPerson = c.SalesPerson, PhoneNumber = c.Phone
148 | FROM SalesLT.Customer AS c
149 | WHERE c.CustomerID = SalesLT.CallLog.CustomerID;
150 | ```
151 |
152 | 8. Run the **UPDATE** statement and note the number of rows affected.
153 | 9. Switch to the query pane containing the **SELECT** query and run it. Note that the table has been updated using the values returned by the **SELECT** statement.
154 |
155 | ## Delete data
156 |
157 | To delete rows in the table, you generally use the **DELETE** statement; though you can also remove all rows from a table by using the **TRUNCATE TABLE** statement.
158 |
159 | 1. On the query pane containing the **UPDATE** statement, replace the existing code with the following code.
160 |
161 | ```sql
162 | DELETE FROM SalesLT.CallLog
163 | WHERE CallTime < DATEADD(dd, -7, GETDATE());
164 | ```
165 |
166 | 2. Run the **DELETE** statement and review the message, which should indicate the number of rows affected.
167 | 3. Switch to the query pane containing the **SELECT** query and run it. Note that rows with a **CallDate** older than 7 days have been deleted.
168 | 4. Switch back to the query pane containing the **DELETE** statement, and replace it with the following code, which uses the **TRUNCATE TABLE** statement to remove all rows in the table.
169 |
170 | ```sql
171 | TRUNCATE TABLE SalesLT.CallLog;
172 | ```
173 |
174 | 5. Run the **TRUNCATE TABLE** statement and note the number of rows affected.
175 | 6. Switch to the query pane containing the **SELECT** query and run it. Note that *all* rows have been deleted from the table.
176 |
177 | ## Challenges
178 |
179 | Now it's your turn to try modifying some data.
180 |
181 | > **Tip**: Try to determine the appropriate code for yourself. If you get stuck, suggested answers are provided at the end of this lab.
182 |
183 | ### Challenge 1: Insert products
184 |
185 | Each Adventure Works product is stored in the **SalesLT.Product** table, and each product has a unique **ProductID** identifier, which is implemented as an *identity* column in the **SalesLT.Product** table. Products are organized into categories, which are defined in the **SalesLT.ProductCategory** table. The products and product category records are related by a common **ProductCategoryID** identifier, which is an *identity* column in the **SalesLT.ProductCategory** table.
186 |
187 | 1. Insert a product
188 | - Adventure Works has started selling the following new product. Insert it into the **SalesLT.Product** table, using default or *NULL* values for unspecified columns:
189 | - **Name**: LED Lights
190 | - **ProductNumber**: LT-L123
191 | - **StandardCost**: 2.56
192 | - **ListPrice**: 12.99
193 | - **ProductCategoryID**: 37
194 | - **SellStartDate**: *Today's date*
195 | - After you have inserted the product, run a query to determine the **ProductID** that was generated.
196 | - Then run a query to view the row for the product in the **SalesLT.Product** table.
197 | 2. Insert a new category with two products
198 | - Adventure Works is adding a product category for *Bells and Horns* to its catalog. The parent category for the new category is **4** (*Accessories*). This new category includes the following two new products:
199 | - First product:
200 | - **Name**: Bicycle Bell
201 | - **ProductNumber**: BB-RING
202 | - **StandardCost**: 2.47
203 | - **ListPrice**: 4.99
204 | - **ProductCategoryID**: *The **ProductCategoryID** for the new Bells and Horns category*
205 | - **SellStartDate**: *Today's date*
206 | - Second product:
207 | - **Name**: Bicycle Horn
208 | - **ProductNumber**: BB-PARP
209 | - **StandardCost**: 1.29
210 | - **ListPrice**: 3.75
211 | - **ProductCategoryID**: *The **ProductCategoryID** for the new Bells and Horns category*
212 | - **SellStartDate**: *Today's date*
213 | - Write a query to insert the new product category, and then insert the two new products with the appropriate **ProductCategoryID** value.
214 | - After you have inserted the products, query the **SalesLT.Product** and **SalesLT.ProductCategory** tables to verify that the data has been inserted.
215 |
216 | ### Challenge 2: Update products
217 |
218 | You have inserted data for a product, but the pricing details are not correct. You must now update the records you have previously inserted to reflect the correct pricing. Tip: Review the documentation for UPDATE in the Transact-SQL Language Reference.
219 |
220 | 1. Update product prices
221 | - The sales manager at Adventure Works has mandated a 10% price increase for all products in the *Bells and Horns* category. Update the rows in the **SalesLT.Product** table for these products to increase their price by 10%.
222 |
223 | 2. Discontinue products
224 | - The new LED lights you inserted in the previous challenge are to replace all previous light products. Update the **SalesLT.Product** table to set the **DiscontinuedDate** to today’s date for all products in the Lights category (product category ID **37**) other than the LED Lights product you inserted previously.
225 |
226 | ### Challenge 3: Delete products
227 |
228 | The Bells and Horns category has not been successful, and it must be deleted from the database.
229 |
230 | 1. Delete a product category and its products
231 | - Delete the records for the *Bells and Horns* category and its products. You must ensure that you delete the records from the tables in the correct order to avoid a foreign-key constraint violation.
232 |
233 | ## Challenge Solutions
234 |
235 | This section contains suggested solutions for the challenge queries.
236 |
237 | ### Challenge 1
238 |
239 | 1. Insert a product:
240 |
241 | ```sql
242 | INSERT INTO SalesLT.Product (Name, ProductNumber, StandardCost, ListPrice, ProductCategoryID, SellStartDate)
243 | VALUES
244 | ('LED Lights', 'LT-L123', 2.56, 12.99, 37, GETDATE());
245 |
246 | SELECT SCOPE_IDENTITY();
247 |
248 | SELECT * FROM SalesLT.Product
249 | WHERE ProductID = SCOPE_IDENTITY();
250 | ```
251 |
252 | 2. Insert a new category with two products:
253 |
254 | ```sql
255 | INSERT INTO SalesLT.ProductCategory (ParentProductCategoryID, Name)
256 | VALUES
257 | (4, 'Bells and Horns');
258 |
259 | INSERT INTO SalesLT.Product (Name, ProductNumber, StandardCost, ListPrice, ProductCategoryID, SellStartDate)
260 | VALUES
261 | ('Bicycle Bell', 'BB-RING', 2.47, 4.99, IDENT_CURRENT('SalesLT.ProductCategory'), GETDATE()),
262 | ('Bicycle Horn', 'BH-PARP', 1.29, 3.75, IDENT_CURRENT('SalesLT.ProductCategory'), GETDATE());
263 |
264 | SELECT c.Name As Category, p.Name AS Product
265 | FROM SalesLT.Product AS p
266 | JOIN SalesLT.ProductCategory as c
267 | ON p.ProductCategoryID = c.ProductCategoryID
268 | WHERE p.ProductCategoryID = IDENT_CURRENT('SalesLT.ProductCategory');
269 | ```
270 |
271 | ### Challenge 2
272 |
273 | 1. Update product prices:
274 |
275 | ```sql
276 | UPDATE SalesLT.Product
277 | SET ListPrice = ListPrice * 1.1
278 | WHERE ProductCategoryID =
279 | (SELECT ProductCategoryID
280 | FROM SalesLT.ProductCategory
281 | WHERE Name = 'Bells and Horns');
282 | ```
283 |
284 | 2. Discontinue products:
285 |
286 | ```sql
287 | UPDATE SalesLT.Product
288 | SET DiscontinuedDate = GETDATE()
289 | WHERE ProductCategoryID = 37
290 | AND ProductNumber <> 'LT-L123';
291 | ```
292 |
293 | ### Challenge 3
294 |
295 | 1. Delete a product category and its products:
296 |
297 | ```sql
298 | DELETE FROM SalesLT.Product
299 | WHERE ProductCategoryID =
300 | (SELECT ProductCategoryID
301 | FROM SalesLT.ProductCategory
302 | WHERE Name = 'Bells and Horns');
303 |
304 | DELETE FROM SalesLT.ProductCategory
305 | WHERE ProductCategoryID =
306 | (SELECT ProductCategoryID
307 | FROM SalesLT.ProductCategory
308 | WHERE Name = 'Bells and Horns');
309 | ```
310 |
--------------------------------------------------------------------------------
/Instructions/Labs/06-use-table-expressions.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Create queries with table expressions'
4 | module: 'Additional exercises'
5 | ---
6 |
7 | # Create queries with table expressions
8 |
9 | In this exercise, you'll use table expressions to query the **Adventureworks** database.
10 |
11 | > **Note**: This exercise assumes you have created the **Adventureworks** database.
12 |
13 | ## Create a view
14 |
15 | A view is a predefined query that you can query like a table.
16 |
17 | 1. Open a query editor for your **Adventureworks** database, and create a new query.
18 | 1. In the query editor, enter the following code to retrieve all products that are classified as road bikes (*ProductCategoryID=6*) from the **SalesLT.Products** table:
19 |
20 | ```sql
21 | SELECT ProductID, Name, ListPrice
22 | FROM SalesLT.Product
23 | WHERE ProductCategoryID = 6;
24 | ```
25 |
26 | 1. Run your query and view the results.
27 |
28 | 1. The query returned all products that are categorized as road bikes. But what if you wanted to use a view for this data to ensure applications don't need to access the underlying table to fetch it? Modify the code to add a CREATE VIEW clause as shown here:
29 |
30 | ```sql
31 | CREATE VIEW SalesLT.vProductsRoadBikes AS
32 | SELECT ProductID, Name, ListPrice
33 | FROM SalesLT.Product
34 | WHERE ProductCategoryID = 6;
35 | ```
36 |
37 | 1. This code creates a view called **vProductsRoadBikes** for all road bikes. Run the code and create the view.
38 |
39 | ## Query a view
40 |
41 | You've created your view. Now you can use it. For example, you can use your view to get a list of any road bikes based on their **ListPrice**.
42 |
43 | 1. In the query editor, replace the code you entered previously with the following code:
44 |
45 | ```sql
46 | SELECT ProductID, Name, ListPrice
47 | FROM SalesLT.vProductsRoadBikes
48 | WHERE ListPrice < 1000;
49 | ```
50 |
51 | 1. Run the query and review the results. You've queried your view and retrieved a list of any road bikes that have a **ListPrice** under 1000. Your query uses your view as a source for the data. This means your applications can use your view for specific searches like this, and won't need to query the underlying table to fetch the data they need.
52 |
53 | ## Use a derived table
54 |
55 | Sometimes you might end up having to rely on complex queries. You can use derived tables in place of those complex queries to avoid adding to their complexity.
56 |
57 | 1. In the query editor, replace the code you entered previously with the following code:
58 |
59 | ```sql
60 | SELECT ProductID, Name, ListPrice,
61 | CASE WHEN ListPrice > 1000 THEN N'High' ELSE N'Normal' END AS PriceType
62 | FROM SalesLT.Product;
63 | ```
64 |
65 | 1. Run the query, which calculates whether the price of a product is considered high or normal.
66 | 1. Now let's further build on this query based on additional criteria, without adding to its complexity. In order to do this, you can create a derived table, which you can think of conceptually as a view that is defined within the context of another query. Replace the previous code with the code below:
67 |
68 | ```sql
69 | SELECT DerivedTable.ProductID, DerivedTable.Name, DerivedTable.ListPrice
70 | FROM
71 | (
72 | SELECT
73 | ProductID, Name, ListPrice,
74 | CASE WHEN ListPrice > 1000 THEN N'High' ELSE N'Normal' END AS PriceType
75 | FROM SalesLT.Product
76 | ) AS DerivedTable
77 | WHERE DerivedTable.PriceType = N'High';
78 | ```
79 |
80 | 1. Run the code, which defines a derived table and fetches the **ProductID**, **Name**, and **ListPrice** of products that have a **PriceType** of *High* only. Your derived table enabled you to easily build on top of your initial query based on your additional criteria, without making the initial query any more complex.
81 |
82 | ## Challenges
83 |
84 | Now it's your turn to use table expressions.
85 |
86 | > **Tip**: Try to determine the appropriate code for yourself. If you get stuck, suggested answers are provided at the end of this lab.
87 |
88 | ### Challenge 1: Create a view
89 |
90 | Adventure Works is forming a new sales team located in Canada. The team wants to create a map of all of the customer addresses in Canada. This team will need access to address details on Canadian customers only. Your manager has asked you to make sure that the team can get the data they require, but ensure that they don't access the underlying source data when getting their information.
91 |
92 | To carry out the task do the following:
93 |
94 | 1. Write a Transact-SQL query to create a view for customer addresses in Canada.
95 | - Create a view based on the following columns in the **SalesLT.Address** table:
96 | - **AddressLine1**
97 | - **City**
98 | - **StateProvince**
99 | - **CountryRegion**
100 | - In your query, use the **CountryRegion** column to filter for addresses located in *Canada* only.
101 |
102 | 1. Query your new view.
103 | - Fetch the rows in your newly created view to ensure it was created successfully. Notice that it only shows address in Canada.
104 |
105 | ### Challenge 2: Use a derived table
106 |
107 | The transportation team at Adventure Works wants to optimize its processes. Products that weigh more than 1000 are considered to be heavy products, and will also need to use a new transportation method if their list price is over 2000. You've been asked to classify products according to their weight, and then provide a list of products that meet both these weight and list price criteria.
108 |
109 | To help, you'll:
110 |
111 | 1. Write a query that classifies products as heavy and normal based on their weight.
112 | - Use the **Weight** column to decide whether a product is heavy or normal.
113 |
114 | 1. Create a derived table based on your query
115 | - Use your derived table to find any heavy products with a list price over 2000.
116 | - Make sure to select the following columns: **ProductID, Name, Weight, ListPrice**.
117 |
118 | ## Challenge Solutions
119 |
120 | This section contains suggested solutions for the challenge queries.
121 |
122 | ### Challenge 1
123 |
124 | 1. Write a Transact-SQL query to create a view for customer addresses in Canada.
125 |
126 | ```sql
127 | CREATE VIEW SalesLT.vAddressCA AS
128 | SELECT AddressLine1, City, StateProvince, CountryRegion
129 | FROM SalesLT.Address
130 | WHERE CountryRegion = 'Canada';
131 | ```
132 |
133 | 1. Query your new view.
134 |
135 | ```sql
136 | SELECT * FROM SalesLT.vAddressCA;
137 | ```
138 |
139 | ### Challenge 2
140 |
141 | 1. Write a query that classifies products as heavy and normal based on their weight.
142 |
143 | ```sql
144 | SELECT ProductID, Name, Weight, ListPrice,
145 | CASE WHEN Weight > 1000 THEN N'Heavy' ELSE N'Normal' END AS WeightType
146 | FROM SalesLT.Product;
147 | ```
148 |
149 | 1. Create a derived table based on your query.
150 |
151 | ```sql
152 | SELECT DerivedTable.ProductID, DerivedTable.Name, DerivedTable.Weight, DerivedTable.ListPrice
153 | FROM
154 | (
155 | SELECT ProductID, Name, Weight, ListPrice,
156 | CASE WHEN Weight > 1000. THEN N'Heavy' ELSE N'Normal' END AS WeightType
157 | FROM SalesLT.Product
158 | ) AS DerivedTable
159 | WHERE DerivedTable.WeightType = N'Heavy' AND DerivedTable.ListPrice > 2000;
160 | ```
161 |
--------------------------------------------------------------------------------
/Instructions/Labs/07-combine-query-results.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Combine query results with set operators'
4 | module: 'Additional exercises'
5 | ---
6 | # Combine query results with set operators
7 |
8 | In this lab, you will use set operators to retrieve results from the **Adventureworks** database.
9 |
10 | > **Note**: This exercise assumes you have created the **Adventureworks** database.
11 |
12 | ## Write a query that uses the UNION operator
13 |
14 | The UNION operator enables you to combine the results from multiple queries into a single result set.
15 |
16 | 1. Open a query editor for your **Adventureworks** database, and create a new query.
17 | 1. In the query editor, enter the following code:
18 |
19 | ```sql
20 | SELECT ProductID, Name
21 | FROM SalesLT.Product
22 | WHERE ProductID NOT IN (SELECT ProductID FROM SalesLT.SalesOrderDetail)
23 | ORDER BY ProductID
24 | ```
25 |
26 | 1. Run the query, which returns the ID and name of all products that have not been sold. Then view the results and messages to observe how many rows were returned by this query.
27 | 1. Under the query to return unsold products, add the following code:
28 |
29 | ```sql
30 | SELECT ProductID, Name
31 | FROM SalesLT.Product
32 | WHERE DiscontinuedDate IS NULL
33 | ```
34 |
35 | 1. Select only the code you just added (which retrieves the ID and name of all products that are not discontinued) and run it. Then view the results and messages to observe how many rows were returned by this query.
36 | 1. Modify the code by adding a UNION operator between the two queries:
37 |
38 | ```sql
39 | SELECT ProductID, Name
40 | FROM SalesLT.Product
41 | WHERE ProductID NOT IN (SELECT ProductID FROM SalesLT.SalesOrderDetail)
42 | UNION
43 | SELECT ProductID, Name
44 | FROM SalesLT.Product
45 | WHERE DiscontinuedDate IS NULL
46 | ORDER BY ProductID
47 | ```
48 |
49 | 1. Run the entire query, and view the results and messages. The results include a row for each product for which there have been no sales *or* that has not been discontinued. Rows with the same values in each column from multiple queries are consolidated into a single row in the results - eliminating duplicate rows for products that are both unsold and not discontinued.
50 | 1. Modify the query to add the ALL keyword to the UNION operator:
51 |
52 | ```sql
53 | SELECT ProductID, Name
54 | FROM SalesLT.Product
55 | WHERE ProductID NOT IN (SELECT ProductID FROM SalesLT.SalesOrderDetail)
56 | UNION ALL
57 | SELECT ProductID, Name
58 | FROM SalesLT.Product
59 | WHERE DiscontinuedDate IS NULL
60 | ORDER BY ProductID
61 | ```
62 |
63 | 1. Run the modified query, and view the results and messages. The results include a row for each product that has not been discontinued *and* for each product that has not been sold. Some products are listed twice (once because they have not been sold, and once because they have not been discontinued). The ALL keyword produces results that include all rows returned by all of the individual queries - which may result in duplicates.
64 |
65 | ## Write a query that uses the INTERSECT operator
66 |
67 | Now let's try a query using the INTERSECT operator.
68 |
69 | 1. Modify the query to replace the UNION ALL operator with the INTERSECT operator:
70 |
71 | ```sql
72 | SELECT ProductID, Name
73 | FROM SalesLT.Product
74 | WHERE ProductID NOT IN (SELECT ProductID FROM SalesLT.SalesOrderDetail)
75 | INTERSECT
76 | SELECT ProductID, Name
77 | FROM SalesLT.Product
78 | WHERE DiscontinuedDate IS NULL
79 | ORDER BY ProductID
80 | ```
81 |
82 | 1. Run the query, and view the results and messages. The results include a row for each product for which there have been no sales *and* that has not been discontinued. The results of the INTERSECT operator include only rows that are returned by all of the individual queries.
83 |
84 | ## Write a query that uses the EXCEPT operator
85 |
86 | Now let's try a query using the EXCEPT operator.
87 |
88 | 1. Modify the query to replace the INTERSECT operator with the EXCEPT operator:
89 |
90 | ```sql
91 | SELECT ProductID, Name
92 | FROM SalesLT.Product
93 | WHERE ProductID NOT IN (SELECT ProductID FROM SalesLT.SalesOrderDetail)
94 | EXCEPT
95 | SELECT ProductID, Name
96 | FROM SalesLT.Product
97 | WHERE DiscontinuedDate IS NULL
98 | ORDER BY ProductID
99 | ```
100 |
101 | 1. Run the query, and view the results and messages. The results include a row for each unsold product other than products that have not been discontinued. The results of the EXCEPT operator include only rows that are returned by the queries *before* the EXCEPT operator.
102 |
103 | ## Write a query that uses the CROSS APPLY operator
104 |
105 | Now you will write a table-valued function to return the product category and quantity ordered by specific customers.
106 |
107 | 1. Create a new query and enter the following code:
108 |
109 | ```sql
110 | CREATE OR ALTER FUNCTION SalesLT.fn_ProductSales (@CustomerID int)
111 | RETURNS TABLE
112 | RETURN
113 | SELECT C.[Name] AS 'Category', SUM(D.OrderQty) AS 'Quantity'
114 | FROM SalesLT.SalesOrderHeader AS H
115 | INNER JOIN SalesLT.SalesOrderDetail AS D
116 | ON H.SalesOrderID = D.SalesOrderID
117 | INNER JOIN SalesLT.Product AS P
118 | ON D.ProductID = P.ProductID
119 | INNER JOIN SalesLT.ProductCategory AS C
120 | ON P.ProductCategoryID = C.ProductCategoryID
121 | WHERE H.CustomerID = @CustomerID
122 | GROUP BY C.[Name]
123 | ```
124 |
125 | 1. Run the code to create the function.
126 |
127 | 1. Now, use the following code to pass the **CustomerID** to the table-valued function in a CROSS APPLY statement within a query, retrieving details of sales for each customer returned by the query:
128 |
129 | ```sql
130 | SELECT C.CustomerID, C.CompanyName, P.Category, P.Quantity
131 | FROM SalesLT.Customer AS C
132 | CROSS APPLY SalesLT.fn_ProductSales(C.CustomerID) AS P;
133 | ```
134 |
135 | 1. Run the query and view the results.
136 |
137 | ## Challenge
138 |
139 | Use the following code to create a table-valued function that retrieves address details for a given customer:
140 |
141 | ```sql
142 | CREATE OR ALTER FUNCTION SalesLT.fn_CustomerAddresses (@CustomerID int)
143 | RETURNS TABLE
144 | RETURN
145 | SELECT ca.AddressType, a.AddressLine1, a.AddressLine2, a.City, a.StateProvince, a.CountryRegion, a.PostalCode
146 | FROM SalesLT.CustomerAddress as ca
147 | JOIN SalesLT.Address AS a
148 | ON a.AddressID = ca.AddressID
149 | WHERE ca.CustomerID = @CustomerID
150 | ```
151 |
152 | Now write a query that returns every customer ID and company name along with all of the address fields retrieved by the function.
153 |
154 | > **Tip**: Try to determine the appropriate code for yourself. If you get stuck, a suggested answer is provided below.
155 |
156 | ## Challenge Solution
157 |
158 | This section contains a suggested solution for the challenge query.
159 |
160 | ```sql
161 | SELECT c.CustomerID, c.CompanyName, a.*
162 | FROM SalesLT.Customer AS c
163 | CROSS APPLY SalesLT.fn_CustomerAddresses(c.CustomerID) AS a
164 | ORDER BY c.CustomerID;
165 | ```
166 |
--------------------------------------------------------------------------------
/Instructions/Labs/08-create-window-query-functions.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Use window functions'
4 | module: 'Additional exercises'
5 | ---
6 | # Use window functions
7 |
8 | In this exercise, you'll apply window functions on the **Adventureworks** database.
9 |
10 | > **Note**: This exercise assumes you have created the **Adventureworks** database.
11 |
12 | ## Ranking function
13 |
14 | Let's start by creating a query that uses a window function to return a ranking value.
15 |
16 | 1. Open a query editor for your **Adventureworks** database, and create a new query.
17 | 1. In the query editor, enter the following code:
18 |
19 | ```sql
20 | SELECT C.Name AS 'Category',
21 | SUM(D.OrderQty) AS 'ItemsSold',
22 | RANK() OVER(ORDER BY SUM(D.OrderQty) DESC) AS 'Rank'
23 | FROM SalesLT.SalesOrderDetail AS D
24 | INNER JOIN SalesLT.Product AS P
25 | ON D.ProductID = P.ProductID
26 | INNER JOIN SalesLT.ProductCategory AS C
27 | ON P.ProductCategoryID = C.ProductCategoryID
28 | GROUP BY C.Name
29 | ORDER BY Rank;
30 | ```
31 |
32 | 1. Run the query and review the results. The product categories in the results have a rank number according to the number of items sold within each category. The rank is based on a descending order of sales (so the category with most items sold is 1, the category with the second most items sold is 2, and so on).
33 |
34 | > **Tip**: Look closely at the results to see how rank is assigned to categories with the same number of sales.
35 |
36 | ## Aggregation function by partition
37 |
38 | Now, let's create a query that returns each product with its category and list price along with the average list price for products in the same category.
39 |
40 | 1. In the query editor, replace the existing query with the following code:
41 |
42 | ```sql
43 | SELECT p.Name AS Product,
44 | c.Name AS Category,
45 | p.ListPrice,
46 | AVG(p.ListPrice) OVER (PARTITION BY c.Name) AS AvgCategoryPrice
47 | FROM SalesLT.Product AS p
48 | JOIN SalesLT.ProductCategory AS c
49 | ON p.ProductCategoryID = c.ProductCategoryID;
50 | ```
51 |
52 | 1. Run the query and review the results. The OVER clause applies the average function to ListPrice, partitioning by category (in other words, it calculates the average list price for products in each category; so you can easily compare the price of an individual product to the average price of all products in the same category).
53 |
54 | ## Challenges
55 |
56 | Now it's your turn to use window functions.
57 |
58 | > **Tip**: Try to determine the appropriate code for yourself. If you get stuck, suggested answers are provided at the end of this lab.
59 |
60 | ### Challenge 1: Rank salespeople based on orders
61 |
62 | Write a query that ranks the salespeople based on the number of orders placed by the customers they are assigned to.
63 |
64 | ### Challenge 2: Retrieve each customer with the total number of customers in the same region
65 |
66 | Write a query that returns the company name of each customer, the city in which the customer has its main office, and the total number of customers with a main office in the same region.
67 |
68 | ## Challenge Solutions
69 |
70 | This section contains suggested solutions for the challenge queries.
71 |
72 | ### Challenge 1
73 |
74 | ```sql
75 | SELECT c.SalesPerson,
76 | COUNT(o.SalesOrderID) AS 'SalesOrders',
77 | RANK() OVER(ORDER BY COUNT(o.SalesOrderID) DESC) AS 'Rank'
78 | FROM SalesLT.SalesOrderHeader AS o
79 | INNER JOIN SalesLT.Customer AS c
80 | ON o.CustomerID = c.CustomerID
81 | GROUP BY c.SalesPerson
82 | ORDER BY Rank;
83 | ```
84 |
85 | ### Challenge 2
86 |
87 | ```sql
88 | SELECT c.CompanyName,
89 | a.CountryRegion,
90 | COUNT(c.CustomerID) OVER (PARTITION BY a.CountryRegion) AS CustomersInRegion
91 | FROM SalesLT.Customer AS c
92 | JOIN SalesLT.CustomerAddress AS ca
93 | ON c.CustomerID = ca.CustomerID
94 | JOIN SalesLT.Address AS a
95 | ON ca.AddressID = a.AddressID
96 | WHERE ca.AddressType = 'Main Office';
97 | ```
98 |
--------------------------------------------------------------------------------
/Instructions/Labs/09-transform-data.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Use pivoting and grouping sets'
4 | module: 'Additional exercises'
5 | ---
6 |
7 | # Use pivoting and grouping sets
8 |
9 | In this exercise, you'll use pivoting and grouping sets to query the **Adventureworks** database.
10 |
11 | > **Note**: This exercise assumes you have created the **Adventureworks** database.
12 |
13 | ## Pivot data using the PIVOT operator
14 |
15 | 1. Open a query editor for your **Adventureworks** database, and create a new query.
16 | 1. In the query editor, enter the following code to create a view that contains the ID, company name, and main office region for all customers
17 |
18 | ```sql
19 | CREATE VIEW SalesLT.v_CustomerRegions
20 | AS
21 | SELECT c.CustomerID, c.CompanyName,a. CountryRegion
22 | FROM SalesLT.Customer AS c
23 | JOIN SalesLT.CustomerAddress AS ca
24 | ON c.CustomerID = ca.CustomerID
25 | JOIN SalesLT.Address AS a
26 | ON ca.AddressID = a.AddressID
27 | WHERE ca.AddressType = 'Main Office';
28 | GO
29 | ```
30 |
31 | 1. Run your code to create the view
32 | 1. You can now query the view to retrieve information about the regions where customers have their main office. For example, run the following query:
33 |
34 | ```sql
35 | SELECT CountryRegion, COUNT(CustomerID) AS Customers
36 | FROM SalesLT.v_CustomerRegions
37 | GROUP BY CountryRegion;
38 | ```
39 |
40 | The query returns the number of customers in each region. Howeverm suppose you wanted the data presented as a single row that contains the number of offices in each region, like this:
41 |
42 | | Data | Canada | United Kingdom | United States |
43 | |--|--|--|--|
44 | | Customer Count | 106 | 38 | 263 |
45 |
46 | 1. To accomplish this, you can use retrieve the necessary columns (**CustomerID** and **CountryRegion** and a literal "Customer Count" row header) from the view, and then use the PIVOT operator to count the customer IDs in each named region, like this:
47 |
48 | ```sql
49 | SELECT *
50 | FROM
51 | (
52 | SELECT 'Customer Count' AS Data, CustomerID, CountryRegion
53 | FROM SalesLT.v_CustomerRegions
54 | ) AS SourceData
55 | PIVOT
56 | (
57 | COUNT(CustomerID) FOR CountryRegion IN ([Canada], [United Kingdom], [United States])
58 | ) AS PivotedData
59 | ```
60 |
61 | 1. Run the query to view the results.
62 |
63 | ## Group data using a grouping subclause
64 |
65 | Use subclauses like **GROUPING SETS**, **ROLLUP**, and **CUBE** to group data in different ways. Each subclause allows you to group data in a unique way. For instance, **ROLLUP** allows you to dictate a hierarchy and provides a grand total for your groupings. Alternatively, you can use **CUBE** to get all possible combinations for groupings.
66 |
67 | For example, let's see how you can use **ROLLUP** to group a set of data.
68 |
69 | 1. Create a view that includes details of sales of products to customers from multiple tables in the database. To do this, Run the following code:
70 |
71 | ```sql
72 | CREATE VIEW SalesLT.v_ProductSales AS
73 | SELECT c.CustomerID, c.CompanyName, c.SalesPerson,
74 | a.City, a.StateProvince, a.CountryRegion,
75 | p.Name As Product, pc.Name AS Category,
76 | o.SubTotal + o.TaxAmt + o.Freight AS TotalDue
77 | FROM SalesLT.Customer AS c
78 | INNER JOIN SalesLT.CustomerAddress AS ca
79 | ON c.CustomerID = ca.CustomerID
80 | INNER JOIN SalesLT.Address AS a
81 | ON ca.AddressID = a.AddressID
82 | INNER JOIN SalesLT.SalesOrderHeader AS o
83 | ON c.CustomerID = o.CustomerID
84 | INNER JOIN SalesLT.SalesOrderDetail AS od
85 | ON o.SalesOrderID = od.SalesOrderID
86 | INNER JOIN SalesLT.Product AS p
87 | ON od.ProductID = p.ProductID
88 | INNER JOIN SalesLT.ProductCategory AS pc
89 | ON p.ProductCategoryID = pc.ProductCategoryID
90 | WHERE ca.AddressType = 'Main Office';
91 | ```
92 |
93 | 1. Your view (**SalesLT.v_ProductSales**) enables you to summarize sales by attributes of products (for example category) and attributes of customers (for example, geographical location). Run the query below to view sales totals grouped by geographical region and product category:
94 |
95 | ```sql
96 | SELECT CountryRegion, Category, SUM(TotalDue) AS TotalSales
97 | FROM SalesLT.v_ProductSales
98 | GROUP BY CountryRegion, Category
99 | ```
100 |
101 | The results show the sales totals for each combination of region and product category.
102 |
103 | 1. Now let's use **ROLLUP** to group this data. Replace your previous code with the code below:
104 |
105 | ```sql
106 | SELECT CountryRegion, Category, SUM(TotalDue) AS TotalSales
107 | FROM SalesLT.v_ProductSales
108 | GROUP BY ROLLUP (CountryRegion, Category);
109 | ```
110 |
111 | 1. Run the query and review the results.
112 |
113 | The results contain a row for each region and product category as before. Additionally, after the rows for each region there is a row containing a *NULL* category and the subtotal for all products sold in that region, and at the end of the resultset there's a row with NULL region and category values containing the grand total for sales of all product categories in all regions.
114 |
115 | 1. Modify the query to use the CUBE operator instead of ROLLUP:
116 |
117 | ```sql
118 | SELECT CountryRegion, Category, SUM(TotalDue) AS TotalSales
119 | FROM SalesLT.v_ProductSales
120 | GROUP BY CUBE (CountryRegion, Category);
121 | ```
122 |
123 | 1. Run the modified query and review the results.
124 |
125 | This time, the results include:
126 | - Sales for each category in each region
127 | - A subtotal for each product category in all regions (with a *NULL* **CountryRegion**)
128 | - A subtotal for each region for all product categories (with a *NULL* **Category**)
129 | - A grand total for sales of all product categories in all regions (with *NULL* **CountryRegion** and **Category** values)
130 |
131 | ## Challenges
132 |
133 | Now it's your turn to pivot and group data.
134 |
135 | > **Tip**: Try to determine the appropriate code for yourself. If you get stuck, suggested answers are provided at the end of this lab.
136 |
137 | ### Challenge 1: Count product colors by category
138 |
139 | The Adventure Works marketing team wants to conduct research into the relationship between colors and products. To give them a starting point, you've been asked to provide information on how many products are available across the different color types.
140 |
141 | - Use the **SalesLT.Product** and **SalesLT.ProductCategory** tables to get a list of products, their colors, and product categories.
142 | - Pivot the data so that the colors become columns with a value indicating how many products in each category are that color.
143 |
144 | ### Challenge 2: Aggregate sales data by product and salesperson
145 |
146 | The sales team at Adventure Works wants to compare sales of individual products by salesperson.
147 | To accomplish this, write a query that groups data from the **SalesLT.v_ProductSales** view you created previously to return:
148 |
149 | - The sales amount for each product by each salesperson
150 | - The subtotal of sales for each product by all salespeople
151 | - The grand total for all products by all saleseople
152 |
153 | ## Challenge Solutions
154 |
155 | This section contains suggested solutions for the challenge queries.
156 |
157 | ### Challenge 1
158 |
159 | ```sql
160 | SELECT *
161 | FROM
162 | (
163 | SELECT P.ProductID, PC.Name AS Category, ISNULL(P.Color, 'Uncolored') AS Color
164 | FROM Saleslt.ProductCategory AS PC
165 | JOIN SalesLT.Product AS P
166 | ON PC.ProductCategoryID = P.ProductCategoryID
167 | ) AS ProductColors
168 | PIVOT
169 | (
170 | COUNT(ProductID) FOR Color IN(
171 | [Red], [Blue], [Black], [Silver], [Yellow],
172 | [Grey], [Multi], [Uncolored])
173 | ) AS ColorCountsByCategory
174 | ORDER BY Category;
175 | ```
176 |
177 | ### Challenge 2
178 |
179 | ```sql
180 | SELECT Product, SalesPerson, SUM(TotalDue) AS TotalSales
181 | FROM SalesLT.v_ProductSales
182 | GROUP BY ROLLUP (Product, SalesPerson);
183 | ```
184 |
--------------------------------------------------------------------------------
/Instructions/Labs/10-program-with-tsql.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Introduction to programming with Transact-SQL'
4 | module: 'Additional exercises'
5 | ---
6 |
7 | # Introduction to programming with Transact-SQL
8 |
9 | In this exercise, you'll use get an introduction to programming with Transact-SQL using the **Adventureworks** database.
10 |
11 | > **Note**: This exercise assumes you have created the **Adventureworks** database.
12 |
13 | ## Declare variables and retrieve values
14 |
15 | 1. Open a query editor for your **Adventureworks** database, and create a new query.
16 | 1. In the query pane, type the following code:
17 |
18 | ```sql
19 | DECLARE @productID int = 680;
20 |
21 | SELECT @productID AS ProductID;
22 | ```
23 |
24 | 1. Run the query and review the result, which is returned as a resultset from the SELECT statement:
25 |
26 | | ProductID |
27 | | -------- |
28 | | 680 |
29 |
30 | 1. Modify the code as follows:
31 |
32 | ```sql
33 | -- Variable declarations
34 | DECLARE
35 | @productID int,
36 | @productPrice money;
37 |
38 | -- Specify a product
39 | SET @productID = 680;
40 | PRINT @productID;
41 |
42 | -- Get the product price
43 | SELECT @productPrice = ListPrice FROM SalesLT.Product WHERE ProductID = @productID;
44 | PRINT @ProductPrice;
45 | ```
46 |
47 | 1. Run the code and review the output. This time, the PRINT statements result in the variable values being included in the messages produced by the code:
48 |
49 | ```
50 | 8:02:11 AM Started executing on line 1
51 | 8:02:01 AM Started executing query.
52 | 8:02:01 AM 680
53 | 8:02:01 AM 1431.50
54 | 8:02:01 AM Finished executing query.
55 | 8:02:13 AM SQL Server execution time: 00:00:00.010 | Total duration: 00:00:01.782
56 | ```
57 |
58 | 1. Add a SELECT statement to output the variables as a resultset:
59 |
60 | ```sql
61 | -- Variable declarations
62 | DECLARE
63 | @productID int,
64 | @productPrice money;
65 |
66 | -- Specify a product
67 | SET @productID = 680;
68 | PRINT @productID;
69 |
70 | -- Get the product price
71 | SELECT @productPrice = ListPrice FROM SalesLT.Product WHERE ProductID = @productID;
72 | PRINT @productPrice;
73 |
74 | -- Output the results
75 | SELECT @productID AS ProductID, @productPrice AS Price;
76 | ```
77 |
78 | 1. Run the code, and view the results, which should look like this:
79 |
80 | | ProductID | Price |
81 | | -------- | -- |
82 | | 680 | 1431.50 |
83 |
84 | (Note that the variable values are still included in the messages because of the PRINT statements)
85 |
86 | ## Explore variable scope
87 |
88 | Now, we'll look at the behavior of variables when code is run in batches.
89 |
90 | 1. Modify the code to add the batch delimiter GO before the final SELECT statement. This causes the client to sent the code after the GO statement to the server in a new batch:
91 |
92 | ```sql
93 | -- Variable declarations
94 | DECLARE
95 | @productID int,
96 | @productPrice money;
97 |
98 | -- Specify a product
99 | SET @productID = 680;
100 | PRINT @productID;
101 |
102 | -- Get the product price
103 | SELECT @productPrice = ListPrice FROM SalesLT.Product WHERE ProductID = @productID;
104 | PRINT @productPrice;
105 |
106 | GO
107 |
108 | -- Output the results
109 | SELECT @productID AS ProductID, @productPrice AS Price;
110 | ```
111 |
112 | 1. Run the code, and review the error that is returned:
113 |
114 | *Must declare the scalar variable "@productID"*
115 |
116 | Variables are local to the batch in which they're defined. If you try to refer to a variable that was defined in another batch, you get an error saying that the variable wasn't defined. Also, keep in mind that GO is a client command, not a server T-SQL command.
117 |
118 | 1. Remove the GO statement and verify that the code works as before.
119 |
120 | ## Use table variables
121 |
122 | So far, you've used variables that encapsulate a single value of a specific data type. In Transact-SQL, you can also use *table* variables to encapsulate multiple rows of data.
123 |
124 | 1. Modify the code to add a declaration for a table variable to insert the results into:
125 |
126 | ```sql
127 | -- Variable declarations
128 | DECLARE
129 | @productID int,
130 | @productPrice money;
131 |
132 | DECLARE @priceData TABLE(ProductID int, Price money);
133 |
134 | -- Specify a product
135 | SET @productID = 680;
136 |
137 | -- Get the product price
138 | SELECT @productPrice = ListPrice FROM SalesLT.Product WHERE ProductID = @productID;
139 |
140 | -- Insert the data into a table variable
141 | INSERT INTO @priceData VALUES(@productID, @productPrice);
142 |
143 | -- Output the results
144 | SELECT * FROM @priceData;
145 | ```
146 |
147 | 1. Run the code, and view the results (the data in the table variable).
148 |
149 | ## Write conditional logic
150 |
151 | Conditional logic is used to *branch* program execution flow based on specific conditions. The most common form of conditional logic is the IF..ELSE statement. Transact-SQL also supports a CASE statement.
152 |
153 | 1. Modify the code as follows to add logic that assigns a price level based on some conditional logic comparing the price of a specific to the averege product price:
154 |
155 | ```sql
156 | -- Variable declarations
157 | DECLARE
158 | @productID int,
159 | @productPrice money,
160 | @averagePrice money,
161 | @priceLevel nvarchar(20);
162 |
163 | DECLARE @priceData TABLE(ProductID int, Price money, PriceLevel nvarchar(20));
164 |
165 | -- Specify a product
166 | SET @productID = 680;
167 | PRINT @productID;
168 |
169 | -- Get the product price
170 | SELECT @productPrice = ListPrice FROM SalesLT.Product WHERE ProductID = @productID;
171 | PRINT @productPrice;
172 |
173 | -- Get average product price
174 | SELECT @averagePrice = AVG(ListPrice) FROM SalesLT.Product;
175 | PRINT @averagePrice;
176 |
177 | -- Determine the price level
178 | IF @ProductPrice < @averagePrice
179 | SET @priceLevel = N'Below average'
180 | ELSE IF @ProductPrice > @averagePrice
181 | SET @priceLevel = N'Above average'
182 | ELSE
183 | SET @priceLevel = N'Average';
184 |
185 | -- Insert the data into a table variable
186 | INSERT INTO @priceData VALUES(@productID, @productPrice, @priceLevel);
187 |
188 | -- Output the results
189 | SELECT * FROM @priceData;
190 | ```
191 |
192 | 1. Run the code and review the results.
193 |
194 | The IF..ELSE statement block checks a series of conditions, running the statements for the first one that is found to be true, or statement under the final ELSE block if no match is found.
195 |
196 | 1. Modify the code to perform the conditional logic using a CASE statement:
197 |
198 | ```sql
199 | -- Variable declarations
200 | DECLARE
201 | @productID int,
202 | @productPrice money,
203 | @averagePrice money,
204 | @priceLevel nvarchar(20);
205 |
206 | DECLARE @priceData TABLE(ProductID int, Price money, PriceLevel nvarchar(20));
207 |
208 | -- Specify a product
209 | SET @productID = 680;
210 | PRINT @productID;
211 |
212 | -- Get the product price
213 | SELECT @productPrice = ListPrice FROM SalesLT.Product WHERE ProductID = @productID;
214 | PRINT @productPrice;
215 |
216 | -- Get average product price
217 | SELECT @averagePrice = AVG(ListPrice) FROM SalesLT.Product;
218 | PRINT @averagePrice;
219 |
220 | -- Determine the price level
221 | SET @priceLevel =
222 | CASE
223 | WHEN @ProductPrice < @averagePrice THEN
224 | N'Below average'
225 | WHEN @ProductPrice > @averagePrice THEN
226 | N'Above average'
227 | ELSE
228 | N'Average'
229 | END;
230 |
231 | -- Insert the data into a table variable
232 | INSERT INTO @priceData VALUES(@productID, @productPrice, @priceLevel);
233 |
234 | -- Output the results
235 | SELECT * FROM @priceData
236 | ```
237 |
238 | 1. Run the code and verify that the results are same as before.
239 |
240 | ## Use a loop to write iterative code
241 |
242 | Loops are used to perform logic iteratively, running the same code multiple times - usually until a condition is met. In Transact-SQL, you can implement loops using the WHILE statement.
243 |
244 | 1. Modify the code to use a WHILE loop to retrieve the price for each of the top 10 selling products (by quantity sold) and determine the price level for each of those products:
245 |
246 | ```sql
247 | -- Variable declarations
248 | DECLARE
249 | @productID int,
250 | @productPrice money,
251 | @averagePrice money,
252 | @priceLevel nvarchar(20);
253 |
254 | DECLARE @priceData TABLE(Rank int, ProductID int, Price money, PriceLevel nvarchar(20));
255 |
256 | -- Get average product price
257 | SELECT @averagePrice = AVG(ListPrice) FROM SalesLT.Product;
258 |
259 | -- Loop through the top 10 selling product to determine their price levels
260 | DECLARE @salesRank int = 1
261 | WHILE @salesRank <= 10
262 | BEGIN
263 | -- Get the product ID for the current sales rank
264 | WITH RankedProductSales AS(
265 | SELECT ProductID, RANK() OVER(ORDER BY SUM(OrderQty) DESC) AS 'Rank'
266 | FROM SalesLT.SalesOrderDetail
267 | GROUP BY ProductID)
268 | SELECT @productID = ProductID FROM RankedProductSales WHERE Rank = @salesRank;
269 |
270 | -- Get the product price
271 | SELECT @productPrice = ListPrice FROM SalesLT.Product WHERE ProductID = @productID;
272 |
273 | -- Determine the price level
274 | SET @priceLevel =
275 | CASE
276 | WHEN @ProductPrice < @averagePrice THEN
277 | N'Below average'
278 | WHEN @ProductPrice > @averagePrice THEN
279 | N'Above average'
280 | ELSE
281 | N'Average'
282 | END;
283 |
284 | -- Insert the results into a table variable
285 | INSERT INTO @priceData VALUES (@salesRank, @productID, @productPrice, @priceLevel);
286 |
287 | -- Increment the sales rank by 1 so we can get the next one in the next loop iteration
288 | SET @salesRank += 1;
289 |
290 | END;
291 |
292 | -- Display the results
293 | SELECT * FROM @priceData;
294 | ```
295 |
296 | 1. Run the code and review the results.
297 |
298 | > **Note**: This code is designed to demonstrate how to use a loop. While loops can be useful, it can often be more efficient to use set-based operations to achieve similar results.
299 |
300 | ## Challenges
301 |
302 | Now it's time to try using what you've learnt.
303 |
304 | > **Tip**: Try to determine the appropriate solutions for yourself. If you get stuck, suggested answers are provided at the end of this lab.
305 |
306 | ### Challenge 1: Assignment of values to variables
307 |
308 | You are developing a new Transact-SQL application that needs to temporarily store values drawn from the database, and depending on their values, display the outcome to the user.
309 |
310 | 1. Create your variables.
311 | - Write a Transact-SQL statement to declare two variables. The first is an nvarchar with length 30 called salesOrderNumber, and the other is an integer called customerID.
312 | 1. Assign a value to the integer variable.
313 | - Extend your Transact-SQL code to assign the value 29847 to the customerID.
314 | 1. Assign a value from the database and display the result.
315 | - Extend your Transact-SQL to set the value of the variable salesOrderNumber using the column **salesOrderNumber** from the SalesOrderHeader table, filter using the **customerID** column and the customerID variable. Display the result to the user as OrderNumber.
316 |
317 | ### Challenge 2: Aggregate product sales
318 |
319 | The sales manager would like a list of the first 10 customers that registered and made purchases online as part of a promotion. You've been asked to build the list.
320 |
321 | 1. Declare the variables:
322 | - Write a Transact-SQL statement to declare three variables. The first is called **customerID** and will be an Integer with an initial value of 1. The next two variables will be called **fname** and **lname**. Both will be NVARCHAR, give fname a length 20 and lname a length 30.
323 | 1. Construct a terminating loop:
324 | - Extend your Transact-SQL code and create a WHILE loop that will stop when the customerID variable reaches 10.
325 | 1. Select the customer first name and last name and display:
326 | - Extend the Transact-SQL code, adding a SELECT statement to retrieve the **FirstName** and **LastName** columns and assign them respectively to fname and lname. Combine and PRINT the fname and lname. Filter using the **customerID** column and the customerID variable.
327 |
328 | ## Challenge Solutions
329 |
330 | This section contains suggested solutions for the challenge queries.
331 |
332 | ### Challenge 1
333 |
334 | ```sql
335 | DECLARE
336 | @salesOrderNUmber nvarchar(30),
337 | @customerID int;
338 |
339 | SET @customerID = 29847;
340 |
341 | SET @salesOrderNUmber = (SELECT salesOrderNumber FROM SalesLT.SalesOrderHeader WHERE CustomerID = @customerID)
342 |
343 | SELECT @salesOrderNUmber as OrderNumber;
344 | ```
345 |
346 | ### Challenge 2
347 |
348 | ```sql
349 | DECLARE @customerID AS INT = 1;
350 | DECLARE @fname AS NVARCHAR(20);
351 | DECLARE @lname AS NVARCHAR(30);
352 |
353 | WHILE @customerID <=10
354 | BEGIN
355 | SELECT @fname = FirstName, @lname = LastName FROM SalesLT.Customer
356 | WHERE CustomerID = @CustomerID;
357 | PRINT @fname + N' ' + @lname;
358 | SET @customerID += 1;
359 | END;
360 | ```
361 |
--------------------------------------------------------------------------------
/Instructions/Labs/11-create-stored-procedures.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Create stored procedures and functions in Transact-SQL'
4 | module: 'Additional exercises'
5 | ---
6 |
7 | # Create stored procedures and functions in Transact-SQL
8 |
9 | In this exercise, you'll create and run stored procedures in the **Adventureworks** database.
10 |
11 | > **Note**: This exercise assumes you have created the **Adventureworks** database.
12 |
13 | ## Create a stored procedure
14 |
15 | Stored procedures are named groups of Transact-SQL statements that can be used and reused whenever they're needed.
16 |
17 | 1. Open a query editor for your **Adventureworks** database, and create a new query.
18 | 1. In the query pane, type the following code:
19 |
20 | ```sql
21 | CREATE PROCEDURE SalesLT.up_GetTopProducts
22 | AS
23 | SELECT TOP(10) Name, ListPrice
24 | FROM SalesLT.Product
25 | GROUP BY Name, ListPrice
26 | ORDER BY ListPrice DESC;
27 | ```
28 |
29 | 1. Run the code to create a stored procedure named **SalesLT.up_GetTopProducts**.
30 | 1. In the query pane, type the following code under the CREATE PROCEDURE statement:
31 |
32 | ```sql
33 | EXECUTE SalesLT.up_GetTopProducts;
34 | ```
35 |
36 | 1. Select the EXECUTE statement to highlight it, and then run it. The stored procedure is executed and returns the top 10 products by price.
37 |
38 | 1. Now alter the stored procedure by adding an input parameter so that you can specify how many "top" products you want to return. In the query pane, type the following T-SQL code:
39 |
40 | ```sql
41 | ALTER PROCEDURE SalesLT.up_GetTopProducts (@count int)
42 | AS
43 | SELECT TOP(@count) Name, ListPrice
44 | FROM SalesLT.Product
45 | GROUP BY Name, ListPrice
46 | ORDER BY ListPrice DESC;
47 | ```
48 |
49 | 1. Select the ALTER PROCEDURE statement to highlight it, and then run it to modify the stored procedure
50 |
51 | 1. Modify the EXECUTE statement used to call the stored procedure to pass a parameter:
52 |
53 | ```sql
54 | EXECUTE SalesLT.up_GetTopProducts @count=20;
55 | ```
56 |
57 | 1. Highlight the modified EXECUTE statement and run it to call the stored procedure, passing the parameter value by name. This time the stored procedure returns the top 20 products by price.
58 |
59 | ## Create functions
60 |
61 | Functions are similar to stored procedures, but can be used in SELECT statements like built in functions.
62 |
63 | ### Create a scalar function
64 |
65 | Scalar functions return a single value.
66 |
67 | 1. Create a new query, and add the following code, which defines a function to apply a specified percentage discount to the price of a specified product:
68 |
69 | ```sql
70 | CREATE FUNCTION SalesLT.fn_ApplyDiscount (@productID int, @percentage decimal)
71 | RETURNS money
72 | AS
73 | BEGIN
74 | DECLARE @discountedPrice money;
75 | SELECT @discountedPrice = ListPrice - (ListPrice * (@percentage/100))
76 | FROM SalesLT.Product
77 | WHERE ProductID = @productID;
78 | RETURN @discountedPrice
79 | END;
80 | ```
81 |
82 | 1. Run the code to create the function.
83 | 1. In the query pane, type the following code under the CREATE FUNCTION statement:
84 |
85 | ```sql
86 | SELECT ProductID, Name, ListPrice, StandardCost,
87 | SalesLT.fn_ApplyDiscount(ProductID, 10) AS SalePrice
88 | FROM SalesLT.Product;
89 | ```
90 |
91 | 1. Select and run the SELECT statement and view the results, which show the ID, name, list price, and cost of each product together with a sale price that is calculated by using the function you created to apply a 10% discount.
92 |
93 | ### Create a table-valued function
94 |
95 | Table-valued functions return a table.
96 |
97 | 1. Create a new query, and add the following code, which defines a function that returns the ID, name, price, cost, and gross profit for all products in a specified category:
98 |
99 | ```sql
100 | CREATE FUNCTION SalesLT.fn_ProductProfit (@categoryID int)
101 | RETURNS TABLE
102 | AS
103 | RETURN
104 | SELECT ProductID, Name AS Product, ListPrice, StandardCost, ListPrice - StandardCost AS Profit
105 | FROM SalesLT.Product
106 | WHERE ProductCategoryID = @categoryID;
107 | ```
108 |
109 | 1. Run the code to create the function.
110 | 1. In the query pane, type the following code under the CREATE FUNCTION statement:
111 |
112 | ```sql
113 | SELECT * FROM SalesLT.fn_ProductProfit(18)
114 | ```
115 |
116 | 1. Select and run the SELECT statement and view the results, which show the ID, name, price, cost, and gross profit for products in category 18.
117 | 1. Modify the SELECT statement to use a CROSS APPLY clause:
118 |
119 | ```sql
120 | SELECT c.Name AS Category, pm.Product, pm.ListPrice, pm.Profit
121 | FROM SalesLT.ProductCategory AS c
122 | CROSS APPLY SalesLT.fn_ProductProfit(c.ProductCategoryID) AS pm
123 | ORDER BY Category, Product;
124 | ```
125 |
126 | 1. Select and run the SELECT statement and view the results., The CROSS APPLY clause runs the function for each category in the **SalesLT.ProductCategory** table - creating an inner join between the table of product categories and the table returned by the function.
127 |
128 | ## Challenges
129 |
130 | Now it's time to try using what you've learnt.
131 |
132 | > **Tip**: Try to determine the appropriate solutions for yourself. If you get stuck, suggested answers are provided at the end of this lab.
133 |
134 | ### Challenge 1: Create a stored procedure to retrieve products in a specific category
135 |
136 | Create a stored procedure that returns the ID, name, and list price of all products in a specified category ID.
137 |
138 | Test your stored procedure by using it to retrieve details of products in category *18*.
139 |
140 | ### Challenge 2: Create a function to find the average price of a product in a specific category
141 |
142 | Create a function that returns the average list price of a product in a specified category ID.
143 |
144 | Test the function by writing a query that returns a the ID, names,and average product prices for each distinct category.
145 |
146 | ### Challenge 3: Create a function to find subcategories of a specified category
147 |
148 | Product categories are hierarchical - some categories are subcategories of parent categories, identified by the **ParentProductCategoryID** field in the **SalesLT.ProductCategory** table.
149 |
150 | Create a function that returns a table containing the ID and name of all subcategories of a specified category ID.
151 |
152 | Test your function, initially by using it to return all subcategories of category *1*; then by using a CROSS APPLY query to return all parent category names with the names of their subcategories.
153 |
154 | ## Challenge Solutions
155 |
156 | This section contains suggested solutions for the challenge queries.
157 |
158 | ### Challenge 1
159 |
160 | ```sql
161 | -- Create the procedure
162 | CREATE PROCEDURE SalesLT.up_GetProducts (@categoryID int)
163 | AS
164 | SELECT ProductID, Name AS Product, ListPrice
165 | FROM SalesLT.Product
166 | WHERE ProductCategoryID = @categoryID;
167 |
168 | GO
169 |
170 | -- Test the procedure with category 18
171 | EXECUTE SalesLT.up_GetProducts @categoryID=18;
172 | ```
173 |
174 | ### Challenge 2
175 |
176 | ```sql
177 | -- Create a function
178 | CREATE FUNCTION SalesLT.fn_AvgProductPrice (@categoryID int)
179 | RETURNS money
180 | AS
181 | BEGIN
182 | DECLARE @averagePrice money;
183 | SELECT @averagePrice = AVG(ListPrice)
184 | FROM SalesLT.Product
185 | WHERE ProductCategoryID = @categoryID;
186 | RETURN @averagePrice
187 | END;
188 | GO
189 |
190 | -- Test the function
191 | SELECT ProductCategoryID, Name AS Category,
192 | SalesLT.fn_AvgProductPrice(ProductCategoryID) AS AveragePrice
193 | FROM SalesLT.ProductCategory;
194 | ```
195 |
196 | ### Challenge 3
197 |
198 | ```sql
199 | -- Create a table-valued function
200 | CREATE FUNCTION SalesLT.fn_SubCategories (@categoryID int)
201 | RETURNS TABLE
202 | AS
203 | RETURN
204 | SELECT ProductCategoryID, Name AS SubCategory
205 | FROM SalesLT.ProductCategory
206 | WHERE ParentProductCategoryID = @categoryID;
207 | GO
208 |
209 | -- Test the function
210 | SELECT * FROM SalesLT.fn_SubCategories(1);
211 | GO
212 |
213 | -- Use the function in a CROSS APPLY query
214 | SELECT c.Name AS Category, sc.SubCategory
215 | FROM SalesLT.ProductCategory AS c
216 | CROSS APPLY SalesLT.fn_SubCategories(c.ProductCategoryID) AS sc
217 | ORDER BY Category, SubCategory;
218 | ```
219 |
220 |
--------------------------------------------------------------------------------
/Instructions/Labs/12-implement-error-handling.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Implement error handling with Transact-SQL'
4 | module: 'Additional exercises'
5 | ---
6 |
7 | # Implement error handling with Transact-SQL
8 |
9 | In this exercise, you'll use various Transact-SQL error handling techniques.
10 |
11 | > **Note**: This exercise assumes you have created the **Adventureworks** database.
12 |
13 | ## Observe unhandled error behavior in Transact-SQL
14 |
15 | The Adventureworks database contains details of products, including their size. Numeric values indicate the product size in centimeters, and you will use a stored procedure to convert these sizes to inches.
16 |
17 | 1. Open a query editor for your **Adventureworks** database, and create a new query.
18 | 1. In the query pane, type the following code:
19 |
20 | ```sql
21 | CREATE PROCEDURE SalesLT.up_GetProductSizeInInches (@productID int, @SizeInInches int OUTPUT)
22 | AS
23 | BEGIN
24 | SELECT @SizeInInches = CAST(Size AS decimal) * 0.394
25 | FROM SalesLT.Product
26 | WHERE ProductID = @productID;
27 | END;
28 | ```
29 |
30 | 1. Run the code to create the stored procedure.
31 | 1. Create a second query, and run the following code to test your stored procedure using product *680*, which has a numeric size value:
32 |
33 | ```sql
34 | DECLARE @SizeInInches int;
35 | EXECUTE SalesLT.up_GetProductSizeInInches 680, @SizeInInches OUTPUT;
36 | SELECT @SizeInInches;
37 | ```
38 |
39 | 1. Review the results, noting that the size in inches of product *680* is returned successfully.
40 | 1. Modify the test code to use product *710*, which has the size value "L":
41 |
42 | ```sql
43 | DECLARE @SizeInInches int;
44 | EXECUTE SalesLT.up_GetProductSizeInInches 710, @SizeInInches OUTPUT;
45 | SELECT @SizeInInches;
46 | ```
47 |
48 | 1. Run the modified test code and review the output messages. An error occurs, causing query execution to stop.
49 |
50 | ## Use TRY/CATCH to handle an error
51 |
52 | Transact-SQL supports structured exception handling through the use of a TRY/CATCH block.
53 |
54 | 1. Return to the query used to create the stored procedure, and alter the procedure code to add a TRY/CATCH block, like this:
55 |
56 | ```sql
57 | ALTER PROCEDURE SalesLT.up_GetProductSizeInInches (@productID int, @SizeInInches int OUTPUT)
58 | AS
59 | BEGIN
60 | BEGIN TRY
61 | SELECT @SizeInInches = CAST(Size AS decimal) * 0.394
62 | FROM SalesLT.Product
63 | WHERE ProductID = @productID;
64 | END TRY
65 | BEGIN CATCH
66 | PRINT 'An error occurred';
67 | SET @sizeInInches = 0;
68 | END CATCH
69 | END
70 | ```
71 |
72 | 1. Run the code to alter the stored procedure.
73 | 1. Return to the query used to test the stored procedure and re-run the code that attempts to get the size for product *710*:
74 |
75 | ```sql
76 | DECLARE @SizeInInches int;
77 | EXECUTE SalesLT.up_GetProductSizeInInches 710, @SizeInInches OUTPUT;
78 | SELECT @SizeInInches;
79 | ```
80 |
81 | 1. Review the results, which show the size as *0*. Then review the output messages and note that they include a notification that an error occurred. The code in the CATCH block has handled the error and enabled the stored procedure to fail gracefully.
82 |
83 | ## Capture error details
84 |
85 | The message returned in the CATCH block indicates that an error occurred, but provides no details that would help troubleshoot the problem. You can use built-in functions to get more information about the current error and use those to provide more details.
86 |
87 | 1. Return to the query used to create the stored procedure, and alter the procedure code to print the error number and message, like this:
88 |
89 | ```sql
90 | ALTER PROCEDURE SalesLT.up_GetProductSizeInInches (@productID int, @SizeInInches int OUTPUT)
91 | AS
92 | BEGIN
93 | BEGIN TRY
94 | SELECT @SizeInInches = CAST(Size AS decimal) * 0.394
95 | FROM SalesLT.Product
96 | WHERE ProductID = @productID;
97 | END TRY
98 | BEGIN CATCH
99 | PRINT 'Error Number: ' + CAST(ERROR_NUMBER() AS varchar(10));
100 | PRINT 'Error Message: ' + ERROR_MESSAGE();
101 | SET @sizeInInches = 0;
102 | END CATCH
103 | END
104 | ```
105 |
106 | 1. Run the code to alter the stored procedure.
107 | 1. Return to the query used to test the stored procedure and re-run the code that attempts to get the size for product *710*:
108 |
109 | ```sql
110 | DECLARE @SizeInInches int;
111 | EXECUTE SalesLT.up_GetProductSizeInInches 710, @SizeInInches OUTPUT;
112 | SELECT @SizeInInches;
113 | ```
114 |
115 | 1. Review the results, which again show the size as *0*. Then review the output messages and note that they include the error number and message.
116 |
117 | > **Tip**: In this example, the error details are just printed in the query message output. In a production solution, you might write the error details to a log table to assist in troubleshooting.
118 |
119 | ## Throw the error to the client application
120 |
121 | So far, you've used a TRY/CATCH block to handle an error gracefully. The client application that calls the stored procedure does not encounter an exception. In multi-tier application designs, a common practice is to handle exceptions in the data tier to log details for troubleshooting purposes and ensure the integrity of the database, but then propagate the error to the calling application tier, which includes its own exception handling logic.
122 |
123 | 1. Return to the query used to create the stored procedure, and alter the procedure code to print the error number and message, like this:
124 |
125 | ```sql
126 | ALTER PROCEDURE SalesLT.up_GetProductSizeInInches (@productID int, @SizeInInches int OUTPUT)
127 | AS
128 | BEGIN
129 | BEGIN TRY
130 | SELECT @SizeInInches = CAST(Size AS decimal) * 0.394
131 | FROM SalesLT.Product
132 | WHERE ProductID = @productID;
133 | END TRY
134 | BEGIN CATCH
135 | PRINT 'Error Number: ' + CAST(ERROR_NUMBER() AS varchar(10));
136 | PRINT 'Error Message: ' + ERROR_MESSAGE();
137 | THROW;
138 | END CATCH
139 | END
140 | ```
141 |
142 | 1. Run the code to alter the stored procedure.
143 | 1. Return to the query used to test the stored procedure and re-run the code that attempts to get the size for product *710*:
144 |
145 | ```sql
146 | DECLARE @SizeInInches int;
147 | EXECUTE SalesLT.up_GetProductSizeInInches 710, @SizeInInches OUTPUT;
148 | SELECT @SizeInInches;
149 | ```
150 |
151 | 1. Review the output, which indicates that an error caused the query to fail. Note that the code in the CATCH block intercepted the error and printed details before re-throwing it to the calling client application (in this case, the query editor).
152 |
153 | ## Challenges
154 |
155 | Now it's time to try using what you've learned.
156 |
157 | > **Tip**: Try to determine the appropriate solutions for yourself. If you get stuck, suggested answers are provided at the end of this lab.
158 |
159 | ### Challenge 1: Handle errors gracefully
160 |
161 | Adventure Works has decided to calculate shipping cost for products based on their price and weight. A developer has created the following stored procedure to calculate the shipping cost for a specific product:
162 |
163 | ```sql
164 | CREATE PROCEDURE SalesLT.up_GetShippingPrice (@productID int, @ShippingPrice money OUTPUT)
165 | AS
166 | BEGIN
167 | DECLARE @price money, @weight decimal;
168 |
169 | SELECT @price = ISNULL(ListPrice, 0.00), @weight = ISNULL(Weight, 0.00)
170 | FROM SalesLT.Product
171 | WHERE ProductID = @productID;
172 |
173 | SET @ShippingPrice = @price/@weight;
174 | END
175 | ```
176 |
177 | When testing the stored procedure with the following code, the developer has found that the procedure works successfully:
178 |
179 | ```sql
180 | DECLARE @productID int = 680;
181 | DECLARE @shippingPrice money;
182 | EXECUTE SalesLT.up_GetShippingPrice @productID, @shippingPrice OUTPUT
183 | SELECT @shippingPrice;
184 | ```
185 |
186 | However, when using a different product ID, the stored procedure fails with an error:
187 |
188 | ```sql
189 | DECLARE @productID int = 710;
190 | DECLARE @shippingPrice money;
191 | EXECUTE SalesLT.up_GetShippingPrice @productID, @shippingPrice OUTPUT
192 | SELECT @shippingPrice;
193 | ```
194 |
195 | You must modify the stored procedure, without changing the logic used to calculate the shipping price, so that if an error occurs, it is handled gracefully; returning a shipping price of 0.00 and including the error number and message in the query output message.
196 |
197 | ### Challenge 2: Propagate an error to the calling client application
198 |
199 | Having written code to handle errors in the shipping price stored procedure, you must now modify it to handle the error and return its number and message in the output as before, but also cause the error to be propagated back to the client application that called it to be handled there.
200 |
201 | ## Challenge Solutions
202 |
203 | This section contains suggested solutions for the challenge queries.
204 |
205 | ### Challenge 1
206 |
207 | ```sql
208 | ALTER PROCEDURE SalesLT.up_GetShippingPrice (@productID int, @ShippingPrice money OUTPUT)
209 | AS
210 | BEGIN
211 | DECLARE @price money, @weight decimal;
212 |
213 | BEGIN TRY
214 | SELECT @price = ISNULL(ListPrice, 0.00), @weight = ISNULL(Weight, 0.00)
215 | FROM SalesLT.Product
216 | WHERE ProductID = @productID;
217 | SET @ShippingPrice = @price/@weight;
218 | END TRY
219 | BEGIN CATCH
220 | PRINT 'Error Number: ' + CAST(ERROR_NUMBER() AS varchar(10));
221 | PRINT 'Error Message: ' + ERROR_MESSAGE();
222 | SET @ShippingPrice = 0.00;
223 | END CATCH
224 | END
225 | ```
226 |
227 | ### Challenge 2
228 |
229 | ```sql
230 | ALTER PROCEDURE SalesLT.up_GetShippingPrice (@productID int, @ShippingPrice money OUTPUT)
231 | AS
232 | BEGIN
233 | DECLARE @price money, @weight decimal;
234 |
235 | BEGIN TRY
236 | SELECT @price = ISNULL(ListPrice, 0.00), @weight = ISNULL(Weight, 0.00)
237 | FROM SalesLT.Product
238 | WHERE ProductID = @productID;
239 | SET @ShippingPrice = @price/@weight;
240 | END TRY
241 | BEGIN CATCH
242 | PRINT 'Error Number: ' + CAST(ERROR_NUMBER() AS varchar(10));
243 | PRINT 'Error Message: ' + ERROR_MESSAGE();
244 | THROW;
245 | END CATCH
246 | END
247 | ```
248 |
--------------------------------------------------------------------------------
/Instructions/Labs/13-implement-transitions-in-tsql.md:
--------------------------------------------------------------------------------
1 | ---
2 | lab:
3 | title: 'Implement transactions with Transact SQL'
4 | module: 'Additional exercises'
5 | ---
6 |
7 | # Implement transactions with Transact SQL
8 |
9 | In this exercise, you'll use transactions to enforce data integrity in the **AdventureWorks** database.
10 |
11 | > **Note**: This exercise assumes you have created the **Adventureworks** database.
12 |
13 | ## Insert data without transactions
14 |
15 | Consider a website that needs to store customer information. As part of the customer registration, data about a customer and their address need to be stored. A customer without an address will cause problems for the shipping when orders are made.
16 |
17 | In this exercise you'll use a transaction to ensure that when a row is inserted into the **Customer** and **Address** tables, a row is also added to the **CustomerAddress** table to create a link between the customer record and the address record. If one insert fails, then all should fail.
18 |
19 | 1. Open a query editor for your **Adventureworks** database, and create a new query.
20 | 1. In the query pane, type the following code:
21 |
22 | ```sql
23 | INSERT INTO SalesLT.Customer (NameStyle, FirstName, LastName, EmailAddress, PasswordHash, PasswordSalt, rowguid, ModifiedDate)
24 | VALUES (0, 'Norman','Newcustomer','norman0@adventure-works.com','U1/CrPqSzwLTtwgBehfpIl7f1LHSFpZw1qnG1sMzFjo=','QhHP+y8=',NEWID(), GETDATE());
25 |
26 | INSERT INTO SalesLT.Address (AddressLine1, City, StateProvince, CountryRegion, PostalCode, rowguid, ModifiedDate)
27 | VALUES ('6388 Lake City Way', 'Burnaby','British Columbia','Canada','V5A 3A6',NEWID(), GETDATE());
28 |
29 | INSERT INTO SalesLT.CustomerAddress (CustomerID, AddressID, AddressType, rowguid, ModifiedDate)
30 | VALUES (IDENT_CURRENT('SalesLT.Customer'), IDENT_CURRENT('SalesLT.Address'), 'Home', NEWID(), '12-1-20212');
31 | ```
32 |
33 | 1. Run the query, and review the output messages, which should include the following error message:
34 |
35 | *Conversion failed when converting date and/or time from character string.*
36 |
37 | 1. Create a new query and enter the following code into the new query window:
38 |
39 | ```sql
40 | SELECT TOP 1 c.CustomerID, c.FirstName, c.LastName, ca.AddressID, a.City, c.ModifiedDate
41 | FROM SalesLT.Customer AS c
42 | LEFT JOIN SalesLT.CustomerAddress AS ca
43 | ON c.CustomerID = ca.CustomerID
44 | LEFT JOIN SalesLT.Address AS a
45 | ON ca.AddressID = a.AddressID
46 | ORDER BY c.CustomerID DESC;
47 | ```
48 |
49 | A new row for *Norman Newcustomer* was inserted into the Customer table (and another was inserted into the Address table). However, the insert for the CustomerAddress table failed. The database is now inconsistent as there's no link between the new customer and their address.
50 |
51 | To fix this, you'll need to delete the two rows that were inserted.
52 |
53 | 1. Create a new query with the following code and run it to delete the inconsistent data:
54 |
55 | ```sql
56 | DELETE SalesLT.Customer
57 | WHERE CustomerID = IDENT_CURRENT('SalesLT.Customer');
58 |
59 | DELETE SalesLT.Address
60 | WHERE AddressID = IDENT_CURRENT('SalesLT.Address');
61 | ```
62 |
63 | > **Note**: This code only works because you are the only user working in the database. In a real scenario, you would need to ascertain the IDs of the records that were inserted and specify them explicitly in case new customer and address records had been inserted after you ran your original code.
64 |
65 | ## Insert data using a transaction
66 |
67 | All of these statements need to run as a single atomic transaction. If any one of them fails, then all statements should fail. Let's group them together in a transaction.
68 |
69 | 1. Switch back to the original query window with the INSERT statements, and modify the code to enclose the original INSERT statements in a transaction, like this:
70 |
71 | ```sql
72 | BEGIN TRANSACTION;
73 |
74 | INSERT INTO SalesLT.Customer (NameStyle, FirstName, LastName, EmailAddress, PasswordHash, PasswordSalt, rowguid, ModifiedDate)
75 | VALUES (0, 'Norman','Newcustomer','norman0@adventure-works.com','U1/CrPqSzwLTtwgBehfpIl7f1LHSFpZw1qnG1sMzFjo=','QhHP+y8=', NEWID(), GETDATE());
76 |
77 | INSERT INTO SalesLT.Address (AddressLine1, City, StateProvince, CountryRegion, PostalCode, rowguid, ModifiedDate)
78 | VALUES ('6388 Lake City Way', 'Burnaby','British Columbia','Canada','V5A 3A6', NEWID(), GETDATE());
79 |
80 | INSERT INTO SalesLT.CustomerAddress (CustomerID, AddressID, AddressType, rowguid, ModifiedDate)
81 | VALUES (IDENT_CURRENT('SalesLT.Customer'), IDENT_CURRENT('SalesLT.Address'), 'Home', NEWID(), '12-1-20212');
82 |
83 | COMMIT TRANSACTION;
84 | ```
85 |
86 | 1. Run the code, and review the output message. Again, it looks like the first two statements succeeded and the third one failed.
87 |
88 | 1. Switch to the query containing the SELECT statement to retrieve the address city for the latest customer record, and run it. This time, there should be no record for *Norman Newcustomer*. Using a transaction with these statements has triggered an automatic rollback. The level 16 conversion error is high enough to cause all statements to be rolled back.
89 |
90 | ## Handle errors and explicitly rollback transactions
91 |
92 | Lower level errors can require that you explicitly handle the error and rollback any active transactions.
93 |
94 | 1. Switch back to the original INSERT query script, and modify the transaction as follows:
95 |
96 | ```sql
97 | BEGIN TRANSACTION;
98 |
99 | INSERT INTO SalesLT.Customer (NameStyle, FirstName, LastName, EmailAddress, PasswordHash, PasswordSalt, rowguid, ModifiedDate)
100 | VALUES (0, 'Norman','Newcustomer','norman0@adventure-works.com','U1/CrPqSzwLTtwgBehfpIl7f1LHSFpZw1qnG1sMzFjo=','QhHP+y8=', NEWID(), GETDATE());
101 |
102 | INSERT INTO SalesLT.Address (AddressLine1, City, StateProvince, CountryRegion, PostalCode, rowguid, ModifiedDate)
103 | VALUES ('6388 Lake City Way', 'Burnaby','British Columbia','Canada','V5A 3A6', NEWID(), GETDATE());
104 |
105 | INSERT INTO SalesLT.CustomerAddress (CustomerID, AddressID, AddressType, rowguid, ModifiedDate)
106 | VALUES (IDENT_CURRENT('SalesLT.Customer'), IDENT_CURRENT('SalesLT.Address'), 'Home', '16765338-dbe4-4421-b5e9-3836b9278e63', GETDATE());
107 |
108 | COMMIT TRANSACTION;
109 | ```
110 |
111 | 1. Run the modified code. This time, a different error (with a lower severity level) occurs:
112 |
113 | *Violation of UNIQUE KEY constraint 'AK_CustomerAddress_rowguid'. Cannot insert duplicate key in object 'SalesLT.CustomerAddress'. The duplicate key value is (16765338-dbe4-4421-b5e9-3836b9278e63).*
114 |
115 | 1. Switch back to the query containing the SELECT customer statement and run the query to see if the *Norman Newcustomer* row was added.
116 |
117 | Even though an error occurred in the transaction, a new record has been added and the database is once again inconsistent.
118 |
119 | 1. Switch back to the query containing the DELETE statements, and run it to delete the new inconsistent data.
120 |
121 | Enclosing the statements in a transaction isn't enough to deal with lower priority errors. You need to catch these errors and explicitly use a ROLLBACK statement. We need to combine batch error handling and transactions to resolve our data consistency issue.
122 |
123 | 1. Switch back to the query containing the transaction to insert a new customer, and modify the code to enclose the transaction in a TRY/CATCH block, and use the ROLLBACK TRANSACTION statement if an error occurs.
124 |
125 | ```sql
126 | BEGIN TRY
127 | BEGIN TRANSACTION;
128 | INSERT INTO SalesLT.Customer (NameStyle, FirstName, LastName, EmailAddress, PasswordHash, PasswordSalt, rowguid, ModifiedDate)
129 | VALUES (0, 'Norman','Newcustomer','norman0@adventure-works.com','U1/CrPqSzwLTtwgBehfpIl7f1LHSFpZw1qnG1sMzFjo=','QhHP+y8=',NEWID(), GETDATE());
130 |
131 | INSERT INTO SalesLT.Address (AddressLine1, City, StateProvince, CountryRegion, PostalCode, rowguid, ModifiedDate)
132 | VALUES ('6388 Lake City Way', 'Burnaby','British Columbia','Canada','V5A 3A6',NEWID(), GETDATE());
133 |
134 | INSERT INTO SalesLT.CustomerAddress (CustomerID, AddressID, AddressType, rowguid, ModifiedDate)
135 | VALUES (IDENT_CURRENT('SalesLT.Customer'), IDENT_CURRENT('SalesLT.Address'), 'Home', '16765338-dbe4-4421-b5e9-3836b9278e63', GETDATE());
136 | COMMIT TRANSACTION;
137 | PRINT 'Transaction committed.';
138 |
139 | END TRY
140 | BEGIN CATCH
141 | ROLLBACK TRANSACTION;
142 | PRINT 'Transaction rolled back.';
143 | END CATCH;
144 | ```
145 |
146 | 1. Run the code and review the results and messages.
147 | 1. Switch back to the query containing the SELECT customer statement and run the query to see if the *Norman Newcustomer* row was added.
148 |
149 | Note that the most recently modified customer record is not for *Norman Newcustomer* - the INSERT statement that succeeded has been rolled back to ensure the database remains consistent.
150 |
151 | ## Check the transaction state before rolling back
152 |
153 | The CATCH block will handle errors that occur anywhere in the TRY block, so if an error were to occur outside of the BEGIN TRANSACTION...COMMIT TRANSACTION block, there would be no active transaction to roll back. To avoid this issue, you can check the current transaction state with XACT_STATE(), which returns one of the following values:
154 |
155 | - **-1**: There is an active transaction in process that cannot be committed.
156 | - **0**: There are no transactions in process.
157 | - **1**: There is an active transaction in process that can be committed or rolled back.
158 |
159 | 1. Back in the original query to insert a new customer, surround the ROLLBACK statements with an IF statement checking the value, so your code looks like this.
160 |
161 | ```sql
162 | BEGIN TRY
163 | BEGIN TRANSACTION;
164 |
165 | INSERT INTO SalesLT.Customer (NameStyle, FirstName, LastName, EmailAddress, PasswordHash, PasswordSalt, rowguid, ModifiedDate)
166 | VALUES (0, 'Norman','Newcustomer','norman0@adventure-works.com','U1/CrPqSzwLTtwgBehfpIl7f1LHSFpZw1qnG1sMzFjo=','QhHP+y8=',NEWID(), GETDATE());
167 |
168 | INSERT INTO SalesLT.Address (AddressLine1, City, StateProvince, CountryRegion, PostalCode, rowguid, ModifiedDate)
169 | VALUES ('6388 Lake City Way', 'Burnaby','British Columbia','Canada','V5A 3A6',NEWID(), GETDATE());
170 |
171 | INSERT INTO SalesLT.CustomerAddress (CustomerID, AddressID, AddressType, rowguid, ModifiedDate)
172 | VALUES (IDENT_CURRENT('SalesLT.Customer'), IDENT_CURRENT('SalesLT.Address'), 'Home', '16765338-dbe4-4421-b5e9-3836b9278e63', GETDATE());
173 |
174 | COMMIT TRANSACTION;
175 | PRINT 'Transaction committed.';
176 | END TRY
177 | BEGIN CATCH
178 | PRINT 'An error occurred.'
179 | IF (XACT_STATE()) <> 0
180 | BEGIN
181 | PRINT 'Transaction in process.'
182 | ROLLBACK TRANSACTION;
183 | PRINT 'Transaction rolled back.';
184 | END;
185 | END CATCH
186 | ```
187 |
188 | 1. Run the modified code, and review the output messages - noting that an in-process transaction was detected and rolled back.
189 |
190 | 1. Modify the code as follows to avoid specifying an explicit **rowid** (which was caused the duplicate key error)
191 |
192 | ```sql
193 | BEGIN TRY
194 | BEGIN TRANSACTION;
195 |
196 | INSERT INTO SalesLT.Customer (NameStyle, FirstName, LastName, EmailAddress, PasswordHash, PasswordSalt, rowguid, ModifiedDate)
197 | VALUES (0, 'Norman','Newcustomer','norman0@adventure-works.com','U1/CrPqSzwLTtwgBehfpIl7f1LHSFpZw1qnG1sMzFjo=','QhHP+y8=',NEWID(), GETDATE());
198 |
199 | INSERT INTO SalesLT.Address (AddressLine1, City, StateProvince, CountryRegion, PostalCode, rowguid, ModifiedDate)
200 | VALUES ('6388 Lake City Way', 'Burnaby','British Columbia','Canada','V5A 3A6',NEWID(), GETDATE());
201 |
202 | INSERT INTO SalesLT.CustomerAddress (CustomerID, AddressID, AddressType, ModifiedDate)
203 | VALUES (IDENT_CURRENT('SalesLT.Customer'), IDENT_CURRENT('SalesLT.Address'), 'Home', GETDATE());
204 |
205 | COMMIT TRANSACTION;
206 | PRINT 'Transaction committed.';
207 | END TRY
208 | BEGIN CATCH
209 | PRINT 'An error occurred.'
210 | IF (XACT_STATE()) <> 0
211 | BEGIN
212 | PRINT 'Transaction in process.'
213 | ROLLBACK TRANSACTION;
214 | PRINT 'Transaction rolled back.';
215 | END;
216 | END CATCH
217 | ```
218 |
219 | 1. Run the code, and note that this time, all three INSERT statement succeed.
220 | 1. Switch back to the query containing the SELECT customer statement and run the query to verify that the *Norman Newcustomer* row was inserted into the **Customer** table along with the related records in the **Address** and **CustomerAddress** tables.
221 | 1. Back in the original INSERT query, modify the code to insert another customer - this time throwing an error within the TRY block after the transaction has been committed:
222 |
223 | ```sql
224 | BEGIN TRY
225 | BEGIN TRANSACTION;
226 |
227 | INSERT INTO SalesLT.Customer (NameStyle, FirstName, LastName, EmailAddress, PasswordHash, PasswordSalt, rowguid, ModifiedDate)
228 | VALUES (0, 'Ann','Othercustomr','ann0@adventure-works.com','U1/CrPqSzwLTtwgBehfpIl7f1LHSFpZw1qnG1sMzFjo=','QhHP+y8=',NEWID(), GETDATE());;
229 |
230 | INSERT INTO SalesLT.Address (AddressLine1, City, StateProvince, CountryRegion, PostalCode, rowguid, ModifiedDate)
231 | VALUES ('6388 Lake City Way', 'Burnaby','British Columbia','Canada','V5A 3A6',NEWID(), GETDATE());
232 |
233 | INSERT INTO SalesLT.CustomerAddress (CustomerID, AddressID, AddressType, ModifiedDate)
234 | VALUES (IDENT_CURRENT('SalesLT.Customer'), IDENT_CURRENT('SalesLT.Address'), 'Home', GETDATE());
235 |
236 | COMMIT TRANSACTION;
237 | PRINT 'Transaction committed.';
238 | THROW 51000, 'Some kind of error', 1;
239 |
240 | END TRY
241 | BEGIN CATCH
242 | PRINT 'An error occurred.'
243 | IF (XACT_STATE()) <> 0
244 | BEGIN
245 | PRINT 'Transaction in process.'
246 | ROLLBACK TRANSACTION;
247 | PRINT 'Transaction rolled back.';
248 | END;
249 | END CATCH
250 | ```
251 |
252 | 1. Run the code and review the output. All three INSERT statements should succeed, but an error is caught by the CATCH block.
253 |
254 | 1. Switch back to the query containing the SELECT customer statement and run the query to verify that a record for *Ann Othercustomer* has been inserted along with the related address records. The transaction succeeded and was not rolled back, even though an error subsequently occurred.
255 |
256 | ## Challenge
257 |
258 | Now it's time to try using what you've learned.
259 |
260 | > **Tip**: Try to determine the appropriate solution for yourself. If you get stuck, a suggested solution is provided at the end of this lab.
261 |
262 | ### Use a transaction to insert data into multiple tables
263 |
264 | When a sales order header is inserted, it must have at least one corresponding sales order detail record. Currently, you use the following code to accomplish this:
265 |
266 | ```sql
267 | -- Get the highest order ID and add 1
268 | DECLARE @OrderID INT;
269 | SELECT @OrderID = MAX(SalesOrderID) + 1 FROM SalesLT.SalesOrderHeader;
270 |
271 | -- Insert the order header
272 | INSERT INTO SalesLT.SalesOrderHeader (SalesOrderID, OrderDate, DueDate, CustomerID, ShipMethod)
273 | VALUES (@OrderID, GETDATE(), DATEADD(month, 1, GETDATE()), 1, 'CARGO TRANSPORT');
274 |
275 | -- Insert one or more order details
276 | INSERT INTO SalesLT.SalesOrderDetail (SalesOrderID, OrderQty, ProductID, UnitPrice)
277 | VALUES (@OrderID, 1, 712, 8.99);
278 | ```
279 |
280 | You need to encapsulate this code in a transaction so that all inserts succeed or fail as an atomic unit or work.
281 |
282 | ## Challenge solution
283 |
284 | ### Use a transaction to insert data into multiple tables
285 |
286 | The following code encloses the logic to insert a new order and order detail in a transaction, rolling back the transaction if an error occurs.
287 |
288 | ```sql
289 | BEGIN TRY
290 | BEGIN TRANSACTION;
291 | -- Get the highest order ID and add 1
292 | DECLARE @OrderID INT;
293 | SELECT @OrderID = MAX(SalesOrderID) + 1 FROM SalesLT.SalesOrderHeader;
294 |
295 | -- Insert the order header
296 | INSERT INTO SalesLT.SalesOrderHeader (SalesOrderID, OrderDate, DueDate, CustomerID, ShipMethod)
297 | VALUES (@OrderID, GETDATE(), DATEADD(month, 1, GETDATE()), 1, 'CARGO TRANSPORT');
298 |
299 | -- Insert one or more order details
300 | INSERT INTO SalesLT.SalesOrderDetail (SalesOrderID, OrderQty, ProductID, UnitPrice)
301 | VALUES (@OrderID, 1, 712, 8.99);
302 |
303 | COMMIT TRANSACTION;
304 | PRINT 'Transaction committed.';
305 |
306 | END TRY
307 | BEGIN CATCH
308 | PRINT 'An error occurred.'
309 | IF (XACT_STATE()) <> 0
310 | BEGIN
311 | PRINT 'Transaction in process.'
312 | ROLLBACK TRANSACTION;
313 | PRINT 'Transaction rolled back.';
314 | END;
315 | END CATCH
316 | ```
317 |
318 | To test the transaction, try to insert an order detail with an invalid product ID, like this:
319 |
320 | ```sql
321 | BEGIN TRY
322 | BEGIN TRANSACTION;
323 | -- Get the highest order ID and add 1
324 | DECLARE @OrderID INT;
325 | SELECT @OrderID = MAX(SalesOrderID) + 1 FROM SalesLT.SalesOrderHeader;
326 |
327 | -- Insert the order header
328 | INSERT INTO SalesLT.SalesOrderHeader (SalesOrderID, OrderDate, DueDate, CustomerID, ShipMethod)
329 | VALUES (@OrderID, GETDATE(), DATEADD(month, 1, GETDATE()), 1, 'CARGO TRANSPORT');
330 |
331 | -- Insert one or more order details
332 | INSERT INTO SalesLT.SalesOrderDetail (SalesOrderID, OrderQty, ProductID, UnitPrice)
333 | VALUES (@OrderID, 1, 'Invalid product', 8.99);
334 |
335 | COMMIT TRANSACTION;
336 | PRINT 'Transaction committed.';
337 |
338 | END TRY
339 | BEGIN CATCH
340 | PRINT 'An error occurred.'
341 | IF (XACT_STATE()) <> 0
342 | BEGIN
343 | PRINT 'Transaction in process.'
344 | ROLLBACK TRANSACTION;
345 | PRINT 'Transaction rolled back.';
346 | END;
347 | END CATCH
348 | ```
349 |
--------------------------------------------------------------------------------
/Instructions/Labs/images/adventureworks-erd.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/MicrosoftLearning/dp-080-Transact-SQL/7178866374e687e4404b48e80411f14595d474fa/Instructions/Labs/images/adventureworks-erd.png
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | MIT License
2 |
3 | Copyright (c) 2019 Sidney Andrews
4 |
5 | Permission is hereby granted, free of charge, to any person obtaining a copy
6 | of this software and associated documentation files (the "Software"), to deal
7 | in the Software without restriction, including without limitation the rights
8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
9 | copies of the Software, and to permit persons to whom the Software is
10 | furnished to do so, subject to the following conditions:
11 |
12 | The above copyright notice and this permission notice shall be included in all
13 | copies or substantial portions of the Software.
14 |
15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
21 | SOFTWARE.
--------------------------------------------------------------------------------
/Scripts/adventureworkslt.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/MicrosoftLearning/dp-080-Transact-SQL/7178866374e687e4404b48e80411f14595d474fa/Scripts/adventureworkslt.sql
--------------------------------------------------------------------------------
/Scripts/module01-demos.sql:
--------------------------------------------------------------------------------
1 | -- This script contains demo code for Module 1 of the Transact-SQL course
2 |
3 |
4 | -- BASIC QUERIES
5 |
6 | -- Select all columns
7 | SELECT * FROM SalesLT.Customer;
8 |
9 | -- Select specific columns
10 | SELECT CustomerID, FirstName, LastName
11 | FROM SalesLT.Customer;
12 |
13 | -- Select an expression
14 | SELECT CustomerID, FirstName + ' ' + LastName
15 | FROM SalesLT.Customer;
16 |
17 | -- Apply an alias
18 | SELECT CustomerID, FirstName + ' ' + LastName AS CustomerName
19 | FROM SalesLT.Customer;
20 |
21 |
22 |
23 |
24 | -- DATA TYPES
25 |
26 | -- Try to combine incompatible data types (results in error)
27 | SELECT CustomerID + ':' + EmailAddress AS CustomerIdentifier
28 | FROM SalesLT.Customer;
29 |
30 | -- Use cast
31 | SELECT CAST(CustomerID AS varchar) + ':' + EmailAddress AS CustomerIdentifier
32 | FROM SalesLT.Customer;
33 |
34 | -- Use convert
35 | SELECT CONVERT(varchar, CustomerID) + ':' + EmailAddress AS CustomerIdentifier
36 | FROM SalesLT.Customer;
37 |
38 | -- convert dates
39 | SELECT CustomerID,
40 | CONVERT(nvarchar(30), ModifiedDate) AS ConvertedDate,
41 | CONVERT(nvarchar(30), ModifiedDate, 126) AS ISO8601FormatDate
42 | FROM SalesLT.Customer;
43 |
44 |
45 |
46 |
47 | -- NULL VALUES
48 |
49 | -- See the effect of expressions with NULL values
50 | SELECT CustomerID, Title + ' ' + LastName AS Greeting
51 | FROM SalesLT.Customer;
52 |
53 | -- Replace NULL value (use ? if Title is NULL)
54 | SELECT CustomerID, ISNULL(Title, '?') + ' ' + LastName AS Greeting
55 | FROM SalesLT.Customer;
56 |
57 | -- Coalesce (use first non-NULL value)
58 | SELECT CustomerID, COALESCE(Title, FirstName) + ' ' + LastName AS Greeting
59 | FROM SalesLT.Customer;
60 |
61 | -- Convert specific values to NULL
62 | SELECT SalesOrderID, ProductID, UnitPrice, NULLIF(UnitPriceDiscount, 0) AS Discount
63 | FROM SalesLT.SalesOrderDetail;
64 |
65 |
66 |
67 |
68 | -- CASE statement
69 |
70 | --Simple case
71 | SELECT CustomerID,
72 | CASE
73 | WHEN Title IS NOT NULL AND MiddleName IS NOT NULL
74 | THEN Title + ' ' + FirstName + ' ' + MiddleName + ' ' + LastName
75 | WHEN Title IS NOT NULL AND MiddleName IS NULL
76 | THEN Title + ' ' + FirstName + ' ' + LastName
77 | ELSE FirstName + ' ' + LastName
78 | END AS CustomerName
79 | FROM SalesLT.Customer;
80 |
81 | -- Searched case
82 | SELECT FirstName, LastName,
83 | CASE Suffix
84 | WHEN 'Sr.' THEN 'Senior'
85 | WHEN 'Jr.' THEN 'Junior'
86 | ELSE ISNULL(Suffix, '')
87 | END AS NameSuffix
88 | FROM SalesLT.Customer;
89 |
--------------------------------------------------------------------------------
/Scripts/module02-demos.sql:
--------------------------------------------------------------------------------
1 | -- This script contains demo code for Module 2 of the Transact-SQL course
2 |
3 |
4 | -- ORDER BY
5 |
6 | -- Sort by column
7 | SELECT AddressLine1, City, PostalCode, CountryRegion
8 | FROM SalesLT.Address
9 | ORDER BY CountryRegion;
10 |
11 | -- Sort and subsort
12 | SELECT AddressLine1, City, PostalCode, CountryRegion
13 | FROM SalesLT.Address
14 | ORDER BY CountryRegion, City;
15 |
16 | -- Descending
17 | SELECT AddressLine1, City, PostalCode, CountryRegion
18 | FROM SalesLT.Address
19 | ORDER BY CountryRegion DESC, City ASC;
20 |
21 |
22 |
23 | -- TOP
24 |
25 | -- Top records
26 | SELECT TOP (10) AddressLine1, ModifiedDate
27 | FROM SalesLT.Address
28 | ORDER BY ModifiedDate DESC;
29 |
30 | -- Top with ties
31 | SELECT TOP (10) WITH TIES AddressLine1, ModifiedDate
32 | FROM SalesLT.Address
33 | ORDER BY ModifiedDate DESC;
34 |
35 | -- Top percent
36 | SELECT TOP (10) PERCENT AddressLine1, ModifiedDate
37 | FROM SalesLT.Address
38 | ORDER BY ModifiedDate DESC;
39 |
40 |
41 |
42 | -- OFFSET and FETCH
43 |
44 | -- First 10 rows
45 | SELECT AddressLine1, ModifiedDate
46 | FROM SalesLT.Address
47 | ORDER BY ModifiedDate DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY;
48 |
49 | -- Next page
50 | SELECT AddressLine1, ModifiedDate
51 | FROM SalesLT.Address
52 | ORDER BY ModifiedDate DESC OFFSET 10 ROWS FETCH NEXT 10 ROWS ONLY;
53 |
54 |
55 |
56 | -- ALL and DISTINCT
57 |
58 | -- Implicit all
59 | SELECT City
60 | FROM SalesLT.Address;
61 |
62 | -- Explicit all
63 | SELECT ALL City
64 | FROM SalesLT.Address;
65 |
66 | -- Distinct
67 | SELECT DISTINCT City
68 | FROM SalesLT.Address;
69 |
70 | -- Distinct combination
71 | SELECT DISTINCT City, PostalCode
72 | FROM SalesLT.Address;
73 |
74 |
75 |
76 | -- WHERE CLAUSE
77 |
78 | -- Simple filter
79 | SELECT AddressLine1, City, PostalCode
80 | FROM SalesLT.Address
81 | WHERE CountryRegion = 'United Kingdom'
82 | ORDER BY City, PostalCode;
83 |
84 | -- Multiple criteria (and)
85 | SELECT AddressLine1, City, PostalCode
86 | FROM SalesLT.Address
87 | WHERE CountryRegion = 'United Kingdom'
88 | AND City = 'London'
89 | ORDER BY PostalCode;
90 |
91 | -- Multiple criteria (or)
92 | SELECT AddressLine1, City, PostalCode, CountryRegion
93 | FROM SalesLT.Address
94 | WHERE CountryRegion = 'United Kingdom'
95 | OR CountryRegion = 'Canada'
96 | ORDER BY CountryRegion, PostalCode;
97 |
98 | -- Nested conditions
99 | SELECT AddressLine1, City, PostalCode
100 | FROM SalesLT.Address
101 | WHERE CountryRegion = 'United Kingdom'
102 | AND (City = 'London' OR City = 'Oxford')
103 | ORDER BY City, PostalCode;
104 |
105 | -- Not equal to
106 | SELECT AddressLine1, City, PostalCode
107 | FROM SalesLT.Address
108 | WHERE CountryRegion = 'United Kingdom'
109 | AND City <> 'London'
110 | ORDER BY City, PostalCode;
111 |
112 | -- Greater than
113 | SELECT AddressLine1, City, PostalCode
114 | FROM SalesLT.Address
115 | WHERE CountryRegion = 'United Kingdom'
116 | AND City = 'London'
117 | AND PostalCode > 'S'
118 | ORDER BY PostalCode;
119 |
120 | -- Like with wildcard
121 | SELECT AddressLine1, City, PostalCode
122 | FROM SalesLT.Address
123 | WHERE CountryRegion = 'United Kingdom'
124 | AND City = 'London'
125 | AND PostalCode LIKE 'SW%'
126 | ORDER BY PostalCode;
127 |
128 | -- Like with regex pattern
129 | SELECT AddressLine1, City, PostalCode
130 | FROM SalesLT.Address
131 | WHERE CountryRegion = 'United Kingdom'
132 | AND City = 'London'
133 | AND PostalCode LIKE 'SW[0-9] [0-9]__'
134 | ORDER BY PostalCode;
135 |
136 | -- check for null
137 | SELECT AddressLine1, AddressLine2, City, PostalCode
138 | FROM SalesLT.Address
139 | WHERE AddressLine2 IS NOT NULL
140 | ORDER BY City, PostalCode;
141 |
142 | -- within a range
143 | SELECT AddressLine1, ModifiedDate
144 | FROM SalesLT.Address
145 | WHERE ModifiedDate BETWEEN '01/01/2005' AND '12/31/2005'
146 | ORDER BY ModifiedDate;
147 |
148 | -- In a list
149 | SELECT AddressLine1, City, CountryRegion
150 | FROM SalesLT.Address
151 | WHERE CountryRegion IN ('Canada', 'United States')
152 | ORDER BY City;
--------------------------------------------------------------------------------
/Scripts/module03-demos.sql:
--------------------------------------------------------------------------------
1 | -- This script contains demo code for Module 3 of the Transact-SQL course
2 |
3 |
4 | -- INNER joins
5 |
6 | -- Implicit
7 | SELECT p.ProductID, m.Name AS Model, p.Name AS Product
8 | FROM SalesLT.Product AS p
9 | JOIN SalesLT.ProductModel AS m
10 | ON p.ProductModelID = m.ProductModelID
11 | ORDER BY p.ProductID;
12 |
13 | -- Explicit
14 | SELECT p.ProductID, m.Name AS Model, p.Name AS Product
15 | FROM SalesLT.Product AS p
16 | INNER JOIN SalesLT.ProductModel AS m
17 | ON p.ProductModelID = m.ProductModelID
18 | ORDER BY p.ProductID;
19 |
20 | -- Multiple joins
21 | SELECT od.SalesOrderID, m.Name AS Model, p.Name AS ProductName, od.OrderQty
22 | FROM SalesLT.Product AS p
23 | JOIN SalesLT.ProductModel AS m
24 | ON p.ProductModelID = m.ProductModelID
25 | JOIN SalesLT.SalesOrderDetail AS od
26 | ON p.ProductID = od.ProductID
27 | ORDER BY od.SalesOrderID;
28 |
29 |
30 |
31 | -- OUTER Joins
32 |
33 | -- Left outer join
34 | SELECT od.SalesOrderID, p.Name AS ProductName, od.OrderQty
35 | FROM SalesLT.Product AS p
36 | LEFT OUTER JOIN SalesLT.SalesOrderDetail AS od
37 | ON p.ProductID = od.ProductID
38 | ORDER BY od.SalesOrderID;
39 |
40 | -- Outer keyword is optional
41 | SELECT od.SalesOrderID, p.Name AS ProductName, od.OrderQty
42 | FROM SalesLT.Product AS p
43 | LEFT JOIN SalesLT.SalesOrderDetail AS od
44 | ON p.ProductID = od.ProductID
45 | ORDER BY od.SalesOrderID;
46 |
47 |
48 |
49 | -- CROSS JOIN
50 |
51 | -- Every product/city combination
52 | SELECT p.Name AS Product, a.City
53 | FROM SalesLT.Product AS p
54 | CROSS JOIN SalesLT.Address AS a;
55 |
56 |
57 |
58 | -- SELF JOIN
59 |
60 | -- Prepare the demo
61 | -- There's no employee table, so we'll create one for this example
62 | CREATE TABLE SalesLT.Employee
63 | (EmployeeID int IDENTITY PRIMARY KEY,
64 | EmployeeName nvarchar(256),
65 | ManagerID int);
66 | GO
67 | -- Get salesperson from Customer table and generate managers
68 | INSERT INTO SalesLT.Employee (EmployeeName, ManagerID)
69 | SELECT DISTINCT Salesperson, NULLIF(CAST(RIGHT(SalesPerson, 1) as INT), 0)
70 | FROM SalesLT.Customer;
71 | GO
72 | UPDATE SalesLT.Employee
73 | SET ManagerID = (SELECT MIN(EmployeeID) FROM SalesLT.Employee WHERE ManagerID IS NULL)
74 | WHERE ManagerID IS NULL
75 | AND EmployeeID > (SELECT MIN(EmployeeID) FROM SalesLT.Employee WHERE ManagerID IS NULL);
76 | GO
77 |
78 | -- Here's the actual self-join demo
79 | SELECT e.EmployeeName, m.EmployeeName AS ManagerName
80 | FROM SalesLT.Employee AS e
81 | LEFT JOIN SalesLT.Employee AS m
82 | ON e.ManagerID = m.EmployeeID
83 | ORDER BY e.ManagerID;
84 |
85 |
86 |
87 | -- SIMPLE SUBQUERIES
88 |
89 | -- Scalar subquery
90 | -- Outer query
91 | SELECT p.Name, p.StandardCost
92 | FROM SalesLT.Product AS p
93 | WHERE StandardCost <
94 | -- Inner query
95 | (SELECT AVG(StandardCost)
96 | FROM SalesLT.Product)
97 | ORDER BY p.StandardCost DESC;
98 |
99 | --Multivalue subquery
100 | -- Outer query
101 | SELECT p.Name, p.StandardCost
102 | FROM SalesLT.Product AS p
103 | WHERE p.ProductID IN
104 | -- Inner query
105 | (SELECT ProductID
106 | FROM SalesLT.SalesOrderDetail)
107 | ORDER BY p.StandardCost DESC;
108 |
109 |
110 |
111 | -- CORRELATED SUBQUERY
112 |
113 | -- Outer query
114 | SELECT SalesOrderID, CustomerID, OrderDate
115 | FROM SalesLT.SalesOrderHeader AS o1
116 | WHERE SalesOrderID =
117 | -- Inner query
118 | (SELECT MAX(SalesOrderID)
119 | FROM SalesLT.SalesOrderHeader AS o2
120 | --References alias in outer query
121 | WHERE o2.CustomerID = o1.CustomerID)
122 | ORDER BY CustomerID, OrderDate;
123 |
124 | -- Outer query
125 | SELECT od.SalesOrderID, od.OrderQty,
126 | -- Inner query
127 | (SELECT Name
128 | FROM SalesLT.Product AS p
129 | --References alias in outer query
130 | WHERE p.ProductID = od.ProductID) AS ProductName
131 | FROM SalesLT.SalesOrderDetail AS od
132 | ORDER BY od.SalesOrderID
133 |
134 | -- Using EXISTS
135 | -- Outer query
136 | SELECT CustomerID, CompanyName, EmailAddress
137 | FROM SalesLT.Customer AS c
138 | WHERE EXISTS
139 | -- Inner query
140 | (SELECT *
141 | FROM SalesLT.SalesOrderHeader AS o
142 | --References alias in outer query
143 | WHERE o.CustomerID = c.CustomerID);
144 |
145 |
--------------------------------------------------------------------------------
/Scripts/module04-demos.sql:
--------------------------------------------------------------------------------
1 | -- This script contains demo code for Module 5 of the Transact-SQL course
2 |
3 |
4 |
5 | -- Basic scalar functions
6 |
7 | -- Dates
8 | SELECT SalesOrderID,
9 | OrderDate,
10 | YEAR(OrderDate) AS OrderYear,
11 | DATENAME(mm,OrderDate) AS OrderMonth,
12 | DAY(OrderDate) AS OrderDay,
13 | DATENAME(dw, OrderDate) AS OrderWeekDay,
14 | DATEDIFF(yy,OrderDate, GETDATE()) AS YearsSinceOrder
15 | FROM SalesLT.SalesOrderHeader;
16 |
17 |
18 | -- Math
19 | SELECT TaxAmt,
20 | ROUND(TaxAmt, 0) AS Rounded,
21 | FLOOR(TaxAmt) AS Floor,
22 | CEILING(TaxAmt) AS Ceiling,
23 | SQUARE(TaxAmt) AS Squared,
24 | SQRT(TaxAmt) AS Root,
25 | LOG(TaxAmt) AS Log,
26 | TaxAmt * RAND() AS Randomized
27 | FROM SalesLT.SalesOrderHeader;
28 |
29 |
30 | -- Text
31 | SELECT CompanyName,
32 | UPPER(CompanyName) AS UpperCase,
33 | LOWER(CompanyName) AS LowerCase,
34 | LEN(CompanyName) AS Length,
35 | REVERSE(CompanyName) AS Reversed,
36 | CHARINDEX(' ', CompanyName) AS FirstSpace,
37 | LEFT(CompanyName, CHARINDEX(' ', CompanyName)) AS FirstWord,
38 | SUBSTRING(CompanyName, CHARINDEX(' ', CompanyName) + 1, LEN(CompanyName)) AS RestOfName
39 | FROM SalesLT.Customer;
40 |
41 |
42 |
43 |
44 | -- Logical
45 |
46 | -- IIF
47 | SELECT AddressType, -- Evaluation if True if False
48 | IIF(AddressType = 'Main Office', 'Billing', 'Mailing') AS UseAddressFor
49 | FROM SalesLT.CustomerAddress;
50 |
51 |
52 | -- CHOOSE
53 |
54 | -- Prepare by updating status to a value between 1 and 5
55 | UPDATE SalesLT.SalesOrderHeader
56 | SET Status = SalesOrderID % 5 + 1
57 |
58 | -- Now use CHOOSE to map the status code to a value in a list
59 | SELECT SalesOrderID, Status,
60 | CHOOSE(Status, 'Ordered', 'Confirmed', 'Shipped', 'Delivered', 'Completed') AS OrderStatus
61 | FROM SalesLT.SalesOrderHeader;
62 |
63 |
64 |
65 |
66 | -- RANKING Functions
67 |
68 | -- Ranking
69 | SELECT TOP (100) ProductID, Name, ListPrice,
70 | RANK() OVER(ORDER BY ListPrice DESC) AS RankByPrice
71 | FROM SalesLT.Product AS p
72 | ORDER BY RankByPrice;
73 |
74 | -- Partitioning
75 | SELECT c.Name AS Category, p.Name AS Product, ListPrice,
76 | RANK() OVER(PARTITION BY c.Name ORDER BY ListPrice DESC) AS RankByPrice
77 | FROM SalesLT.Product AS p
78 | JOIN SalesLT.ProductCategory AS c
79 | ON p.ProductCategoryID = c.ProductcategoryID
80 | ORDER BY Category, RankByPrice;
81 |
82 |
83 |
84 | -- ROWSET Functions
85 |
86 | -- Use OPENROWSET to retrieve external data
87 | -- (Advanced option needs to be enabled to allow this)
88 | EXEC sp_configure 'show advanced options', 1;
89 | RECONFIGURE;
90 | GO
91 | EXEC sp_configure 'Ad Hoc Distributed Queries', 1;
92 | RECONFIGURE;
93 | GO
94 | -- Now we can use OPENROWSET to connect to an external data source and return a rowset
95 | SELECT a.*
96 | FROM OPENROWSET('SQLNCLI', 'Server=localhost\SQLEXPRESS;Trusted_Connection=yes;',
97 | 'SELECT Name, ListPrice
98 | FROM adventureworks.SalesLT.Product') AS a;
99 |
100 |
101 |
102 | -- Use OPENXML to read data from an XML document into a rowset
103 | -- First prepare an XML document
104 | DECLARE @idoc INT, @doc VARCHAR(1000);
105 | SET @doc = '
106 |
107 | This is a really great product!
108 |
109 |
110 | Fantasic - I love this product!!
111 |
112 | ';
113 | EXEC sp_xml_preparedocument @idoc OUTPUT, @doc;
114 | -- Now use OPENXML to read attributes and elements into a rowset
115 | SELECT ProductID, Reviewer, ReviewText
116 | FROM OPENXML (@idoc, '/Reviews/Review',3)
117 | WITH (ProductID INT,
118 | Reviewer VARCHAR(20),
119 | ReviewText VARCHAR(MAX));
120 |
121 |
122 |
123 | -- Use OPENJSON to read a JSON document
124 | -- First prepare a JSON document
125 | DECLARE @jsonCustomer NVARCHAR(max) = N'{
126 | "id" : 1,
127 | "firstName": "John",
128 | "lastName": "Smith",
129 | "dateOfBirth": "2015-03-25T12:00:00"
130 | }';
131 | -- Now read the JSON values into a rowset
132 | SELECT *
133 | FROM OPENJSON(@jsonCustomer)
134 | WITH (id INT,
135 | firstName NVARCHAR(50),
136 | lastName NVARCHAR(50),
137 | dateOfBirth DATETIME);
138 |
139 |
140 |
141 | -- Aggregate functions and GROUP BY
142 |
143 | -- Aggergate functions
144 | SELECT COUNT(*) AS ProductCount,
145 | MIN(ListPrice) AS MinPrice,
146 | MAX(ListPrice) AS MaxPrice,
147 | AVG(ListPrice) AS AvgPrice
148 | FROM SalesLT.Product
149 |
150 |
151 | -- Group by
152 | SELECT c.Name AS Category,
153 | COUNT(*) AS ProductCount,
154 | MIN(p.ListPrice) AS MinPrice,
155 | MAX(p.ListPrice) AS MaxPrice,
156 | AVG(p.ListPrice) AS AvgPrice
157 | FROM SalesLT.ProductCategory AS c
158 | JOIN SalesLT.Product AS p
159 | ON p.ProductCategoryID = c.ProductCategoryID
160 | GROUP BY c.Name -- (can't use alias because GROUP BY happens before SELECT)
161 | ORDER BY Category; -- (can use alias because ORDER BY happens after SELECT)
162 |
163 | -- Filter aggregated groups
164 | -- How NOT to do it!
165 | SELECT c.Name AS Category,
166 | COUNT(*) AS ProductCount,
167 | MIN(p.ListPrice) AS MinPrice,
168 | MAX(p.ListPrice) AS MaxPrice,
169 | AVG(p.ListPrice) AS AvgPrice
170 | FROM SalesLT.ProductCategory AS c
171 | JOIN SalesLT.Product AS p
172 | ON p.ProductCategoryID = c.ProductCategoryID
173 | WHERE COUNT(*) > 1 -- Attempt to filter on grouped aggregate = error!
174 | GROUP BY c.Name
175 | ORDER BY Category;
176 |
177 | -- How to do it
178 | SELECT c.Name AS Category,
179 | COUNT(*) AS ProductCount,
180 | MIN(p.ListPrice) AS MinPrice,
181 | MAX(p.ListPrice) AS MaxPrice,
182 | AVG(p.ListPrice) AS AvgPrice
183 | FROM SalesLT.ProductCategory AS c
184 | JOIN SalesLT.Product AS p
185 | ON p.ProductCategoryID = c.ProductCategoryID
186 | GROUP BY c.Name
187 | HAVING COUNT(*) > 1 -- Use HAVING to filter after grouping
188 | ORDER BY Category;
189 |
190 |
--------------------------------------------------------------------------------
/Scripts/module05-demos.sql:
--------------------------------------------------------------------------------
1 | -- This script contains demo code for Module 6 of the Transact-SQL course
2 |
3 |
4 |
5 | -- CREATE A TABLE FOR THE DEMOS
6 |
7 | CREATE TABLE SalesLT.Promotion
8 | (
9 | PromotionID int IDENTITY PRIMARY KEY,
10 | PromotionName varchar(20),
11 | StartDate datetime NOT NULL DEFAULT GETDATE(),
12 | ProductModelID int NOT NULL REFERENCES SalesLT.ProductModel(ProductModelID),
13 | Discount decimal(4,2) NOT NULL,
14 | Notes nvarchar(max) NULL
15 | );
16 |
17 | -- Show it's empty
18 | SELECT * FROM SalesLT.Promotion;
19 |
20 |
21 |
22 | -- INSERT
23 |
24 | -- Basic insert with all columns by position
25 | INSERT INTO SalesLT.Promotion
26 | VALUES
27 | ('Clearance Sale', '01/01/2021', 23, 0.1, '10% discount')
28 |
29 | SELECT * FROM SalesLT.Promotion;
30 |
31 |
32 | -- Use defaults and NULLs
33 | INSERT INTO SalesLT.Promotion
34 | VALUES
35 | ('Pull your socks up', DEFAULT, 24, 0.25, NULL)
36 |
37 | SELECT * FROM SalesLT.Promotion;
38 |
39 |
40 | -- Explicit columns
41 | INSERT INTO SalesLT.Promotion (PromotionName, ProductModelID, Discount)
42 | VALUES
43 | ('Caps Locked', 2, 0.2)
44 |
45 | SELECT * FROM SalesLT.Promotion;
46 |
47 | -- Multiple rows
48 | INSERT INTO SalesLT.Promotion
49 | VALUES
50 | ('The gloves are off!', DEFAULT, 3, 0.25, NULL),
51 | ('The gloves are off!', DEFAULT, 4, 0.25, NULL)
52 |
53 | SELECT * FROM SalesLT.Promotion;
54 |
55 |
56 | -- Insert from query
57 | INSERT INTO SalesLT.Promotion (PromotionName, ProductModelID, Discount, Notes)
58 | SELECT DISTINCT 'Get Framed', m.ProductModelID, 0.1, '10% off ' + m.Name
59 | FROM SalesLT.ProductModel AS m
60 | WHERE m.Name LIKE '%frame%';
61 |
62 | SELECT * FROM SalesLT.Promotion;
63 |
64 |
65 | -- SELECT...INTO
66 | SELECT SalesOrderID, CustomerID, OrderDate, PurchaseOrderNumber, TotalDue
67 | INTO SalesLT.Invoice
68 | FROM SalesLT.SalesOrderHeader;
69 |
70 | SELECT * FROM SalesLT.Invoice;
71 |
72 |
73 | -- Retrieve inserted identity value
74 | INSERT INTO SalesLT.Promotion (PromotionName, ProductModelID, Discount)
75 | VALUES
76 | ('A short sale',13, 0.3);
77 |
78 | SELECT SCOPE_IDENTITY() AS LatestIdentityInDB;
79 |
80 | SELECT IDENT_CURRENT('SalesLT.Promotion') AS LatestPromotionID;
81 |
82 | SELECT * FROM SalesLT.Promotion;
83 |
84 | -- Override Identity
85 | SET IDENTITY_INSERT SalesLT.Promotion ON;
86 |
87 | INSERT INTO SalesLT.Promotion (PromotionID, PromotionName, ProductModelID, Discount)
88 | VALUES
89 | (20, 'Another short sale',37, 0.3);
90 |
91 | SET IDENTITY_INSERT SalesLT.Promotion OFF;
92 |
93 | SELECT * FROM SalesLT.Promotion;
94 |
95 |
96 | -- Sequences
97 |
98 | -- Create sequence
99 | CREATE SEQUENCE SalesLT.InvoiceNumbers AS INT
100 | START WITH 72000 INCREMENT BY 1;
101 |
102 | -- Get next value
103 | SELECT NEXT VALUE FOR SalesLT.InvoiceNumbers;
104 |
105 | -- Get next value again (automatically increments on each retrieval)
106 | SELECT NEXT VALUE FOR SalesLT.InvoiceNumbers;
107 |
108 | -- Insert using next sequence value
109 | INSERT INTO SalesLT.Invoice
110 | VALUES
111 | (NEXT VALUE FOR SalesLT.InvoiceNumbers, 2, GETDATE(), 'PO12345', 107.99);
112 |
113 | SELECT * FROM SalesLT.Invoice;
114 |
115 |
116 |
117 |
118 | -- UPDATE
119 |
120 | -- Update a single field
121 | UPDATE SalesLT.Promotion
122 | SET Notes = '25% off socks'
123 | WHERE PromotionID = 2;
124 |
125 | SELECT * FROM SalesLT.Promotion;
126 |
127 |
128 | -- Update multiple fields
129 | UPDATE SalesLT.Promotion
130 | SET Discount = 0.2, Notes = REPLACE(Notes, '10%', '20%')
131 | WHERE PromotionName = 'Get Framed';
132 |
133 | SELECT * FROM SalesLT.Promotion;
134 |
135 | -- Update from query
136 | UPDATE SalesLT.Promotion
137 | SET Notes = FORMAT(Discount, 'P') + ' off ' + m.Name
138 | FROM SalesLT.ProductModel AS m
139 | WHERE Notes IS NULL
140 | AND SalesLT.Promotion.ProductModelID = m.ProductModelID;
141 |
142 | SELECT * FROM SalesLT.Promotion;
143 |
144 |
145 |
146 | -- Delete data
147 | DELETE FROM SalesLT.Promotion
148 | WHERE StartDate < DATEADD(dd, -7, GETDATE());
149 |
150 | SELECT * FROM SalesLT.Promotion;
151 |
152 | -- Truncate to remove all rows
153 | TRUNCATE TABLE SalesLT.Promotion;
154 |
155 | SELECT * FROM SalesLT.Promotion;
156 |
157 |
158 |
159 |
160 | -- Merge insert and update
161 | -- Create a source table with staged changes (don't worry about the details)
162 | SELECT SalesOrderID, CustomerID, OrderDate, PurchaseOrderNumber, TotalDue * 1.1 AS TotalDue
163 | INTO #InvoiceStaging
164 | FROM SalesLT.SalesOrderHeader
165 | WHERE PurchaseOrderNumber = 'PO29111718'
166 | UNION
167 | SELECT 79999, 1, GETDATE(), 'PO54321', 202.99;
168 |
169 | -- Here's the staged data
170 | SELECT * FROM #InvoiceStaging;
171 |
172 | -- Now merge the staged changes
173 | MERGE INTO SalesLT.Invoice as i
174 | USING #InvoiceStaging as s
175 | ON i.SalesOrderID = s.SalesOrderID
176 | WHEN MATCHED THEN
177 | UPDATE SET i.CustomerID = s.CustomerID,
178 | i.OrderDate = GETDATE(),
179 | i.PurchaseOrderNumber = s.PurchaseOrderNumber,
180 | i.TotalDue = s.TotalDue
181 | WHEN NOT MATCHED THEN
182 | INSERT (SalesOrderID, CustomerID, OrderDate, PurchaseOrderNumber, TotalDue)
183 | VALUES (s.SalesOrderID, s.CustomerID, s.OrderDate, s.PurchaseOrderNumber, s.TotalDue);
184 |
185 | -- View the merged table
186 | SELECT * FROM SalesLT.Invoice
187 | ORDER BY OrderDate DESC;
188 |
--------------------------------------------------------------------------------
/_build.yml:
--------------------------------------------------------------------------------
1 | name: '$(Date:yyyyMMdd)$(Rev:.rr)'
2 | jobs:
3 | - job: build_markdown_content
4 | displayName: 'Build Markdown Content'
5 | workspace:
6 | clean: all
7 | pool:
8 | vmImage: 'Ubuntu 16.04'
9 | container:
10 | image: 'microsoftlearning/markdown-build:latest'
11 | steps:
12 | - task: Bash@3
13 | displayName: 'Build Content'
14 | inputs:
15 | targetType: inline
16 | script: |
17 | cp /{attribution.md,template.docx,package.json,package.js} .
18 | npm install
19 | node package.js --version $(Build.BuildNumber)
20 | - task: GitHubRelease@0
21 | displayName: 'Create GitHub Release'
22 | inputs:
23 | gitHubConnection: 'github-microsoftlearning-organization'
24 | repositoryName: '$(Build.Repository.Name)'
25 | tagSource: manual
26 | tag: 'v$(Build.BuildNumber)'
27 | title: 'Version $(Build.BuildNumber)'
28 | releaseNotesSource: input
29 | releaseNotes: '# Version $(Build.BuildNumber) Release'
30 | assets: '$(Build.SourcesDirectory)/out/*.zip'
31 | assetUploadMode: replace
32 | - task: PublishBuildArtifacts@1
33 | displayName: 'Publish Output Files'
34 | inputs:
35 | pathtoPublish: '$(Build.SourcesDirectory)/out/'
36 | artifactName: 'Lab Files'
37 |
--------------------------------------------------------------------------------
/_config.yml:
--------------------------------------------------------------------------------
1 | remote_theme: MicrosoftLearning/Jekyll-Theme
2 | exclude:
3 | - readme.md
4 | - .github/
5 | header_pages:
6 | - index.html
7 | author: Microsoft Learning
8 | twitter_username: mslearning
9 | github_username: MicrosoftLearning
10 | plugins:
11 | - jekyll-sitemap
12 | - jekyll-mentions
13 | - jemoji
14 | markdown: kramdown
15 | kramdown:
16 | syntax_highlighter_opts:
17 | disable : true
18 |
--------------------------------------------------------------------------------
/index.md:
--------------------------------------------------------------------------------
1 | ---
2 | title: Online Hosted Instructions
3 | permalink: index.html
4 | layout: home
5 | ---
6 |
7 | # Transact-SQL Exercises and Demonstrations
8 |
9 | These exercises and demos support Microsoft course [DP-080: Querying with Transact-SQL](https://docs.microsoft.com/training/courses/dp-080t00) and the associated Microsoft Learn training content in the following learning paths:
10 |
11 | - [Get started querying with Transact-SQL](https://docs.microsoft.com/training/paths/get-started-querying-with-transact-sql/)
12 | - [Write advanced Transact-SQl queries](https://docs.microsoft.com/training/paths/write-advanced-transact-sql-queries/)
13 | - [Program with Transact-SQL](https://docs.microsoft.com/training/paths/program-transact-sql/)
14 |
15 | You can complete the exercises using:
16 |
17 | - A local installation of SQL Server
18 | - Azure SQL Database
19 |
20 | Setup instructions are provided for both of these options.
21 |
22 | {% assign labs = site.pages | where_exp:"page", "page.url contains '/Instructions/Labs'" %}
23 | | Module | Lab |
24 | | --- | --- |
25 | {% for activity in labs %}| {{ activity.lab.module }} | [{{ activity.lab.title }}{% if activity.lab.type %} - {{ activity.lab.type }}{% endif %}]({{ site.github.url }}{{ activity.url }}) |
26 | {% endfor %}
27 |
28 | ### Instructor demo's
29 |
30 | {% assign demos = site.pages | where_exp:"page", "page.url contains '/Instructions/Demos'" %}
31 | | Module | Demo |
32 | | --- | --- |
33 | {% for activity in demos %}| {{ activity.demo.module }} | [{{ activity.demo.title }}]({{ site.github.url }}{{ activity.url }}) |
34 | {% endfor %}
35 |
--------------------------------------------------------------------------------
/readme.md:
--------------------------------------------------------------------------------
1 | # DP-080: Querying Data with Microsoft Transact-SQL
2 |
3 | - **Are you a MCT?** - Have a look at our [GitHub User Guide for MCTs](https://microsoftlearning.github.io/MCT-User-Guide/)
4 | - **Need to manually build the lab instructions?** - Instructions are available in the [MicrosoftLearning/Docker-Build](https://github.com/MicrosoftLearning/Docker-Build) repository
5 |
6 | ## What are we doing?
7 |
8 | - To support this course, we will need to make frequent updates to the course content to keep it current with the Azure services used in the course. We are publishing the lab instructions and lab files on GitHub to allow for open contributions between the course authors and MCTs to keep the content current with changes in the Azure platform.
9 |
10 | - We hope that this brings a sense of collaboration to the labs like we've never had before - when Azure changes and you find it first during a live delivery, go ahead and make an enhancement right in the lab source. Help your fellow MCTs.
11 |
12 | ## How should I use these files relative to the released MOC files?
13 |
14 | - The instructor handbook and PowerPoints are still going to be your primary source for teaching the course content.
15 |
16 | - These files on GitHub are designed to be used in the course labs.
17 |
18 | - It will be recommended that for every delivery, trainers check GitHub for any changes that may have been made to support the latest Azure services.
19 |
20 | ## What about changes to the student handbook?
21 |
22 | - We will review the student handbook on a quarterly basis and update through the normal MOC release channels as needed.
23 |
24 | ## How do I contribute?
25 |
26 | - Any MCT can submit a pull request to the code or content in the GitHub repo, Microsoft and the course author will triage and include content and lab code changes as needed.
27 |
28 | - You can submit bugs, changes, improvement and ideas. Find a new Azure feature before we have? Submit a new demo!
29 |
30 |
--------------------------------------------------------------------------------