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

Trouble with Nested "If" Statements

I'm trying to calculate an Average Headcount by department.  This is done by summing the starting and ending headcounts and dividing by 2.  However, if either the starting or ending headcount are 0 (blank), then I want the average to use the other number.  

 

It is working correctly 1-way, but not the other way.  See the table below for the results I'm getting.  If STARTING HEADCOUNT is blank, then it's calculating correctly and using the ENDING HEADCOUNT for the average.  But if ENDING HEADCOUNT is blank, it's still trying to calculate (STARTING + ENDING)/2 which is resulting in the wrong number given the blank.  

 

I'm using nested IF statement in DAX like this:

IF([Starting Headcount]=blank (), [Ending Headcount], IF([Ending Headcount]=blank(), [Starting Headcount], ([Starting Headcount] + [Ending Headcount]/2)

 

Any help is much appreciated

 

 

DepartmentStarting HeadcountEnding HeadcountAverage Headcount (Dynamic)
Sales 1212
Manufacturing111513
Marketing21 10.5

 

1 ACCEPTED SOLUTION
v-yuta-msft
Community Support
Community Support

@Anonymous ,

 

Modify the calculate column like below:

Average Headcount (Dynamic) = 
IF (
    [Starting Headcount] = BLANK ()
        && [Ending Headcount] = BLANK (),
    BLANK (),
    IF (
        [Starting Headcount] = BLANK ()
            && [Ending Headcount] <> BLANK (),
        [Ending Headcount],
        IF (
            [Ending Headcount] = BLANK ()
                && [Starting Headcount] <> BLANK (),
            [Starting Headcount],
            ( [Starting Headcount] + [Ending Headcount] ) / 2
        )
    )
)

Capture.PNG 

 

Community Support Team _ Jimmy Tao

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
v-yuta-msft
Community Support
Community Support

@Anonymous ,

 

Modify the calculate column like below:

Average Headcount (Dynamic) = 
IF (
    [Starting Headcount] = BLANK ()
        && [Ending Headcount] = BLANK (),
    BLANK (),
    IF (
        [Starting Headcount] = BLANK ()
            && [Ending Headcount] <> BLANK (),
        [Ending Headcount],
        IF (
            [Ending Headcount] = BLANK ()
                && [Starting Headcount] <> BLANK (),
            [Starting Headcount],
            ( [Starting Headcount] + [Ending Headcount] ) / 2
        )
    )
)

Capture.PNG 

 

Community Support Team _ Jimmy Tao

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

Thank you!  This worked well.

nsadams87xx
Helper III
Helper III

I would try pivoting your data so your actual data is describing the departments (your departments become your columns).  That way you can use the AVERAGE function or at least be able to use your data in a column structure rather than crossing rows.

The idea with pivoting is very elegant Smiley Happy

 

But if you couldn't use it, try following:

 

AVG =
VAR SUM_OF = TestTable[Column2] + TestTable[Column3]
VAR CNT_OF =
    ( NOT ISBLANK ( TestTable[Column2] ) ) + ( NOT ISBLANK ( TestTable[Column3] ) )
RETURN
    DIVIDE ( SUM_OF; CNT_OF; 0 )

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.