Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
Flixy04
Regular Visitor

SQL query to display year values which lie between two date values

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:

 
SELECT
ID,
StartDate,
DueDate
FROM dbo.Test

Flixy04_0-1691584788787.png

 

Kind regards
Flixy04

2 ACCEPTED SOLUTIONS
ToddChitt
Super User
Super User

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.




Did I answer your question? If so, mark my post as a solution. Also consider helping someone else in the forums!

Proud to be a Super User!





View solution in original post

Anonymous
Not applicable

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:

vcgaomsft_0-1691721423480.png

 

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;

vcgaomsft_1-1691724259008.png

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

View solution in original post

4 REPLIES 4
Flixy04
Regular Visitor

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:

 
SELECT
ID,
StartDate,
DueDate
FROM dbo.Test

Flixy04_0-1691584788787.png

 

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"
Anonymous
Not applicable

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:

vcgaomsft_0-1691721423480.png

 

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;

vcgaomsft_1-1691724259008.png

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

ToddChitt
Super User
Super User

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.




Did I answer your question? If so, mark my post as a solution. Also consider helping someone else in the forums!

Proud to be a Super User!





Helpful resources

Announcements
June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.

Top Solution Authors