Formula to Count Certain Leads for People Within a Specific Month for Sheets

Mattdim805

New Member
Joined
Dec 11, 2013
Messages
11
My Google sheet can be referenced here.

On the 2021 Openers tab, I need to create a formula that will allow me to count the total amount of leads associated with a specific person within a specific month, referencing the data on the 2021 Lead Data tab.

Formula criteria to consider:
  1. The Leads column should only count leads for the adjacent names that match the Lead Opener column, that are in the month of April and have a Lead Status of Lost Lead, Won Lead, Working, and Start a Quote.
  2. The Policies column should only count leads for the adjacent names that match the Lead Owner column, that is in the month of April, and have a Lead Status of Won Lead.
i.e. Cell '2021 Openers'!B6 needs to count cells that match the adjacent name in '2021 Openers'!A6 to '2021 Lead Data'!D:D, the month of April in '2021 Lead Data'!B:B, and "Lost Lead", "Start a Quote", "Won Lead", and "Working" in '2021 Lead Data'!C:C.

i.e. i.e. Cell '2021 Openers'!C6 needs to count cells that match the adjacent name in '2021 Openers'!A6 to '2021 Lead Data'!E:E, the month of April in '2021 Lead Data'!B:B, and "Won Lead" in '2021 Lead Data'!C:C.

Thanks in advance for the help!
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
Do you need this to work in Sheets or Excel?
 
Upvote 0
Not sure if this works in Sheets, but try
Excel Formula:
=SUM(COUNTIFS('2021 Lead Data'!D:D,A3,'2021 Lead Data'!B:B,4,'2021 Lead Data'!C:C,{"Lost lead","won lead","working","start a quote"}))
 
Upvote 0
Not sure if this works in Sheets, but try
Excel Formula:
=SUM(COUNTIFS('2021 Lead Data'!D:D,A3,'2021 Lead Data'!B:B,4,'2021 Lead Data'!C:C,{"Lost lead","won lead","working","start a quote"}))
Hi Fluff. Thanks for the formula. That didn't work for the Leads column, but I was able to modify it to work for the Policies column (did so by removing all criteria but "won lead" for that specific range). If you refer to the below screenshot, you'll find that Kayla Dent has 7 leads total, 4 of which became policies. The policies are calculating properly, but the lead count isn't.

1618692958131.png


Kayla should have 7 leads total in the month of April.

1618693045412.png
 
Upvote 0
You may need to wrap the formula in arrayformula like
Excel Formula:
=arrayformula(SUM(COUNTIFS('2021 Lead Data'!D:D,A3,'2021 Lead Data'!B:B,4,'2021 Lead Data'!C:C,{"Lost lead","won lead","working","start a quote"})))
 
Upvote 0
Solution
You may need to wrap the formula in arrayformula like
Excel Formula:
=arrayformula(SUM(COUNTIFS('2021 Lead Data'!D:D,A3,'2021 Lead Data'!B:B,4,'2021 Lead Data'!C:C,{"Lost lead","won lead","working","start a quote"})))
Worked like a charm - thanks!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,223,886
Messages
6,175,196
Members
452,616
Latest member
intern444

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top