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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
Zyg_D
Continued Contributor
Continued Contributor

Getting blank values instead of actual MIN or MAX in a category

This is the data: 

data.JPG

I want to create a table based on Table1 which would contain every category just once and MIN of the category from one column and MAX of the category from another column. The tricky thing is that if a blank value exists in the category, I want to return the blank value. This is the desired result: 

result.JPG

How to achieve it?

 

1 ACCEPTED SOLUTION
Zyg_D
Continued Contributor
Continued Contributor

Based on the answer from @Anonymous  I was able to create what I needed. 

In the Table1 I added 2 columns:

minValue = 
IF (
    CALCULATE (
        COUNTBLANK(Table1[Value]),
        ALLEXCEPT ( Table1, Table1[Category] )
    ),
    BLANK(),
    CALCULATE ( 
        MIN ( Table1[Value] ), 
        ALLEXCEPT ( Table1, Table1[Category] ) 
    )
)
maxValue2 = 
IF (
    CALCULATE (
        COUNTBLANK(Table1[Value2]),
        ALLEXCEPT ( Table1, Table1[Category] )
    ),
    BLANK(),
    CALCULATE ( 
        MAX ( Table1[Value2] ), 
        ALLEXCEPT ( Table1, Table1[Category] ) 
    )
)

And then created a new table:

ResultTable = 
DISTINCT (
    SELECTCOLUMNS (
        'Table1',
        "Cat", [Category],
        "Val", [minValue],
        "Val2", [maxValue2]
    )
)

View solution in original post

9 REPLIES 9
Zyg_D
Continued Contributor
Continued Contributor

Sorry @Anonymous  I had to write another answer, because I found an error in yours. 

The following line in your code does not effectively check if there are blank values in the filtered column (if in the filtered column there are no blank values, but several different numbers, the SELECTEDVALUE returns blank too, which is why in my case it is not a good choice):

ISBLANK ( SELECTEDVALUE ( 'Table1'[Value] ) )

 I have changed the line with this:

COUNTBLANK(Table1[Value])

 

Zyg_D
Continued Contributor
Continued Contributor

Based on the answer from @Anonymous  I was able to create what I needed. 

In the Table1 I added 2 columns:

minValue = 
IF (
    CALCULATE (
        COUNTBLANK(Table1[Value]),
        ALLEXCEPT ( Table1, Table1[Category] )
    ),
    BLANK(),
    CALCULATE ( 
        MIN ( Table1[Value] ), 
        ALLEXCEPT ( Table1, Table1[Category] ) 
    )
)
maxValue2 = 
IF (
    CALCULATE (
        COUNTBLANK(Table1[Value2]),
        ALLEXCEPT ( Table1, Table1[Category] )
    ),
    BLANK(),
    CALCULATE ( 
        MAX ( Table1[Value2] ), 
        ALLEXCEPT ( Table1, Table1[Category] ) 
    )
)

And then created a new table:

ResultTable = 
DISTINCT (
    SELECTCOLUMNS (
        'Table1',
        "Cat", [Category],
        "Val", [minValue],
        "Val2", [maxValue2]
    )
)
Anonymous
Not applicable

Hi @Zyg_D ,

According to my understanding, you want to create a table with three columns: distinct Category, Min Value and Max Value2 , right?

 

You could use the following formula:

 

//Create columns

minValue =
IF (
    CALCULATE (
        ISBLANK ( SELECTEDVALUE ( 'Table1'[Value] ) ),
        ALLEXCEPT ( Table1, Table1[Category] )
    ),
    BLANK (),
    CALCULATE ( MIN ( 'Table1'[Value] ), ALLEXCEPT ( 'Table1', Table1[Category] ) )
)

 

maxValue2 =
IF (
    CALCULATE (
        ISBLANK ( SELECTEDVALUE ( 'Table1'[Value2] ) ),
        ALLEXCEPT ( Table1, Table1[Category] )
    ),
    BLANK (),
    CALCULATE ( MAX ( 'Table1'[Value2] ), ALLEXCEPT ( 'Table1', Table1[Category] ) )
)

//Create table

Table 2 =
DISTINCT (
    SELECTCOLUMNS (
        'Table1',
        "Cat", [Category],
        "Val", [minValue],
        "Val2", [maxValue2]
    )
)

My visualization looks like this:

8.28.3.1.png

Is the result what you want? If you have any questions, please upload some data samples and expected output.

Please do mask sensitive data before uploading.

 

Best Regards,

Eyelyn Qin

Zyg_D
Continued Contributor
Continued Contributor

Thank you, @Anonymous  . I was hoping a shorter solution exists, but your answer does exactly what I described, so thanks! 

Zyg_D
Continued Contributor
Continued Contributor

Any more ideas?

Sujit_Thakur
Solution Sage
Solution Sage

Do you want to ignore blank or count it as minimun of all??

Zyg_D
Continued Contributor
Continued Contributor


@Sujit_Thakur wrote:

Do you want to ignore blank or count it as minimun of all??


I don't want to ignore blank values. if they are there, they must appear both, as minimum and as maximum. 

amitchandak
Super User
Super User

@Zyg_D , try

maxx(filter(table,not(isblank(table[value]))),table[Value])
minx(filter(table,not(isblank(table[value]))),table[Value])

 

maxx(filter(table,not(isblank(table[value2]))),table[Value2])
minx(filter(table,not(isblank(table[value2]))),table[Value2])

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube
Zyg_D
Continued Contributor
Continued Contributor


@amitchandak wrote:

@Zyg_D, try

maxx(filter(table,not(isblank(table[value]))),table[Value])
minx(filter(table,not(isblank(table[value]))),table[Value])

 

maxx(filter(table,not(isblank(table[value2]))),table[Value2])
minx(filter(table,not(isblank(table[value2]))),table[Value2])


Please elaborate more on your answer. As it is, it is impossible to tell how I should get my desired table. 

Error: "The expression specified in the query is not a valid table expression."

Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors