-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
1 parent
854d506
commit ed167cb
Showing
2 changed files
with
74 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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; |
31 changes: 31 additions & 0 deletions
31
WideWorldImporters/Challenges/Functions/ufn_DaysSinceLastInvoice.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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 | ||
) | ||
) | ||
); |