From ed167cb1f0d23946fc73ec1c198881f2daffcc9e Mon Sep 17 00:00:00 2001 From: Justin Frizzell <143661894+JustinFrizzell@users.noreply.github.com> Date: Thu, 12 Oct 2023 18:30:48 +0100 Subject: [PATCH] Added challenge #5 --- Challenges/#5 - ufn_DaysSinceLastInvoice.sql | 43 +++++++++++++++++++ .../Functions/ufn_DaysSinceLastInvoice.sql | 31 +++++++++++++ 2 files changed, 74 insertions(+) create mode 100644 Challenges/#5 - ufn_DaysSinceLastInvoice.sql create mode 100644 WideWorldImporters/Challenges/Functions/ufn_DaysSinceLastInvoice.sql diff --git a/Challenges/#5 - ufn_DaysSinceLastInvoice.sql b/Challenges/#5 - ufn_DaysSinceLastInvoice.sql new file mode 100644 index 0000000..7dfb7f3 --- /dev/null +++ b/Challenges/#5 - ufn_DaysSinceLastInvoice.sql @@ -0,0 +1,43 @@ +-- Requirement: ufn_DaysSinceLastInvoice + +-- Our sales team often wants to understand the purchasing patterns of our customers. Specifically, they're interested in knowing, for a given invoice, +-- how many days had passed since the last invoice for that same customer. This would help us identify customers with consistent purchasing frequencies +-- as well as those whose purchasing has deviated from their usual patterns. + +-- Function Objective: +-- Create a tabular function that, when provided an invoice ID, returns the number of days since the last invoice for that same customer. + +-- Function Specifications: + +-- Function Name: ufn_DaysSinceLastInvoice + +-- Input Parameter: InvoiceID (integer) + +-- Output Columns: +-- CurrentInvoiceID: The provided InvoiceID. +-- CustomerID: The ID of the customer associated with the provided InvoiceID. +-- PreviousInvoiceDate: The date of the last invoice for that customer before the provided InvoiceID. +-- CurrentInvoiceDate: The date of the provided InvoiceID. +-- DaysSinceLastInvoice: The difference in days between CurrentInvoiceDate and PreviousInvoiceDate. +-- Logic: + +-- For a given InvoiceID, retrieve the customer associated with it. +-- Find the date of the last invoice for that customer that occurred before the provided InvoiceID. +-- Calculate the difference in days between the provided InvoiceID's date and the last invoice's date. +-- The function should handle scenarios where there is no previous invoice for the customer (i.e., it's their first purchase). In such cases, the PreviousInvoiceDate +-- should be NULL, and DaysSinceLastInvoice should also be NULL. + +-- Solution: WideWorldImporters\Challenges\Functions\ufn_DaysSinceLastInvoice.sql + +SELECT + i.InvoiceID + , i.CustomerID + , l.PreviousInvoiceDate + , l.CurrentInvoiceDate + , l.DaysSinceLastInvoice +FROM + Sales.Invoices AS i +CROSS APPLY + dbo.ufn_DaysSinceLastInvoice(i.InvoiceID) AS l +WHERE + i.CustomerID = 847; diff --git a/WideWorldImporters/Challenges/Functions/ufn_DaysSinceLastInvoice.sql b/WideWorldImporters/Challenges/Functions/ufn_DaysSinceLastInvoice.sql new file mode 100644 index 0000000..8328abb --- /dev/null +++ b/WideWorldImporters/Challenges/Functions/ufn_DaysSinceLastInvoice.sql @@ -0,0 +1,31 @@ +CREATE FUNCTION dbo.ufn_DaysSinceLastInvoice (@InvoiceID INT) +RETURNS TABLE +AS +RETURN +( + SELECT + CurrentInvoice.InvoiceID AS CurrentInvoiceID + , CurrentInvoice.CustomerID + , PreviousInvoice.InvoiceDate AS PreviousInvoiceDate + , CurrentInvoice.InvoiceDate AS CurrentInvoiceDate + , DATEDIFF(DAY, PreviousInvoice.InvoiceDate, CurrentInvoice.InvoiceDate) AS DaysSinceLastInvoice + FROM + Sales.Invoices AS CurrentInvoice + LEFT JOIN + Sales.Invoices + AS PreviousInvoice + ON CurrentInvoice.CustomerID = PreviousInvoice.CustomerID + AND CurrentInvoice.InvoiceDate > PreviousInvoice.InvoiceDate + WHERE + CurrentInvoice.InvoiceID = @InvoiceID + AND ( + PreviousInvoice.InvoiceDate IS NULL + OR PreviousInvoice.InvoiceDate + = ( + SELECT MAX(InvoiceDate) + FROM Sales.Invoices + WHERE CustomerID = CurrentInvoice.CustomerID + AND InvoiceDate < CurrentInvoice.InvoiceDate + ) + ) +);