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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
RGL
Helper II
Helper II

Average fo weekly distinct values

 

I need have a table with daily sales and calculate the average weekly sales for a fixed period, for L4W and for the last week.

 

How can I calculate the average of unique customers of each week.

 

For example

 

Week No.      DISTINTICT CUSTOMERS

Week 13                100

Week 14                  90

Week 15                120

 

I need the average of 100,90,120

 

There can be customers with cancellations or refunds, which have a negative sale amount, so I need to just count distinct customers with positive amounts.

 

thanks

1 ACCEPTED SOLUTION
Anonymous
Not applicable

// Your customers must be stored in a dimension
// table Customer. T is your sales table, the
// fact table. There's also a Dates dimension
// that's connected to your fact table via the
// Date field. The Date table is marked as
// a Date table in the model. Fact table should
// always be hidden and the only allowed objects
// exposed in it are measures. With this star-schema
// design (which is the only correct design, by the way)
// you can do...

[Total Amount] = SUM( T[Amount] )

// This is the number of visible customers,
// not necessarily the buying customers.
[# Custs] = COUNTROWS( Customer )

// These are buying customers within those
// that are visible.
[# Buying Custs] = DISTINCTCOUNT( T[CustomerId] )
	
// Now, you want to have the number of customers
// that for the selected period in Dates have Amounts > 0.
[# Positive Cust] =
	COUNTROWS(
		FILTER(
			Customer,
			[Total Amount] > 0
		)
	)

// Now, you can create the weekly average you want.
// Bear in mind that this average reposponds to
// any filters that restrict the number of days
// in the weeks and also excludes the weeks where
// the number of positive customers is BLANK. If
// you want to include the weeks where there were
// no customers, just add 0 to [# Positive Cust]
// in the measure.
[Weekly CustNo Avg] =
	AVERAGEX(
		VALUES( Dates[Week No] ),
		[# Positive Cust]
	)

 

Best

D

View solution in original post

2 REPLIES 2
amitchandak
Super User
Super User

@RGL ,

Try

averagex(Values(Table[Week No.]),[DISTINTICT CUSTOMERS])

Anonymous
Not applicable

// Your customers must be stored in a dimension
// table Customer. T is your sales table, the
// fact table. There's also a Dates dimension
// that's connected to your fact table via the
// Date field. The Date table is marked as
// a Date table in the model. Fact table should
// always be hidden and the only allowed objects
// exposed in it are measures. With this star-schema
// design (which is the only correct design, by the way)
// you can do...

[Total Amount] = SUM( T[Amount] )

// This is the number of visible customers,
// not necessarily the buying customers.
[# Custs] = COUNTROWS( Customer )

// These are buying customers within those
// that are visible.
[# Buying Custs] = DISTINCTCOUNT( T[CustomerId] )
	
// Now, you want to have the number of customers
// that for the selected period in Dates have Amounts > 0.
[# Positive Cust] =
	COUNTROWS(
		FILTER(
			Customer,
			[Total Amount] > 0
		)
	)

// Now, you can create the weekly average you want.
// Bear in mind that this average reposponds to
// any filters that restrict the number of days
// in the weeks and also excludes the weeks where
// the number of positive customers is BLANK. If
// you want to include the weeks where there were
// no customers, just add 0 to [# Positive Cust]
// in the measure.
[Weekly CustNo Avg] =
	AVERAGEX(
		VALUES( Dates[Week No] ),
		[# Positive Cust]
	)

 

Best

D

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors