- Subscribe to RSS Feed
- Mark Topic as New
- Mark Topic as Read
- Float this Topic for Current User
- Bookmark
- Subscribe
- Printer Friendly Page
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Use count with look up and an if argument
Hi All,
I have two tables which are related by CurveId. I want to calculate how many of the rows whose Score in Table 1 fall in between "From and To" in Table 2 and put the total count against each row under the TotalCount column.
As in the example below, there are 2 rows in Table 1 whose scores fall in between 4% and 10% in CurveId 1 in Table 2, and there are 3 rows in Table 1 whose scores fall in between 10% and 20% in CurveId 1 Table 2.
Table 1 | |||
TransactionId | CurveId | Score | TotalCount |
1000 | 1 | 2.00% | 1 |
1000 | 1 | 7.00% | 2 |
1000 | 1 | 8.00% | 2 |
1000 | 1 | 15.00% | 3 |
1000 | 1 | 16.00% | 3 |
1000 | 1 | 20.00% | 3 |
Table 2 | ||
CurveId | From | To |
1 | 0% | 4% |
1 | 4% | 10% |
1 | 10% | 20% |
2 | 0% | 8% |
2 | 8% | 15% |
2 | 15% | 20% |
2 | 20% | 25% |
I have tried the expression below but it just returns 1 against each row.
CALCULATE(
COUNT(Table1[TransactionId]),
FILTER(Table2, Table1[Score]>=Table2[From]&&Table1[Score]<=Table2[To])
)
Any help will be greatly appreciated.
Thank you.
Solved! Go to Solution.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Hi @theblueslover ,
You could try this measure.
Count =
CALCULATE (
COUNT ( 'Table'[CurveId] ),
FILTER (
'Table',
[Score] <= MAX ( 'Table (2)'[To] )
&& [Score] > MAX ( 'Table (2)'[From] )
&& [CurveId] = MAX ( 'Table (2)'[CurveId] )
)
)
You can check more details from here.
Best Regards,
Stephen Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Hi @theblueslover ,
Could you tell me if your problem has been solved?
If it is, kindly Accept it as the solution. More people will benefit from it.
Or you are still confused about it, please provide me with more details about your table and your problem or share me with your pbix file from your Onedrive for Business.
Best Regards,
Stephen Tao
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Hi Stephen,
Thank you so much for your reply. what I would like to achieve is to add this as a column in Table 1 where we can see the transactions. So following from the same example, TotalCount column is a calculated column and we can see the total number against each line item.
Table 1 | |||
TransactionId | CurveId | Score | TotalCount |
1000 | 1 | 2.00% | 1 |
1000 | 1 | 7.00% | 2 |
1000 | 1 | 8.00% | 2 |
1000 | 1 | 15.00% | 3 |
1000 | 1 | 16.00% | 3 |
1000 | 1 | 20.00% | 3 |
Kind regards,
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Hi @theblueslover ,
You could try this measure.
Count =
CALCULATE (
COUNT ( 'Table'[CurveId] ),
FILTER (
'Table',
[Score] <= MAX ( 'Table (2)'[To] )
&& [Score] > MAX ( 'Table (2)'[From] )
&& [CurveId] = MAX ( 'Table (2)'[CurveId] )
)
)
You can check more details from here.
Best Regards,
Stephen Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
@theblueslover Sounds like you want to do an approximate lookup - see if this post helps https://excelwithallison.blogspot.com/2020/06/dax-approximate-lookup.html
Please @mention me in your reply if you want a response.
Copying DAX from this post? Click here for a hack to quickly replace it with your own table names
Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C
I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com
Helpful resources
Join us at the Microsoft Fabric Community Conference
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Microsoft Fabric Community Conference 2025
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
Subject | Author | Posted | |
---|---|---|---|
08-29-2024 03:03 PM | |||
08-20-2024 05:22 AM | |||
08-27-2024 09:02 AM | |||
11-28-2024 03:40 PM | |||
06-14-2023 10:38 PM |
User | Count |
---|---|
126 | |
82 | |
65 | |
54 | |
44 |
User | Count |
---|---|
194 | |
106 | |
92 | |
63 | |
51 |