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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

How to combine SUMMARIZE table with the Original Table?

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!

 

PowerBI.png

 

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

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.


Go to My LinkedIn Page


View solution in original post

5 REPLIES 5
SpartaBI
Community Champion
Community Champion

@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)

 

Jihwan_Kim
Super User
Super User

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.


Go to My LinkedIn Page


Anonymous
Not applicable

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.

Anonymous
Not applicable

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.

amitchandak
Super User
Super User

@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())

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors