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
Hello,
I need to group transactions by specific number of days after that point. For example number of transac tions between the 3rd-5th day, the 6th-15th day and so on. Can someone please help me figure out the formula for this
Thank you!
Solved! Go to Solution.
Hi @Anonymous ,
Here are the steps you can follow:
1. Check the yellow column – Transform – Unpivot Columns.
2. Select the new [Atrribute] – convert its format to Date/Time.
3. Create calculated table.
Table 2 =
SUMMARIZE('Table','Table'[Name],
"1-2days",
SUMX(FILTER(ALL('Table'),'Table'[Name]=EARLIER('Table'[Name])&&
'Table'[Attribute]>=
MINX(ALL('Table'),'Table'[Attribute])&&'Table'[Attribute]<=MINX(ALL('Table'),'Table'[Attribute])+1),[Value]),
"3-5days",
SUMX(FILTER(ALL('Table'),'Table'[Name]=EARLIER('Table'[Name])&&
'Table'[Attribute]>=
MINX(ALL('Table'),'Table'[Attribute])+2&&'Table'[Attribute]<=MINX(ALL('Table'),'Table'[Attribute])+6),[Value]))
4. Result:
If you need pbix, please click here.
Grouping transactions by number of days.pbix
Best Regards,
Liu Yang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Hi @Anonymous ,
Here are the steps you can follow:
1. Check the yellow column – Transform – Unpivot Columns.
2. Select the new [Atrribute] – convert its format to Date/Time.
3. Create calculated table.
Table 2 =
SUMMARIZE('Table','Table'[Name],
"1-2days",
SUMX(FILTER(ALL('Table'),'Table'[Name]=EARLIER('Table'[Name])&&
'Table'[Attribute]>=
MINX(ALL('Table'),'Table'[Attribute])&&'Table'[Attribute]<=MINX(ALL('Table'),'Table'[Attribute])+1),[Value]),
"3-5days",
SUMX(FILTER(ALL('Table'),'Table'[Name]=EARLIER('Table'[Name])&&
'Table'[Attribute]>=
MINX(ALL('Table'),'Table'[Attribute])+2&&'Table'[Attribute]<=MINX(ALL('Table'),'Table'[Attribute])+6),[Value]))
4. Result:
If you need pbix, please click here.
Grouping transactions by number of days.pbix
Best Regards,
Liu Yang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Thank you!!
Below an example of the data set.
Name | 9/25/2022 | 9/26/2022 | 9/27/2022 | 9/28/2022 | 9/29/2022 | 9/30/2022 | 10/1/2022 |
Name 1 | 3 | 4 | 5 | 6 | 7 | 8 | 9 |
Name 2 | 2 | 3 | 4 | 5 | 6 | 7 | 8 |
Name 3 | 5 | 6 | 7 | 8 | 9 | 10 | 11 |
Result I am looking for
Name | 1-2 days (9/25-9/26) | 3-5 days(9/27-10/1) |
Name 1 | 7 | 35 |
Name 2 | 5 | 30 |
Name 3 | 11 | 45 |
Table Fields
Date
Name
Transactions
I used a matrix and tried grouping by the switch function but it didn't aggregate values correctly when I picked the day I wanted it to start counting from
Day Grouping =
SWITCH(TRUE(),
AND(DATEDIFF(Table[Date],Today(),DAY)>=1,
DATEDIFF(Source[Table[Date],Today(),DAY) <=2), "1-2",
AND(DATEDIFF(Table[Date],Today(),DAY)>=3,
DATEDIFF(Source[Table[Date],Today(),DAY) <=6), "3-6",
AND(DATEDIFF(Source[Table[Date],Today(),DAY)>=6,
DATEDIFF(Source[Table[Date],Today(),DAY) <=15), "6-15",
AND(DATEDIFF(Source[Table[Date],Today(),DAY)>=16,
DATEDIFF(Source[Table[Date],Today(),DAY) <=22), "16-22",
AND(DATEDIFF(Source[Table[Date],Today(),DAY)>=23,
DATEDIFF(Source[Table[Date],Today(),DAY) <=29), "23-29",
AND(DATEDIFF(Source[Table[Date],Today(),DAY)>=30,
DATEDIFF(Source[Table[Date],Today(),DAY) <=60), "30-60")
Thank you
@Anonymous
Please share the sample data
Proud to be a Super User! | |
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 |
---|---|
132 | |
90 | |
88 | |
64 | |
58 |
User | Count |
---|---|
203 | |
141 | |
107 | |
73 | |
70 |