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 guys,
is there a way to store/change a variable in a loop?
I want to calculate the total amount of days products were available and only take the longst timeframe.
(All those products are the same, like they have the ID 1)
I.e
15.10.21 - 30.11.21
07.12.21 - 28.02.22
21.07.22 - 20.08.22
totaldiff = 162 days
Is this possible in PowerQuery or Dax? I would like to avoid other softwaresolutions and try to get this working in PQ or Dax. Functions seem to be a way but will take a lot of performance by doing the loop n^n times.
In Pseudocode my solution would look like this:
[measure/pq]=
var post = [Posting Date]
var unPost = [Unposting Date]
var totalDatesDifference = Date.diff(post , unPost)
loop this:
if(unPost > minPost)
break
else
post = [Posting Date]
unPost = [Unposting Date]
total = total + Date.diff( unPost , post )
Thanks for your help
Solved! Go to Solution.
Hello @Anonymous , here is an example of what you could do with PQ:
let
Source = Excel.CurrentWorkbook(){[Name="DatesDiff"]}[Content],
typed = Table.TransformColumnTypes(Source,{{"Post date", type date}, {"Unpost date", type date}}),
datesListsAdded = Table.AddColumn(typed, "Dates list", each List.Dates([Post date], Duration.Days([Unpost date] - [Post date]) + 1, #duration(1, 0, 0, 0))),
datesListsExpanded = Table.ExpandListColumn(datesListsAdded, "Dates list"),
count = List.Count(List.Distinct(datesListsExpanded[Dates list]))
in
count
The global behavior is to generate a list of all dates between each post and unpost date, expand these lists, and count the number of distinct dates.
With your sample data, I get 162 days, which is what I also find with manual calculation (you are missing some days in your own calculation, you should recheck it).
Hope this helps.
Don't forget to accept my post as solution to help people to find it 🙂
Hello @Anonymous , here is an example of what you could do with PQ:
let
Source = Excel.CurrentWorkbook(){[Name="DatesDiff"]}[Content],
typed = Table.TransformColumnTypes(Source,{{"Post date", type date}, {"Unpost date", type date}}),
datesListsAdded = Table.AddColumn(typed, "Dates list", each List.Dates([Post date], Duration.Days([Unpost date] - [Post date]) + 1, #duration(1, 0, 0, 0))),
datesListsExpanded = Table.ExpandListColumn(datesListsAdded, "Dates list"),
count = List.Count(List.Distinct(datesListsExpanded[Dates list]))
in
count
The global behavior is to generate a list of all dates between each post and unpost date, expand these lists, and count the number of distinct dates.
With your sample data, I get 162 days, which is what I also find with manual calculation (you are missing some days in your own calculation, you should recheck it).
Hope this helps.
Thank you very much, it works like a charm!
And yes I calculated my own sample data wrong... 😣