cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
abarrett
Frequent Visitor

Card Visual showing Count of X filtered by average Y per X over a time period

Trying to Create 2 card visuals (one for this year and one for last year) that show the number of stores that are selling above an average N amount per month.

 

I think the best way to do this is to create a calculated column to sums the sales numbers by Store Name and Year. Can you let me know the best way to approach that?

 

Or if that is not the right appraoch, what might be? Pretty sure I am overcomplicated a potentially simple goal. 

1 ACCEPTED SOLUTION

Hi @abarrett,

Here is the calculated column formula to get the row count based on current category group and average:

 

Column = 
COUNTROWS (
    FILTER (
        SUMMARIZE (
            FILTER ( 'Table', [StoreRef] = EARLIER ( 'Table'[StoreRef] ) ),
            [StoreRef],
            [Date],
            [Revenue],
            "AVG",
                CALCULATE (
                    AVERAGE ( 'Table'[Revenue] ),
                    FILTER (
                        ALL ( 'Table' ),
                        [StoreRef] = EARLIER ( 'Table'[StoreRef] )
                            && YEAR ( [Date] ) = YEAR ( EARLIER ( 'Table'[Date] ) )
                    )
                )
        ),
        [Revenue] > [AVG]
    )
)

 

You can set two 'year' filters on your card to show different results.

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

5 REPLIES 5
jplouw1
New Member

Please give sample data?

abarrett
Frequent Visitor

Below are some overly simplied versions of the data where I am ultimately trying to find the number of stores (YTD, and prior year same time period) where the average monthly revenue is $50 for that same time period

in the below example 2021 (through June) would have 2 stores (Store B and C)
2022 would also have 1, Store A

 

Revenue Table

StoreRefRevenueDate
0$5001/1/2022
0$3004/1/2022
1$1,0001/2/2021
2$1001/5/2022
2$5003/3/2021

 


as well as a reference table where
0 -> Store A
1 -> Store B
2 -> Store C

Hi @abarrett,

Here is the calculated column formula to get the row count based on current category group and average:

 

Column = 
COUNTROWS (
    FILTER (
        SUMMARIZE (
            FILTER ( 'Table', [StoreRef] = EARLIER ( 'Table'[StoreRef] ) ),
            [StoreRef],
            [Date],
            [Revenue],
            "AVG",
                CALCULATE (
                    AVERAGE ( 'Table'[Revenue] ),
                    FILTER (
                        ALL ( 'Table' ),
                        [StoreRef] = EARLIER ( 'Table'[StoreRef] )
                            && YEAR ( [Date] ) = YEAR ( EARLIER ( 'Table'[Date] ) )
                    )
                )
        ),
        [Revenue] > [AVG]
    )
)

 

You can set two 'year' filters on your card to show different results.

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.
jplouw1
New Member

Good day Abarett


You should be able to create a measure that will calculate this (instead of doing an expensive calculated column)

 

Create a new measure.

 

MeasureName =

VAR AvgSalesStore = 12345 (or any value you hardcode) or VAR AvgSalesStore2 = AVERAGE('TableName'[Sales])

VAR NumberOfStoresAboveAverage = 
CALCULATE(

COUNTROWS('TableName'[Sales]), -- This is the main Fact Table

TableName'[Stores] >= AvgSalesStore  -- This will check the stores where the average is either AvgSalesStore or AvgSalesStore2

RETURN

NumberOfStoresAboveAverage

abarrett
Frequent Visitor

So this is fantastic, and I think it gets me about 95% of the direction I am going. 

 

each line item in my version of TableName[Sales] may have more than 1 in it. That is fine, swaping COUNTROWS with SUM should work. Would any other parts of the measure need to be adjusted?



 

Helpful resources

Announcements
September Update

Check it Out!

Click here to learn more about the September 2022 updates!

Power BI Show episode 9

The Power BI Community Show

Watch the playback when Priya Sathy and Charles Webb discuss Datamarts! Kelly also shares Power BI Community updates.

Power BI Dev Camp Session 26

New Date - Check it Out!

Mark your calendars and join us on Thursday, October 6 at 11a PDT for a great session with Ted Pattison!

Top Solution Authors
Top Kudoed Authors