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

Show visual total % for current and previous period

Dear community,

I have problems with calculating the visual total % of work effort for the previous period using DATEADD.

I have some data which shows how much time is spent for each work activity ('Workdetails') If the work activity has lasted several days, the hours are distributed evenly for the dates ('Work effort distributed (h)').

The requirement is to compare the work effort of the current period and the previous period. The data should be slicable and still show 100% in the visual for any selected time period / slicer selections.

I have the following type of data:

YearQuarterMonthDayWorkidCountryPLWorkdetailsStartDateEndDateDistributedDatesEffort_Hours+MinutesWork effort distributed (h)
2021Qtr 4October271United Arab EmiratesSAABTraining partners27.10.2021 0:0027.10.2021 0:0027.10.2021 0:0044
2021Qtr 4December122American SamoaTEAMPersonal development12.12.2021 0:0014.12.2021 0:0012.12.2021 0:00268.666666666666666
2021Qtr 4December132American SamoaTEAMPersonal development12.12.2021 0:0014.12.2021 0:0013.12.2021 0:00268.666666666666666
2021Qtr 4December142American SamoaTEAMPersonal development12.12.2021 0:0014.12.2021 0:0014.12.2021 0:00268.666666666666666
2021Qtr 4December203BelgiumSAABProject support20.12.2021 0:0020.12.2021 0:0020.12.2021 0:0011
2021Qtr 4December204LuxembourgMASITraining / office20.12.2021 0:0020.12.2021 0:0020.12.2021 0:0044
2021Qtr 4December205BelgiumSAABTraining / remote20.12.2021 0:0020.12.2021 0:0020.12.2021 0:0022
2021Qtr 4December206BelgiumSAABDemo / on-site20.12.2021 0:0020.12.2021 0:0020.12.2021 0:0011
2022Qtr 1January47LithuaniaMASIPartner support4.1.2022 0:004.1.2022 0:004.1.2022 0:0011


I also have a custom Calendar table ('Date') linked to my data table ('DistiributedDates').

I'm trying to show how the work effort (in %) differs between the current and previous periods (Year, Quarter, Month, Day).
This bar chart below is basically the visualization that I'm aiming for, but instead of showing the percentage of grand total work effort (of the whole data), the bars should show the visual total - i.e. reacting to slicers on the page, and still providing 100%:

Minna_0-1642525105401.png

 


The work effort amount I'm using as a basis  is in the column: 'Work effort distributed (h)'
The grand total of work effor is in the measure called 'EffortInHoursTotal':

 

 

EffortInHoursTotal = 
CALCULATE(
    SUM('demodata'[Work effort distributed (h)]),
     REMOVEFILTERS('demodata') 
    )

 

 


I have a measure which calculates the Work effort %

 

 

Effort (%) = 
DIVIDE(
     sum('demodata'[Work effort distributed (h)]),  
     [EffortInHoursTotal])

 

 


Then I have a measure which uses the above measure and calculates the Previous period work effort %.
It uses a dynamic time period selection solution that I found from some blog/video.

 

 

Previous Period Effort % = 
SWITCH(
    TRUE(),
    ISINSCOPE('Calendar'[Date].[Day]),
    CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, DAY)
    ), 
    ISINSCOPE('Calendar'[Date].[Month]),
    CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, MONTH)
    ), 
        ISINSCOPE('Calendar'[Date].[Quarter]),
    CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, QUARTER)
    ), 
        ISINSCOPE('Calendar'[Date].[Year]),
    CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, YEAR)
    )
)

 

 


As far as I understand, these basic % calculations seem to work OK (and are actually used in the above bar chart).
But as said, I should not visualize these but "visual total %'.

So, next I've created a measure to calculate the visual total %:

 

 

Effort % ALLSELECTED = 
DIVIDE(
[Effort (%)],
CALCULATE(
   [Effort (%)],
    ALLSELECTED( demodata )
))

 

 

Not sure if it's perfect but I'm able to show this in the visual and it reacts to the slicers, showing all the time total 100%.

 

The measure that I just cannot create is to show the visual total % for the previous period.
This attempt shows 100% bars for all periods:

 

 

Previous Period Effort % ALLSELECTED = 

SWITCH(
    TRUE(),
    ISINSCOPE('Calendar'[Date].[Day]),   
    CALCULATE(
      [Effort % ALLSELECTED],
       DATEADD('Calendar'[Date].[Date], -1, DAY)
    ),
    ISINSCOPE('Calendar'[Date].[Month]), 
    CALCULATE(
        [Effort % ALLSELECTED],
         DATEADD('Calendar'[Date].[Date], -1, MONTH)
    ), 
    ISINSCOPE('Calendar'[Date].[Quarter]),
    CALCULATE(
      [Effort % ALLSELECTED],
       DATEADD('Calendar'[Date].[Date], -1, QUARTER)
    ), 
    ISINSCOPE('Calendar'[Date].[Year]),
    CALCULATE(
      [Effort % ALLSELECTED],
       DATEADD('Calendar'[Date].[Date],-1, YEAR)
    )
)

 

 


I also tried to use the Effort % calculation in VAR but this ignores DATEADD:

 

 

Previous Period Effort % ALLSELECTED VAR = 

VAR _selectedDistribution = 
 [Effort (%)]/
CALCULATE(
     [Effort (%)],
    ALLSELECTED( demodata )
    ) 

RETURN

SWITCH(
    TRUE(),
    ISINSCOPE('Calendar'[Date].[Day]),   
    CALCULATE(
      _selectedDistribution,
        DATEADD('Calendar'[Date], -1, DAY)
    ),
    ISINSCOPE('Calendar'[Date].[Month]), 
    CALCULATE(
        _selectedDistribution ,
         DATEADD('Calendar'[Date], -1, MONTH)
    ), 
    ISINSCOPE('Calendar'[Date].[Quarter]),
    CALCULATE(
      _selectedDistribution,
        DATEADD('Calendar'[Date], -1, QUARTER)
    ), 
    ISINSCOPE('Calendar'[Date].[Year]),
    CALCULATE(
      _selectedDistribution,
        DATEADD('Calendar'[Date],-1, YEAR)
    )
)

 

 

I quess it is probably some context issue but I don't understand what and how to fix it.

Here's a table with all those above measures:

 

Minna_2-1642526967847.png

I hope you understood what I'm trying to do here?

I would really appreciate your expertise because I've stuggled with this a looong time...


BR,
Minna
pbix: Demo.pbix 
https://www.dropbox.com/s/lj80e3wja9o5yhm/Demo.pbix?dl=0

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

Hi @Anonymous ,

According to your sample, can see, there's a total value of Effort(%), but there isn't a total value of Previous Period Effor%, that's why can't directly use the below formula like Effort % ALLSELECTED.

Previous Period Effort % ALLSELECTED= 
DIVIDE([Previous Period Effort %],CALCULATE([Previous Period Effort %],ALLSELECTED(demodata)))

vkalyjmsft_0-1642748014243.png

As for why there isn't a total value of Previous Period Effor%, because the ISINSCOPE function in your formula, there isn't a date in the total row, so it shows blank.

Here's my solution.

Previous Period Effort % = 
SWITCH(
    TRUE(),
    ISINSCOPE('Calendar'[Date].[Day])||[Effort % ALLSELECTED]=1,
     CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, DAY))
    , 
    ISINSCOPE('Calendar'[Date].[Month])||[Effort % ALLSELECTED]=1,
     CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, MONTH)
    ), 
    ISINSCOPE('Calendar'[Date].[Quarter])||[Effort % ALLSELECTED]=1,
     CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, QUARTER)
    ), 
    ISINSCOPE('Calendar'[Date].[Year])||[Effort % ALLSELECTED]=1,
     CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, YEAR))
    )
Previous Period Effort % ALLSELECTED= 
DIVIDE([Previous Period Effort %],CALCULATE([Previous Period Effort %],ALLSELECTED(demodata)))

Get the result.

vkalyjmsft_1-1642748822954.png

I attach my sample below for reference.

 

Best Regards,
Community Support Team _ kalyj

 

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

2 REPLIES 2
v-yanjiang-msft
Community Support
Community Support

Hi @Anonymous ,

According to your sample, can see, there's a total value of Effort(%), but there isn't a total value of Previous Period Effor%, that's why can't directly use the below formula like Effort % ALLSELECTED.

Previous Period Effort % ALLSELECTED= 
DIVIDE([Previous Period Effort %],CALCULATE([Previous Period Effort %],ALLSELECTED(demodata)))

vkalyjmsft_0-1642748014243.png

As for why there isn't a total value of Previous Period Effor%, because the ISINSCOPE function in your formula, there isn't a date in the total row, so it shows blank.

Here's my solution.

Previous Period Effort % = 
SWITCH(
    TRUE(),
    ISINSCOPE('Calendar'[Date].[Day])||[Effort % ALLSELECTED]=1,
     CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, DAY))
    , 
    ISINSCOPE('Calendar'[Date].[Month])||[Effort % ALLSELECTED]=1,
     CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, MONTH)
    ), 
    ISINSCOPE('Calendar'[Date].[Quarter])||[Effort % ALLSELECTED]=1,
     CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, QUARTER)
    ), 
    ISINSCOPE('Calendar'[Date].[Year])||[Effort % ALLSELECTED]=1,
     CALCULATE(
        [Effort (%)],
        DATEADD('Calendar'[Date].[Date], -1, YEAR))
    )
Previous Period Effort % ALLSELECTED= 
DIVIDE([Previous Period Effort %],CALCULATE([Previous Period Effort %],ALLSELECTED(demodata)))

Get the result.

vkalyjmsft_1-1642748822954.png

I attach my sample below for reference.

 

Best Regards,
Community Support Team _ kalyj

 

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

Anonymous
Not applicable

Hi @v-yanjiang-msft 

Oh, what a clever solution, wouldn't have figured this out myself - ever!
Thank you ever so much, you're brilliant! 🙂

BR,
Minna

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.