March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe 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
Hi
I have this 2 tables on my dashboard:
TABLE1CUSTOMERS
CUSTOMERID | PRODUCTIDPURCHASE | REGISTER_DATE
________________________________________________________________
101 | C01 | 20/11/2019
102 | C02 | 20/12/2019
TABLE2PRODUCTS
PRODUCTID | LAUNCH_DATE
___________________________________
C01 | 19/11/2019
C02 | 22/11/2019
I would like to filter CUSTOMERID's out based on whether DATE1 is earlier than DATE2 to see how many new customers bought a product. I was thinking to do this using the DAX below:
NEW CUSTOMERS =
CALCULATE(
COUNT(TABLE1CUSTOMERS[CUSTOMERID]), FILTER('TABLE1CUSTOMERS','TABLE1CUSTOMERS'[REGISTER_DATE]>'TABLE2PRODUCTS'[LAUNCH_DATE])
)
but this is giving me an error because I can't use the FILTER function by referring to another table. Can somebody help me?
Solved! Go to Solution.
Hello,
As you are trying to access the rows of a table on the one side of the relationship from the many side of the relationship, you need to use RELATED function.
NEW_CUSTOMERS = COUNTX(FILTER(Cust,Cust[REGISTER_DATE]>RELATED(Products[LAUNCH_DATE])),Cust[CUSTOMERID]).
Though using CALCULATE function too we could achieve the same result.
This is yet another way of achieving it, without using calculate.
Regards,
Rakesh
Hello,
As you are trying to access the rows of a table on the one side of the relationship from the many side of the relationship, you need to use RELATED function.
NEW_CUSTOMERS = COUNTX(FILTER(Cust,Cust[REGISTER_DATE]>RELATED(Products[LAUNCH_DATE])),Cust[CUSTOMERID]).
Though using CALCULATE function too we could achieve the same result.
This is yet another way of achieving it, without using calculate.
Regards,
Rakesh
@MarketingGerens
It seems your tables are related by product ID, you need to use RELATED() when referring to THE other table columns.
NEW CUSTOMERS = CALCULATE(COUNT(Table1[ID]), FILTER('Table1','Table1'[Register Date]>RELATED(Table2[Launch Date])))
Paul Zheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
You can have a new column in table1customer, that can help you to solve the problem
minx(FILTER('TABLE2PRODUCTS','TABLE1CUSTOMERS'[REGISTER_DATE]>'TABLE2PRODUCTS'[LAUNCH_DATE]
&& 'TABLE1CUSTOMERS'[PRODUCTID ]='TABLE2PRODUCTS'[PRODUCTID ]),'TABLE2PRODUCTS'[LAUNCH_DATE])
Appreciate your Kudos. In case, this is the solution you are looking for, mark it as the Solution. In case it does not help, please provide additional information and mark me with @
Thanks. My Recent Blog -
Winner-Topper-on-Map-How-to-Color-States-on-a-Map-with-Winners , HR-Analytics-Active-Employee-Hire-and-Termination-trend
Power-BI-Working-with-Non-Standard-Time-Periods And Comparing-Data-Across-Date-Ranges
Connect on Linkedin
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
128 | |
90 | |
75 | |
56 | |
53 |
User | Count |
---|---|
200 | |
104 | |
101 | |
67 | |
55 |