Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
Please see attached screenshot. I have an OG table (left). I then can use a SUMMARIZE function to create the middle table, which shows the AvgNumHours. I would like to combine the results to my OG table. My goal is to get to the table on the right exactly as shown with the blank spaces too. Is there a function or expression I can use to get to that table? Thanks!
Solved! Go to Solution.
Hi,
Please check the below DAX formula and the attached pbix file to create a new column.
AvgNumHours CC =
VAR currentstartdate = Data[StartDate]
VAR currentsource = Data[Source]
VAR currentactivityname = Data[ActivityName]
VAR startingrow =
FILTER (
GROUPBY (
Data,
Data[StartDate],
Data[Source],
Data[ActivityName],
"@startingrowNumHours", MINX ( CURRENTGROUP (), Data[NumHours] )
),
Data[StartDate] = currentstartdate
&& Data[Source] = currentsource
&& Data[ActivityName] = currentactivityname
)
RETURN
IF (
Data[NumHours] = MINX ( startingrow, [@startingrowNumHours] ),
AVERAGEX (
FILTER (
Data,
Data[StartDate] = currentstartdate
&& Data[Source] = currentsource
&& Data[ActivityName] = currentactivityname
),
Data[NumHours]
)
)
If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.
@Anonymous you can use this code for the calculated column:
tbl[AvgNumHours] =
VAR _startdate = tbl[StartDate]
VAR _source = tbl[Source]
VAR _activity_name = tbl[ActivityName]
VAR _min_value = CALCULATE(MIN (tbl[NumHours]), REMOVEFILTERS(tbl[NumHours]))
VAR _result =
CALCULATE(
AVERAGE(tbl[NumHours]),
REMOVEFILTERS(tbl[NumHours])
)
RETURN
IF( tbl[NumHours] = _min_value, _result)
Hi,
Please check the below DAX formula and the attached pbix file to create a new column.
AvgNumHours CC =
VAR currentstartdate = Data[StartDate]
VAR currentsource = Data[Source]
VAR currentactivityname = Data[ActivityName]
VAR startingrow =
FILTER (
GROUPBY (
Data,
Data[StartDate],
Data[Source],
Data[ActivityName],
"@startingrowNumHours", MINX ( CURRENTGROUP (), Data[NumHours] )
),
Data[StartDate] = currentstartdate
&& Data[Source] = currentsource
&& Data[ActivityName] = currentactivityname
)
RETURN
IF (
Data[NumHours] = MINX ( startingrow, [@startingrowNumHours] ),
AVERAGEX (
FILTER (
Data,
Data[StartDate] = currentstartdate
&& Data[Source] = currentsource
&& Data[ActivityName] = currentactivityname
),
Data[NumHours]
)
)
If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.
Thanks for your valuable input...This ALMOST works. The issue is in the RESULT section when you use the MINX function that grouping can have duplicate MINIMUM because the [NumHours] can have 2 same MINIMUM values.
Is there a way to use another function that only results in 1 assignment in the grouping? I believe MINX and MAXX will not work if the [NumHours] are not unique.
I think I can add an INDEX column to find the MINX and then apply to [NumHours]...but if you know of an alternate function please let me know...Thanks.
@Anonymous , Add an index column in Power Query first
Index Column: https://youtu.be/NS4esnCDqVw
Then you can create a new column like.I do not think you need even a second table
New column =
var _ind = minx(filter(Table, [Date] =earlier([Date]) && [Source] =earlier([Source]) && [ActivityName] =earlier([ActivityName]) ), [Index])
var _avg = AverageX(filter(Table, [Date] =earlier([Date]) && [Source] =earlier([Source]) && [ActivityName] =earlier([ActivityName]) ), [NumHours])
return
if([Index] =_ind, _avg , blank())
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
23 | |
21 | |
20 | |
13 | |
12 |
User | Count |
---|---|
41 | |
32 | |
23 | |
23 | |
22 |