How to Count of invoice numbers in a column

Copper Contributor

How do we count date wise total invoices from the below table (without counting duplicates)

 

I have tried this formula =SUM(IF(FREQUENCY(C14:C24,C14:C24)>0,1)) but this gives total counts (excl duplicates) irrespective of date

 

DateInv Number
24-04-20221
24-04-20222
24-04-20222
24-04-20222
25-04-20226
25-04-202288
25-04-202288
28-04-202254
28-04-202254
28-04-202259
28-04-202259
  
18 Replies

@Shivashimladka

With data in A14:B24:

 

=SUMPRODUCT(1/COUNTIFS(A14:A24,A14:A24,B14:B24,B14:B24))

@Hans Vogelaar  Thank you Hans Vogelaar. This gives me count of invoices, but not date wise?

 

Need to fill the below table (invoice count date wise)

 

DateCount of inv
24-04-2022?? 
25-04-2022?? 
28-04-2022??

 

Data for filling the above table - 

 

DateInv Number
24-04-20221
24-04-20222
24-04-20222
24-04-20222
25-04-20226
25-04-202288
25-04-202288
28-04-202254
28-04-202254
28-04-202259
28-04-202259

 

 

@Shivashimladka 

A solution is to make sure you have access to Excel 365 and write the formula

= LET(
    date,  UNIQUE(sourceDate),
    count, COUNTIFS(sourceDate,date),
    HSTACK(date, count)
  )

image.png

 

 

@Shivashimladka 

You could create a pivot table, adding the data to the Data Model:

S1359.png

You can then choose Distinct Count to summarize the Inv Number field:

S1360.png

Result:

S1361.png

Sorry, misread the question.

= LET(
    distinctInv, UNIQUE(sourceData),
    invDate,     TAKE(distinctInv, ,1),
    date,        UNIQUE(sourceDate),
    count,       MAP(date, LAMBDA(d, 
                     COUNT(IF(invDate=d, 1)))),
    HSTACK(date, count)
  )

image.png

@Shivashimladka 

=SUM(N(IF($A$5:$A$15=D7,MATCH(IF($A$5:$A$15=D7,$B$5:$B$15),IF($A$5:$A$15=D7,$B$5:$B$15),)=ROW($1:$11))))

An alternative could be this formula. Enter the formula with ctrl+shift+enter if you don't work with Office365 or 2021. 

Thank you so much
This too works. Just curious about the logic behind selecting Row 1 to 11....

@Shivashimladka 

The array of dates and invoice numbers has 11 rows. If you select the MATCH or the ROW part of the formula and press F9 the results are shown in the formula bar. You can see them in the pictures in the attached file. The "then" part of the IF formula compares these results. You can return to the formula with ctrl+Z.

@OliverScheurich 

This is my way of understanding your approach.  Range references always were meaningless to me so refactoring was a key element of my understanding a formula.  I never could tell whether the result was more intelligible or whether it was simply that the refactoring process provided insight.

= LET(
    recordNum,       SEQUENCE(ROWS(sourceData)),
    selectedDate?,   sourceDate=@date,
    selectedInvoice, IF(selectedDate?,invoice),
    firstMatch,      MATCH(selectedInvoice, selectedInvoice,),
  SUM(N(IF(selectedDate?, firstMatch=recordNum))))

It wouldn't have been quite like this a year or two ago, but LET and LAMBDA are now so deeply engrained in my thought process, I almost forget how things used to be.

@Shivashimladka 

 

_Screenshot.png

 

=SUM(--
    (
        FREQUENCY(
            (A$14:A$24=D14)*B$14:B$24,
            (A$14:A$24=D14)*B$14:B$24
        ) > 0
    )
)-1

@Shivashimladka 

I have come to the conclusion that building the entire array of dates and counts in one formula overcomplicates things.  So, given the distinct dates in a spilt range

= MAP(distinctDate#,
      LAMBDA(d, COUNTA(
          UNIQUE(FILTER(invoice, invoiceDate=d))
      ))
  )

@Peter Bartholomew , @Shivashimladka 

To illustrate @Hans Vogelaar solution I added it to the same file

image.png

@Sergei Baklan @Hans Vogelaar 

Agreed that it is a good idea to demonstrate that the Pivot Table provides a realistic solution, and without requiring knowledge of formulas.  The tabular format without subtotals is reasonably easy to emulate using array formulas but to include subtotals or table pivoting requires serious effort without the Pivot Table.  I always get caught out by the need to refresh but, then, I haven't used Calculation Manual either.

@Peter Bartholomew 

I believe one day we will have out of the box DA formula for the aggregations. It's hard to compete with PowerPivot which has tens of years history, nonetheless. All depends on concrete case. Cube formulae in combination with dynamic arrays could be a compromise for today, but here we shall train our brains with MDX to generate more or less complex solution.

To refresh or not to refresh is always the question.

@Shivashimladka Can you help with counting these please?  The data is in L3:L17

XCT22-2494-01
XCT22-2494-02
XCT22-2494-03
XCT22-2494-03
XCT22-2494-03
XCT22-2494-03
XCT22-2494-04
XCT22-2494-04
XCT22-2494-04
XCT22-2494-04
XCT22-2494-04
XCT22-2494-05
XCT22-2494-05
XCT22-2494-06
XCT22-2494-06

@KatieMcAdams 

Do you want to count unique values?

If you have Excel 2021 or 365:

=COUNTA(UNIQUE(L3:L17))

If you have an older version, as an array formula confirmed with Ctrl+Shift+Enter:

=SUMPRODUCT(1/COUNTIF(L3:L17,L3:L17))

@Hans Vogelaar Awesome.  Thank you