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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Pedro503
Resolver I
Resolver I

Using ADDCOLUMNS instead of SUMMARIZE

Hey guys,

 

I've a huge dataset and I must summarize some of its values into a calendar-like table in order to better perform calculations with my measures. In this file I've created a smaller one just to exemplify what I aim to do.

 

The table that's generated off the SUMMARIZE measure brings the correct result, as follows:

@Summarized_tbl = 
SUMMARIZE(F_Table,
			    d_Calendario[Date],
				"@count",	VAR MAXDATE = MAX(d_Calendario[Date])
							VAR MINDATE = MIN(d_Calendario[Date])
							VAR CALCULO = COUNTROWS(FILTER(ALL(F_Table),
														[start]	<= 	MAXDATE	&&
														[end]	>=	MINDATE))
							RETURN CALCULO)

 

 Date  |   @count

1/1/20185
1/2/201814
1/3/201819
1/4/201830
1/5/201837
1/6/201843
1/7/201851
1/8/201858
1/9/201867
1/10/201873
1/11/201884
1/12/201893
1/13/201896
1/14/201899
1/15/2018108

 

However, in my real dataset I'm not able to build this table using SUMMARIZE due to performance issues (whenever I need to create a column or a measure it takes almost two minutes), so that's the reason why I'm trying to create this table using ADDCOLUMNS, which in turn brings the wrong result, as follows:

 

@AddC_tbl = 
ADDCOLUMNS(
            VALUES(d_Calendario[Date]),
			"@count",	VAR MAXDATE = MAX(d_Calendario[Date])
						VAR MINDATE = MIN(d_Calendario[Date])
						VAR CALCULO = CALCULATE(
                                                COUNTROWS(
                                                    FILTER(F_Table,
                                                                [start]	<= 	MAXDATE	&&
                                                                [end]	>=	MINDATE)))
						RETURN CALCULO)

 

 Date  |   @count

01/01/20185
02/01/20189
03/01/20186
04/01/201811
05/01/20187
06/01/20187
07/01/20189
08/01/20187
09/01/20189
10/01/20186
11/01/201811
12/01/20189
13/01/20183
14/01/20183
15/01/20189

 

This calculation is simply counting how many records started on the row context date, but what I want to do is to count how many records was active on each month, as follows:

 

Pedro503_1-1669308622384.png

Any thoughts on what I'm doing wrong about tha ADDCOLUMNS DAX measure previously shown?

1 ACCEPTED SOLUTION

The solution was wrapping the MAX and MIN formulas into CALCULATE and on the filter inside the COUNTROWS put an ALL.

@AddC_tbl = 
ADDCOLUMNS(
            VALUES(d_Calendario[Date]),
			"@count",	VAR MAXDATE = CALCULATE(MAX(d_Calendario[Date]))
						VAR MINDATE = CALCULATE(MIN(d_Calendario[Date]))
						VAR CALCULO = CALCULATE(
                                                COUNTROWS(
                                                    FILTER(ALL(F_Table),
                                                                [start]	<= 	MAXDATE	&&
                                                                [end]	>=	MINDATE)))
						RETURN CALCULO)

 

View solution in original post

3 REPLIES 3
Mikelytics
Resident Rockstar
Resident Rockstar

HI @Pedro503 ,

 

Can you maybe show the data model and sample data?

 

Because if I do not miss something then the following measure should bring the same result like the first measure and if it does then it also should be more performant.

@Summarized_tbl = 

SUMMARIZE(
   d_Calendario,
   d_Calendario[Date],
   "@count",	
   COUNTROWS(F_Table)
)

I come to this conclusion because you calculate a min and max on the same column which you use for your summarization and then you do another calculation using the min and max. Fomr my understanding you have a date table and a fact table with 1:n relation ship and you want the count of rows per date. If that is the case the measure above should do the job as well as should be more performant.

 

Or am I missing here something?

 

Best regards

Michael

-----------------------------------------------------

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly. Appreciate your thumbs up!

@ me in replies or I'll lose your thread.

-----------------------------------------------------

LinkedIn

------------------------------------------------------------------
Visit my blog datenhungrig which I recently started with content about business intelligence and Power BI in German and English or follow me on LinkedIn!

The solution was wrapping the MAX and MIN formulas into CALCULATE and on the filter inside the COUNTROWS put an ALL.

@AddC_tbl = 
ADDCOLUMNS(
            VALUES(d_Calendario[Date]),
			"@count",	VAR MAXDATE = CALCULATE(MAX(d_Calendario[Date]))
						VAR MINDATE = CALCULATE(MIN(d_Calendario[Date]))
						VAR CALCULO = CALCULATE(
                                                COUNTROWS(
                                                    FILTER(ALL(F_Table),
                                                                [start]	<= 	MAXDATE	&&
                                                                [end]	>=	MINDATE)))
						RETURN CALCULO)

 

Thanks for your response

 

Dont know what's happening, but I cant paste the link here (the second line contains the link). The file is on the second line. Actually what I aim to do is to count how many records exists on every month, not necessarily to just count the rows.

For instance, some Id started on 01/01/2018 and was active untill 10/01/2018. I wanna indicate that on every month from January to October this subscription was active.

 

Jan1
Feb1
Mar1
Apr1
May1
Jun1
Jul1
Aug1
Sep1
Oct1

 

To do so, I compute the following Dax measure:

 

 

 

COUNTROWS(
          FILTER(ALL(F_Table),
														                    
          [start] <= MAXDATE &&
														 
          [end]   >= MINDATE))

 

 

 

 

Do you know how to enhance its performance using ADDCOLUMNS?

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

Find out what's new and trending in the Fabric Community.

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

Check out the November 2024 Power BI update to learn about new features.