Join us for an expert-led overview of the tools and concepts you'll need to pass exam PL-300. The first session starts on June 11th. See you there!
Get registeredPower BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.
Hello
I am looking for a SQL query to display year values which are between two date values.
This is what my database looks like and this is what I need:
Kind regards
Flixy04
Solved! Go to Solution.
This is not a Power Query question. It is not even a Power BI question. This is a T-SQL question and involves a CROSS JOIN (Cartesean Product). But here you go:
Create Table #MyTemp ( BudgetYear INT)
INSERT INTO #MyTemp (BudgetYear) VALUES (2021), (2022), ...<end of your range)
SELECT Id, StartDate, DueDate, BudgetYear
FROM dbo.Test
CROSS JOIN #MyTemp
WHERE BudgetYear >= MIN(YEAR(StartDate))
AND BudgetYear <= MAX(YEAR(DueDate))
DROP TABLE #MyTemp
Note: The CROSS JOIN will return one row for every combination of both tables. If you have 50 rows in one table and 10 rows in the second, your result set will be 500 rows.
Hope that helps. If not, please explain the 'rules' for any one Test row to be matched to a Budget Year.
Proud to be a Super User! | |
Hi @Flixy04 ,
Since this is a posting in the powerquery forum, I'm assuming it's a related thread.
Please refer to the following steps:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTIyMDLUNQAhCMdU19BI19hQKVYnWskIImSELG8Mk48FAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, StartDate = _t, DueDate = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"StartDate", type date}, {"DueDate", type date}}),
AddYearsList = Table.AddColumn(#"Changed Type", "BudgetYearList", each List.Transform({Number.From([StartDate])..Number.From([DueDate])}, each Date.From(_))),
ExpandYearsList = Table.ExpandListColumn(AddYearsList, "BudgetYearList"),
AddBudgetYear = Table.AddColumn(ExpandYearsList, "BudgetYear", each Date.Year([BudgetYearList])),
RemoveBudgetYearList = Table.RemoveColumns(AddBudgetYear,{"BudgetYearList"}),
#"Removed Duplicates" = Table.Distinct(RemoveBudgetYearList)
in
#"Removed Duplicates"
Output:
SQL:
WITH YearsCTE (ID, StartDate, DueDate, BudgetYear) AS (
SELECT ID, StartDate, DueDate, YEAR(StartDate) AS BudgetYear
FROM your_table
UNION ALL
SELECT ID, StartDate, DueDate, BudgetYear + 1
FROM YearsCTE
WHERE BudgetYear < YEAR(DueDate)
)
SELECT * FROM YearsCTE
ORDER BY ID, BudgetYear;
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
Hello
I am looking for a SQL query to display year values which are between two date values.
This is what my database looks like and this is what I need:
Kind regards
Flixy04
I presume you want Power Query code. If yes, use this
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTIyMDLUNQAhCMdU19BI19hQKVYnWskIImSELG8Mk48FAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, StartDate = _t, DueDate = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"StartDate", type date}, {"DueDate", type date}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "BudgetYear", each {Date.Year([StartDate])..Date.Year([DueDate])}),
#"Expanded BudgetYear" = Table.ExpandListColumn(#"Added Custom", "BudgetYear")
in
#"Expanded BudgetYear"
Hi @Flixy04 ,
Since this is a posting in the powerquery forum, I'm assuming it's a related thread.
Please refer to the following steps:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTIyMDLUNQAhCMdU19BI19hQKVYnWskIImSELG8Mk48FAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, StartDate = _t, DueDate = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"StartDate", type date}, {"DueDate", type date}}),
AddYearsList = Table.AddColumn(#"Changed Type", "BudgetYearList", each List.Transform({Number.From([StartDate])..Number.From([DueDate])}, each Date.From(_))),
ExpandYearsList = Table.ExpandListColumn(AddYearsList, "BudgetYearList"),
AddBudgetYear = Table.AddColumn(ExpandYearsList, "BudgetYear", each Date.Year([BudgetYearList])),
RemoveBudgetYearList = Table.RemoveColumns(AddBudgetYear,{"BudgetYearList"}),
#"Removed Duplicates" = Table.Distinct(RemoveBudgetYearList)
in
#"Removed Duplicates"
Output:
SQL:
WITH YearsCTE (ID, StartDate, DueDate, BudgetYear) AS (
SELECT ID, StartDate, DueDate, YEAR(StartDate) AS BudgetYear
FROM your_table
UNION ALL
SELECT ID, StartDate, DueDate, BudgetYear + 1
FROM YearsCTE
WHERE BudgetYear < YEAR(DueDate)
)
SELECT * FROM YearsCTE
ORDER BY ID, BudgetYear;
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
This is not a Power Query question. It is not even a Power BI question. This is a T-SQL question and involves a CROSS JOIN (Cartesean Product). But here you go:
Create Table #MyTemp ( BudgetYear INT)
INSERT INTO #MyTemp (BudgetYear) VALUES (2021), (2022), ...<end of your range)
SELECT Id, StartDate, DueDate, BudgetYear
FROM dbo.Test
CROSS JOIN #MyTemp
WHERE BudgetYear >= MIN(YEAR(StartDate))
AND BudgetYear <= MAX(YEAR(DueDate))
DROP TABLE #MyTemp
Note: The CROSS JOIN will return one row for every combination of both tables. If you have 50 rows in one table and 10 rows in the second, your result set will be 500 rows.
Hope that helps. If not, please explain the 'rules' for any one Test row to be matched to a Budget Year.
Proud to be a Super User! | |