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

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes! Register now.

Reply
jrhessey
Frequent Visitor

Row Number by table group

I'm trying to get a day count inside of a grouped by sum table.  I've found some posts here that I think give me a row number in the whole table, not the distinct rows in the summed table.  As you can see in the picture below RowNum appears to be counting up, but I'd just like 1,2,3,4 so I can divide the the Invoiced column by the number and get the running average invoice for through the month (see the excel sheet). 137360 / 1 = 137360, 210689 / 2 = 105344, and so on down the sheet/table. 

 

Formula I'm using 

 

RowNum =
CALCULATE (
COUNT ( DSO_All[Index] ),
FILTER ( ALLSELECTED ( DSO_All ), DSO_All[Index] <= MAX ( DSO_All[Index] ) )
)

 

 

 

PowerBI.jpg

 

Average daily invoice total I'm trying to achieve is below

 

Excel.jpg

 

 

Thanks!!

1 ACCEPTED SOLUTION
rajulshah
Resident Rockstar
Resident Rockstar

Hello @jrhessey,

 

You can create a measure as below:

 

Index = RANKX(ALLSELECTED(RowNum[RunDate]),CALCULATE(FIRSTDATE(RowNum[RunDate])),,ASC,Dense)

 

 

And then the below DAX query will help you:

 

Average Daily Invoice = 
VAR MTDInvoice = TOTALMTD(SUM(RowNum[Daily Invoice]),RowNum[RunDate])
RETURN DIVIDE(MTDInvoice,[Index])

 

 

mtdaverage.png

 

Hope this helps.

View solution in original post

3 REPLIES 3
rajulshah
Resident Rockstar
Resident Rockstar

Hello @jrhessey,

 

You can create a measure as below:

 

Index = RANKX(ALLSELECTED(RowNum[RunDate]),CALCULATE(FIRSTDATE(RowNum[RunDate])),,ASC,Dense)

 

 

And then the below DAX query will help you:

 

Average Daily Invoice = 
VAR MTDInvoice = TOTALMTD(SUM(RowNum[Daily Invoice]),RowNum[RunDate])
RETURN DIVIDE(MTDInvoice,[Index])

 

 

mtdaverage.png

 

Hope this helps.

Thanks for both answers @rajulshah and @Anonymous.  I gave the answer to @rajulshah because of the row numbers and gave kudos to @Anonymous , but if anyone is reading this and doesn't need that, both answers will work for you.  Thanks!!!

Anonymous
Not applicable

Hi, @jrhessey 

You don’t necessarily need the row number, you can filter with the date column instead.

 

Net Invoiced MTD = 
CALCULATE(SUM('Table'[Daily Invoice]),FILTER('Table','Table'[RunDate]<=EARLIER('Table'[RunDate])))

Average Daily Invoice = 
CALCULATE(AVERAGE('Table'[Daily Invoice]),FILTER('Table','Table'[RunDate]<=EARLIER('Table'[RunDate])))

 

If you need an index column and rename it as Day, it is suggested to use add index function in the power query.

Best,
Paul

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

September Power BI Update Carousel

Power BI Monthly Update - September 2025

Check out the September 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors
Top Kudoed Authors