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.
Hi,
I have a data set with "Valid From" and "Valid To" dates which shows the price of a material. The date range is from 7/1/2016 to 10/31/2016. Is there any way to split the date range into 3 separate months?
Solved! Go to Solution.
Hi, @kraghavcd
Based on your description, I created data to reproduce your scenario.
You may click ‘Edit Query’, go to Query Editor, choose ‘Add Column’.
New Valid From = let
IsCrossMonth = Date.Month([Valid to])<>Date.Month([Valid From]) or Date.Year([Valid to])<>Date.Year([Valid From]),
MonthDu = (Date.Year([Valid to])-Date.Year([Valid From]))*12 +Date.Month([Valid to]) -Date.Month([Valid From])
in
List.Generate(()=> [ x = 0 , y = [Valid From]],each [x] <= MonthDu, each [y = [y],x =[x]+ 1],each if[x]=0 then [y] else Date.AddDays(Date.AddMonths([y],[x]),1-Date.Day([y])))
Secondly, you can click the ‘New Valid From’ column and choose ‘Expand to new rows’.
Thirdly, you can add a custom column as follows.
New Valid To = if[Valid From] = [New Valid From]
then if (Date.Year([Valid to])-Date.Year([Valid From]))*12 +Date.Month([Valid to]) -Date.Month([Valid From])<1
then [Valid to]
else Date.AddDays(Date.AddMonths([New Valid From],1),-1)
else if (Date.Year([Valid to])-Date.Year([New Valid From]))*12 +Date.Month([Valid to]) -Date.Month([New Valid From])<1
then [Valid to]
else
Date.AddDays(Date.AddMonths([New Valid From],1),-1)
Finally, you can remove ‘Valid From’ and ‘Valid To’ columns.
Result:
If I misunderstand your thought, please show me your sample data and expected output. I am glad to solve the problem for you. Here is my pbix .
Best Regards,
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @kraghavcd
Based on your description, I created data to reproduce your scenario.
You may click ‘Edit Query’, go to Query Editor, choose ‘Add Column’.
New Valid From = let
IsCrossMonth = Date.Month([Valid to])<>Date.Month([Valid From]) or Date.Year([Valid to])<>Date.Year([Valid From]),
MonthDu = (Date.Year([Valid to])-Date.Year([Valid From]))*12 +Date.Month([Valid to]) -Date.Month([Valid From])
in
List.Generate(()=> [ x = 0 , y = [Valid From]],each [x] <= MonthDu, each [y = [y],x =[x]+ 1],each if[x]=0 then [y] else Date.AddDays(Date.AddMonths([y],[x]),1-Date.Day([y])))
Secondly, you can click the ‘New Valid From’ column and choose ‘Expand to new rows’.
Thirdly, you can add a custom column as follows.
New Valid To = if[Valid From] = [New Valid From]
then if (Date.Year([Valid to])-Date.Year([Valid From]))*12 +Date.Month([Valid to]) -Date.Month([Valid From])<1
then [Valid to]
else Date.AddDays(Date.AddMonths([New Valid From],1),-1)
else if (Date.Year([Valid to])-Date.Year([New Valid From]))*12 +Date.Month([Valid to]) -Date.Month([New Valid From])<1
then [Valid to]
else
Date.AddDays(Date.AddMonths([New Valid From],1),-1)
Finally, you can remove ‘Valid From’ and ‘Valid To’ columns.
Result:
If I misunderstand your thought, please show me your sample data and expected output. I am glad to solve the problem for you. Here is my pbix .
Best Regards,
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Great solution @v-alq-msft .
But the only problem is whenever we give a start date other than the first day of month ,
the first row will have an end date in the next month
Is there a way we can correct it, so that even the first row is up to the end of first month?
I need this too.
Please help us!
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
81 | |
76 | |
61 | |
37 | |
33 |
User | Count |
---|---|
101 | |
56 | |
51 | |
45 | |
40 |