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

Get Fabric certified for FREE! Don't miss your chance! Learn more

Reply
Anonymous
Not applicable

Creating a filtered table based on another one

Here's the link to the file

 

Hey there

 

I'd like to create a table that filters every row of my Fact table as long as the rows' dates are prior or equal to the due date (stored on its own table named 'f_due_user')

Here's the code I've authored but didn't get the expected outcome:

Summarized Table = 
CALCULATETABLE (
    SUMMARIZE ( 
        'Fact', 
        'Fact'[User_id], 
        'Fact'[Subscription_date] 
        ),
    'Fact'[Subscription_date] <= MIN ( f_due_user[Due_payment] ),
    TREATAS( VALUES( 'Fact'[User_id] ), f_due_user[User_id] ),
    TREATAS( VALUES( 'Fact'[Subscription_date] ), f_due_user[Due_payment] )
)

 

I've even tried it by simply using FILTER() as follows, but it did not works either:

VAR _DueDate = MIN( f_due_user[Due_payment] )
VAR _CurrentUser = SELECTEDVALUE( 'Fact'[User_id] )
VAR _Result =
    FILTER(
        ALL( 'Fact' ),
        'Fact'[Subscription_date] <= _DueDate -- && 'Fact'[User_id] = _CurrentUser
    )
RETURN
    _Result

  

Taking as an example the user_id = 22 (but not limited solely to this user_id), here's what I'd like to do:

 

Explanation.png

 

Any thoughts on how this table could be created?

 

 

Thanks in advance.

1 ACCEPTED SOLUTION
ThxAlot
Super User
Super User

In your data model, I didn't see any necessity of d_users since f_due_user[User_id] is a distinct column; you can built a relationship between f_due_user (1:*) Fact by [User_id].

 

Summarized Table.pbix

Anyway, the solution based on your current model,

Summarized Table = 
GENERATE(
    f_due_user,
    VAR __due = f_due_user[Due_payment]
    RETURN
        SELECTCOLUMNS(
            CALCULATETABLE(
                SUMMARIZE( 'Fact', 'Fact'[User_id], 'Fact'[Subscription_date] ),
                CALCULATETABLE( d_users ),
                'Fact'[Subscription_date] <= __due
            ),
            "@subscription", 'Fact'[Subscription_date]
        )
)

ThxAlot_0-1682841310023.png



Expertise = List.Accumulate(


        {Days as from Today},


        {Skills and Knowledge},


        (Current, Everyday) => Current & Day.LearnAndPractise(Everyday)


)



View solution in original post

4 REPLIES 4
ThxAlot
Super User
Super User

In your data model, I didn't see any necessity of d_users since f_due_user[User_id] is a distinct column; you can built a relationship between f_due_user (1:*) Fact by [User_id].

 

Summarized Table.pbix

Anyway, the solution based on your current model,

Summarized Table = 
GENERATE(
    f_due_user,
    VAR __due = f_due_user[Due_payment]
    RETURN
        SELECTCOLUMNS(
            CALCULATETABLE(
                SUMMARIZE( 'Fact', 'Fact'[User_id], 'Fact'[Subscription_date] ),
                CALCULATETABLE( d_users ),
                'Fact'[Subscription_date] <= __due
            ),
            "@subscription", 'Fact'[Subscription_date]
        )
)

ThxAlot_0-1682841310023.png



Expertise = List.Accumulate(


        {Days as from Today},


        {Skills and Knowledge},


        (Current, Everyday) => Current & Day.LearnAndPractise(Everyday)


)



Anonymous
Not applicable

It's exactly what I was looking for, thanks a lot.

Could you explain me whats the point of this CALCULATETABLE() inside another CALCULATETABLE? Dind't get what it is performing on this formula. 

 

Pedro503_0-1682877053190.png


Once again, appreciate your help 👍

Glad that my proposal helps!

In the current data model, filters on f_due_user can't be propagated to Fact table in a natural manner; thus Expanded Table ( CALCULATETABLE(d_users) ) can be leveraged here for filter propagation. 



Expertise = List.Accumulate(


        {Days as from Today},


        {Skills and Knowledge},


        (Current, Everyday) => Current & Day.LearnAndPractise(Everyday)


)



Anonymous
Not applicable

You're totally right. Thanks for your explanation.

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

Share feedback directly with Fabric product managers, participate in targeted research studies and influence the Fabric roadmap.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.