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

Switch and calculate

Hi everyone,

 

I am trying to calculate percentage total no of transactions occured across filters.

 

My data is as follows,

HourWeeknameCount_loading_colTotal_loadingTotal teusLocation_nameColumn
4120WK240090 0
420WK24  80 ND
 20WK24   aND
820WK240090 0
7120WK240080b0
320WK2422190 1
2120WK250090 0
1320WK250088 0
 20WK25    ND
420WK25   cND
4120WK2500 d0
720WK2500  0
 20WK25    ND
4720WK250080b0
1120WK250080 0
2320WK2500 e0
920WK2500 b0
1520WK2500 a0
820WK2500 a0
220WK25221  1
520WK2500  0
 20WK25    ND
5020WK250090 0
1620WK2500 a0
620WK2500 c0
620WK2500 a0

 

I want to calculate as follows,

For a week across different locations what is percentage.

1. First need to filter across location and weekname.

2. Check for overall count for that week and location. (Ex. b location has 10 counts in week 20WK25).

3. Have a condition with Hour <4, check for that particular condition in that week. (Ex. b location has passed 4 counts in week 20WK25).

4. Calculate percentage which step 3/step2.

 

How can I go about this?

 

Switch and calculate in measure is not working, if I do in calculated columns how can I go about it?

 

Thanks

 

 

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

Hi, @Anonymous 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

 

Table:

c1.png

 

You may create a measure as below.

Percenatage = 
var _table = ALLSELECTED('Table')
var tab = 
SUMMARIZE(
    'Table',
    'Table'[Weekname],
    "Result",
    var _weekname = [Weekname]
    var newtab = 
    SUMMARIZE(
        _table,
        'Table'[Hour],
        'Table'[Weekname],
        'Table'[Location_name],
        "flag",
        IF(
            'Table'[Hour]>4&&[Location_name]<>"",
            1,0
        )
    )
    return
    DIVIDE(
        CALCULATE(
            DISTINCTCOUNT('Table'[Location_name]),
            FILTER(
                  newtab,
                  'Table'[Weekname]=_weekname&&
                  [flag]=1
            )
        ),
        COUNTROWS(
            FILTER(
                newtab,
                [Weekname]=_weekname&&
                [Location_name]<>""
            )
        )
    )
)
return
SUMX(
    tab,
    [Result]
)

 

The overall count for '20WK25' with a location is 10. The distinct count location name with criteria of hour>4 for '20WK25' is 5. Here is the result.

c2.png

 

If I misunderstand your thoughts, please show us your expected result. 

 

Best Regards

Allan

 

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-alq-msft
Community Support
Community Support

Hi, @Anonymous 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

 

Table:

c1.png

 

You may create a measure as below.

Percenatage = 
var _table = ALLSELECTED('Table')
var tab = 
SUMMARIZE(
    'Table',
    'Table'[Weekname],
    "Result",
    var _weekname = [Weekname]
    var newtab = 
    SUMMARIZE(
        _table,
        'Table'[Hour],
        'Table'[Weekname],
        'Table'[Location_name],
        "flag",
        IF(
            'Table'[Hour]>4&&[Location_name]<>"",
            1,0
        )
    )
    return
    DIVIDE(
        CALCULATE(
            DISTINCTCOUNT('Table'[Location_name]),
            FILTER(
                  newtab,
                  'Table'[Weekname]=_weekname&&
                  [flag]=1
            )
        ),
        COUNTROWS(
            FILTER(
                newtab,
                [Weekname]=_weekname&&
                [Location_name]<>""
            )
        )
    )
)
return
SUMX(
    tab,
    [Result]
)

 

The overall count for '20WK25' with a location is 10. The distinct count location name with criteria of hour>4 for '20WK25' is 5. Here is the result.

c2.png

 

If I misunderstand your thoughts, please show us your expected result. 

 

Best Regards

Allan

 

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

 

 

Anonymous
Not applicable

Thanks @v-alq-msft . It was very helpful.

 

Done following calculations,

Step 1:  created calculated column for hour.

Hour flag = SWITCH(TRUE(),
                'TATLOADING'[Hour]= BLANK(),0,
                'TATLOADING'[Hour]<4,1,
                'TATLOADING'[Hour]>=4,0)
 
Step 2: created calculated column for location and hour.
Location and Hour flag = SWITCH(TRUE(),
                        'TATLOADING'[Hour flag]=0 && TATLOADING[Location_name]="",0,
                        'TATLOADING'[Hour flag]=1 && TATLOADING[Location_name]="",0,
'TATLOADING'[Hour flag]=0 && TATLOADING[Location_name]<>"",0,
                        'TATLOADING'[Hour flag]=1 && TATLOADING[Location_name]<>"",1)
 
Step 3:Calculated percentage by using step 1 and step 2.
percentage = DIVIDE(SUM(TATLOADING[Location and Hour flag]),COUNTROWS(FILTER(TATLOADING,TATLOADING[Location_name]<>"")))
 
Thanks.
amitchandak
Super User
Super User
Anonymous
Not applicable

@amitchandak, Thanks for your reply, I am not looking for that comparison, I am looking for calculation.

 

I want to calculate percentage across location and across weeks. Ex. 20Wk25 location a achieved 30% like that by using DAX.

My steps are

1. Calculate Overall count across week and location(Ex. location b has 10 counts in week 25)

2. Calculate count with criteria of hour>4. (Ex. location b has passed 5 transactions(counts) in week 25)

3. calculate percentage(Step2/Step1) for each location and week. My DAX should be dynamic so that I dont need to check for weeks everytime.

 

So I tried for started doing step 3,

count = SWITCH(TRUE(),
'TATLOADING'[Hour]<4 ||'TATLOADING'[Hour]=0,1,
'TATLOADING'[Hour]>=4,0)
 
This condition says if Hour>4, put it as 0 else if hour<4 and =0 put as 1.
 
Hereafter how can go about and calculate overall count and percentage Step1 and Step3?
 
Thanks.
 

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.