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
pfuschi
Frequent Visitor

Forecasting is not summing up

Hi all
I need your help in a DAX measure, which doesn't sum up...... I already tried with calculate and sumx, but haven't found a solution.


I have two tables.
- table "pupils" with one entry per year (2010 - 2021 ) and age  of students (0-16)

Table Pupils.png

And a second table "years" with entries from 2010 - 2040.

So far I have this matrix:

matrix distribution.png

 

my goal is to have a what-if analysis to see, what would be the distribution in the future, if the parameter "births" changes.
I already achieved this, as you can see in this picture.

predicted distribution.png

 

but unfortunately, the measure doesn't sum up, starting in 2022 onwards!!

Here is my measure:

test = 
VAR PupilsCount = sum('Pupils'[count])
VAR Diff = MAX(Year[Year]) - 2021
VAR AgeInt = max('Pupils'[Age]) 
VAR BirthNr = SELECTEDVALUE(Births[Births]; 13)
VAR PupFC = LOOKUPVALUE('Pupils'[count]; 'Pupils'[count];max('Pupils'[count])-diff ; 'Pupils'[Year]; max(Year[Year]) - diff) 
VAR Pup = IF (PupilsCount <> BLANK() ;    
    PupilsCount ; 
    if (AgeInt=0; 
        BirthNr; 
        if (PupFC = 0 ; Births; PupFC 
    )))
RETURN
Pup

What I need is a measure, which sums up from 2010 until 2040 and not only until 2021.

Thx for your help.

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

Hi @pfuschi,

 

If you mean look up suitable records based on year and age, you can refer to below steps.

 

1. Create a table stored year and not has relationship to original table.

Year Range = GENERATESERIES(2010,2040,1) 

2. Create matrix visual with age as row(original table), year as column(year range table), lookupvalue measure as value. 

Look up =
VAR currAge =
    LASTNONBLANK ( 'Sample'[Age], [Age] )
VAR currYear =
    SELECTEDVALUE ( 'Year Range'[Year] )
VAR lookup =
    LOOKUPVALUE (
        'Sample'[Count],
        'Sample'[Age], currAge,
        'Sample'[Year], currYear
    )
RETURN
    IF (
        lookup <> BLANK (),
        lookup
    )

9.PNG

 

3. Modify measure to add bin variable to store diff between year and age, use this variable to lookup value from previous records.

Look up 2 = 
VAR currAge =
    LASTNONBLANK ( 'Sample'[Age], [Age] )
VAR currYear =
    SELECTEDVALUE ( 'Year Range'[Year] )
VAR lookup =
    LOOKUPVALUE (
        'Sample'[Count],
        'Sample'[Age], currAge,
        'Sample'[Year], currYear
    )
VAR bin = currYear - currAge
RETURN
    IF (
        lookup <> BLANK (),
        lookup,
        CALCULATE (
            MAX ( 'Sample'[Count] ),
            FILTER ( ALL ( 'Sample' ), [Year] - [Age] = bin )
        )
            + 0
    )

10.PNG

 

BTW, if you want to summarize all suitable records, please use sum function to replace max function which I used in if statement.

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

1 REPLY 1
v-shex-msft
Community Support
Community Support

Hi @pfuschi,

 

If you mean look up suitable records based on year and age, you can refer to below steps.

 

1. Create a table stored year and not has relationship to original table.

Year Range = GENERATESERIES(2010,2040,1) 

2. Create matrix visual with age as row(original table), year as column(year range table), lookupvalue measure as value. 

Look up =
VAR currAge =
    LASTNONBLANK ( 'Sample'[Age], [Age] )
VAR currYear =
    SELECTEDVALUE ( 'Year Range'[Year] )
VAR lookup =
    LOOKUPVALUE (
        'Sample'[Count],
        'Sample'[Age], currAge,
        'Sample'[Year], currYear
    )
RETURN
    IF (
        lookup <> BLANK (),
        lookup
    )

9.PNG

 

3. Modify measure to add bin variable to store diff between year and age, use this variable to lookup value from previous records.

Look up 2 = 
VAR currAge =
    LASTNONBLANK ( 'Sample'[Age], [Age] )
VAR currYear =
    SELECTEDVALUE ( 'Year Range'[Year] )
VAR lookup =
    LOOKUPVALUE (
        'Sample'[Count],
        'Sample'[Age], currAge,
        'Sample'[Year], currYear
    )
VAR bin = currYear - currAge
RETURN
    IF (
        lookup <> BLANK (),
        lookup,
        CALCULATE (
            MAX ( 'Sample'[Count] ),
            FILTER ( ALL ( 'Sample' ), [Year] - [Age] = bin )
        )
            + 0
    )

10.PNG

 

BTW, if you want to summarize all suitable records, please use sum function to replace max function which I used in if statement.

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

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.