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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
kkassel
Frequent Visitor

Calculating week, ytd, and prior ytd with 2 step slicer

I've been messing around with this for a few days now and can't seem to get it to work.  Here's a small truncated sample set of data.

SalespersonWeekYearSales $
Jon122018 $        500
Jon152019 $        100
Dave162019 $        150
Dave172019 $        125
Jon172019 $        125
Dave452019 $        100
Jon452019 $        150
Dave62020 $        175
Dave152020 $        150
Jon172020 $        100

 

I'm trying to get a matrix visual similar to this.

 Current YearCurrent YearCurrent YearCurrent YearPrior YrPrior Yr
SalespersonWeek Sales #Week Sales RevenueYTD Sales #YTD Sales RevenuePY YTD Sales #PY YTD Revenue
Jon110011002225
Dave0023252275

 

My hang up is with the prior year columns.  I cannot get them to work out correctly.

THe report was a 2 step slicer where you select the year and then the week.  I've seen others combine the 2 into a week-year look (22-2020) but I'd like to keep it as is.  I've created a seperate calendar table with no relationship to the sales table.  The week slicer is using the week number from the calendar table whereas the year slicer is using the year from the sales table.  I'm doing it this way because I also have a bar chart visual in the report that is displaying the sales by week for the full year.

 

 

 

Any help would be appreciated.  Thanks!

1 ACCEPTED SOLUTION
v-yingjl
Community Support
Community Support

Hi @kkassel ,

I have created these following measures to try to achieve it:

Current year week sales =
VAR _re =
    COUNTROWS (
        FILTER (
            SUMMARIZE (
                FILTER (
                    ALLSELECTED ( 'Table' ),
                    'Table'[Week] = SELECTEDVALUE ( 'Calendar'[Week] )
                ),
                'Table'[Salesperson],
                'Table'[Week],
                'Table'[Year]
            ),
            [Salesperson] = SELECTEDVALUE ( 'Table'[Salesperson] )
        )
    )
RETURN
    IF ( ISBLANK ( _re ), 0, _re )
Current year #week sales revenue =
VAR _re =
    SUMX (
        FILTER (
            SUMMARIZE (
                FILTER (
                    ALLSELECTED ( 'Table' ),
                    'Table'[Week] = SELECTEDVALUE ( 'Calendar'[Week] )
                ),
                'Table'[Salesperson],
                'Table'[Sales $],
                'Table'[Week],
                'Table'[Year]
            ),
            [Salesperson] = SELECTEDVALUE ( 'Table'[Salesperson] )
        ),
        'Table'[Sales $]
    )
RETURN
    IF ( ISBLANK ( _re ), 0, _re )
Current year YTD sales = COUNTROWS('Table')
Current year #YTD sales revenue = SUM('Table'[Sales $])
Prior year YTD sales =
VAR _re =
    COUNTROWS (
        FILTER (
            ALL ( 'Table' ),
            [Salesperson] = SELECTEDVALUE ( 'Table'[Salesperson] )
                && [Year]
                    = SELECTEDVALUE ( 'Table'[Year] ) - 1
        )
    )
RETURN
    IF ( ISBLANK ( _re ), 0, _re )
Prior year #YTD sales revenue =
VAR _re =
    SUMX (
        FILTER (
            ALL ( 'Table' ),
            [Salesperson] = SELECTEDVALUE ( 'Table'[Salesperson] )
                && [Year]
                    = SELECTEDVALUE ( 'Table'[Year] ) - 1
        ),
        'Table'[Sales $]
    )
RETURN
    IF ( ISBLANK ( _re ), 0, _re )

The sample result may like is (example: 2020 week 17)

result.png

 

Sample file is attached that hopes to help you, please check and try it: Calculating week, ytd, and prior ytd with 2 step slicer.pbix 

 

Best Regards,
Yingjie Li

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

3 REPLIES 3
v-yingjl
Community Support
Community Support

Hi @kkassel ,

I have created these following measures to try to achieve it:

Current year week sales =
VAR _re =
    COUNTROWS (
        FILTER (
            SUMMARIZE (
                FILTER (
                    ALLSELECTED ( 'Table' ),
                    'Table'[Week] = SELECTEDVALUE ( 'Calendar'[Week] )
                ),
                'Table'[Salesperson],
                'Table'[Week],
                'Table'[Year]
            ),
            [Salesperson] = SELECTEDVALUE ( 'Table'[Salesperson] )
        )
    )
RETURN
    IF ( ISBLANK ( _re ), 0, _re )
Current year #week sales revenue =
VAR _re =
    SUMX (
        FILTER (
            SUMMARIZE (
                FILTER (
                    ALLSELECTED ( 'Table' ),
                    'Table'[Week] = SELECTEDVALUE ( 'Calendar'[Week] )
                ),
                'Table'[Salesperson],
                'Table'[Sales $],
                'Table'[Week],
                'Table'[Year]
            ),
            [Salesperson] = SELECTEDVALUE ( 'Table'[Salesperson] )
        ),
        'Table'[Sales $]
    )
RETURN
    IF ( ISBLANK ( _re ), 0, _re )
Current year YTD sales = COUNTROWS('Table')
Current year #YTD sales revenue = SUM('Table'[Sales $])
Prior year YTD sales =
VAR _re =
    COUNTROWS (
        FILTER (
            ALL ( 'Table' ),
            [Salesperson] = SELECTEDVALUE ( 'Table'[Salesperson] )
                && [Year]
                    = SELECTEDVALUE ( 'Table'[Year] ) - 1
        )
    )
RETURN
    IF ( ISBLANK ( _re ), 0, _re )
Prior year #YTD sales revenue =
VAR _re =
    SUMX (
        FILTER (
            ALL ( 'Table' ),
            [Salesperson] = SELECTEDVALUE ( 'Table'[Salesperson] )
                && [Year]
                    = SELECTEDVALUE ( 'Table'[Year] ) - 1
        ),
        'Table'[Sales $]
    )
RETURN
    IF ( ISBLANK ( _re ), 0, _re )

The sample result may like is (example: 2020 week 17)

result.png

 

Sample file is attached that hopes to help you, please check and try it: Calculating week, ytd, and prior ytd with 2 step slicer.pbix 

 

Best Regards,
Yingjie Li

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

 

Thank you @v-yingjl  that works but I have another question regarding the visual.  When I add subtotals to total up the rows, I get 0 for current year week sales, current year #week sales revenue, prior year ytd sales, and prior year #ytd sales revenue.  Why is that and how can i correct it so it totals correctly?

amitchandak
Super User
Super User

@kkassel , Are you using time intelligence with date calendar

example

YTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(('Date'[Date]),"12/31"))
This Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD((ENDOFYEAR('Date'[Date])),"12/31"))

Last YTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(dateadd('Date'[Date],-1,Year),"12/31"))
Last YTD complete Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(ENDOFYEAR(dateadd('Date'[Date],-1,Year)),"12/31"))

Last to last YTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(dateadd('Date'[Date],-2,Year),"12/31"))

Year behind Sales = CALCULATE(SUM(Sales[Sales Amount]),dateadd('Date'[Date],-1,Year))

 

Refer for Week, Also check comment for last year

https://community.powerbi.com/t5/Community-Blog/Week-Is-Not-So-Weak-WTD-Last-WTD-and-This-Week-vs-La...

 

To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :
https://radacad.com/creating-calendar-table-in-power-bi-using-dax-functions
https://www.archerpoint.com/blog/Posts/creating-date-table-power-bi
https://www.sqlbi.com/articles/creating-a-simple-date-table-in-dax/

See if my webinar on Time Intelligence can help: https://community.powerbi.com/t5/Webinars-and-Video-Gallery/PowerBI-Time-Intelligence-Calendar-WTD-Y...


Appreciate your Kudos.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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