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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
Nuuk
New Member

Homologating/Matching weeks between different terms

I am currently working a dashboard for an institution that has three different terms per year. They’d like to compare their actual progress to the past term (-1) and to the correspondent to the past year (-3), however when comparing to the past term, week numbers don’t match. For example:

 

2d5eec2270479ff8361376144379bc3f455149b9.png

 

And I’d like to achieve this (This I’ve achieved it by using a lookup table so that I can match the weeks from the past term to this one):

107824689bcdc2f382b61e0b847980f88720493f.png

 

However, my question is if this is achievable from the original date table without the need to use an additional look up table, if this would be the best practice, and how could it be done?

I’d appreciate any help.

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

Hi @Nuuk ,

 

I suggest you to create a DimWeekandTerm table to help your calculation.

DimWeekandTerm = 
GENERATE(VALUES('Table'[Week Number]),VALUES('Table'[Term]))
Term Sort = 
RANKX(DimWeekandTerm,'DimWeekandTerm'[Term],,ASC,Dense)

Measure:

Measure = 
VAR _CURRENTTERM =
    MAXX ( ALL ( 'DimWeekandTerm' ), 'DimWeekandTerm'[Term Sort] )
VAR _PART1 =
    CALCULATE (
        SUM ( 'Table'[Value] ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[Week Number]
                = MAX ( DimWeekandTerm[Week Number] ) - 16
                && 'Table'[Term] = MAX ( DimWeekandTerm[Term] )
        )
    )
VAR _PART2 =
    CALCULATE (
        SUM ( 'Table'[Value] ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[Week Number] = MAX ( DimWeekandTerm[Week Number] )
                && 'Table'[Term] = MAX ( DimWeekandTerm[Term] )
        )
    )
VAR _TermStart =
    CALCULATE (
        MIN ( DimWeekandTerm[Week Number] ),
        FILTER (
            ALL ( DimWeekandTerm ),
            CALCULATE (
                SUM ( 'Table'[Value] ),
                FILTER (
                    ALL ( 'Table' ),
                    'Table'[Week Number] = EARLIER ( DimWeekandTerm[Week Number] )
                        && 'Table'[Term] = EARLIER ( DimWeekandTerm[Term] )
                )
            )
                <> BLANK ()
                && DimWeekandTerm[Term Sort] = _CURRENTTERM
        )
    )
RETURN
    IF (
        MAX ( DimWeekandTerm[Week Number] ) >= _TermStart,
        IF (
            MAX ( DimWeekandTerm[Term Sort] )
                IN {
                _CURRENTTERM - 1,
                _CURRENTTERM - 3
            },
            _PART1,
            _PART2
        )
    )

Result is as below.

vrzhoumsft_0-1685694318210.png

Best Regards,
Rico Zhou

 

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

1 REPLY 1
v-rzhou-msft
Community Support
Community Support

Hi @Nuuk ,

 

I suggest you to create a DimWeekandTerm table to help your calculation.

DimWeekandTerm = 
GENERATE(VALUES('Table'[Week Number]),VALUES('Table'[Term]))
Term Sort = 
RANKX(DimWeekandTerm,'DimWeekandTerm'[Term],,ASC,Dense)

Measure:

Measure = 
VAR _CURRENTTERM =
    MAXX ( ALL ( 'DimWeekandTerm' ), 'DimWeekandTerm'[Term Sort] )
VAR _PART1 =
    CALCULATE (
        SUM ( 'Table'[Value] ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[Week Number]
                = MAX ( DimWeekandTerm[Week Number] ) - 16
                && 'Table'[Term] = MAX ( DimWeekandTerm[Term] )
        )
    )
VAR _PART2 =
    CALCULATE (
        SUM ( 'Table'[Value] ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[Week Number] = MAX ( DimWeekandTerm[Week Number] )
                && 'Table'[Term] = MAX ( DimWeekandTerm[Term] )
        )
    )
VAR _TermStart =
    CALCULATE (
        MIN ( DimWeekandTerm[Week Number] ),
        FILTER (
            ALL ( DimWeekandTerm ),
            CALCULATE (
                SUM ( 'Table'[Value] ),
                FILTER (
                    ALL ( 'Table' ),
                    'Table'[Week Number] = EARLIER ( DimWeekandTerm[Week Number] )
                        && 'Table'[Term] = EARLIER ( DimWeekandTerm[Term] )
                )
            )
                <> BLANK ()
                && DimWeekandTerm[Term Sort] = _CURRENTTERM
        )
    )
RETURN
    IF (
        MAX ( DimWeekandTerm[Week Number] ) >= _TermStart,
        IF (
            MAX ( DimWeekandTerm[Term Sort] )
                IN {
                _CURRENTTERM - 1,
                _CURRENTTERM - 3
            },
            _PART1,
            _PART2
        )
    )

Result is as below.

vrzhoumsft_0-1685694318210.png

Best Regards,
Rico Zhou

 

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

 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.