SumIf text matches in row above

lfcreds11

New Member
Joined
Oct 12, 2009
Messages
29
Hi all,

I am trying to have column H total the points to date only if the name in Column A matches the row above it. I had created a macro to automatically sort Column A. But currently Column H is adding the row above even though the names do not match. Column H currently has this formula: =IF(G2<=$M$1,"0",SUM(E2,H1)) but I only want that to happen if the names match in A. I hope that makes sense. It's currently showing 2.5 points to date but it should only show 1 for Employee 1. I have over 200 names so writing each individual name would be tedious and time consuming as each formula. Any suggestions are appreciated!

Column AColumn BColumn CColumn DColumn EColumn FColumn GColumn HColumn M
NameDateMinsTypePointsemailreset datePoints to Date=Now()
Employee 15/20/196Late 2.5y11/20/19.5
Employee 24/15/1920Late 31.5y10/15/191.5
Employee 15/21/1910Late 2.5y11/21/192.5

<tbody>
</tbody>
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Try this:

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:75.09px;" /><col style="width:51.33px;" /><col style="width:35.17px;" /><col style="width:40.87px;" /><col style="width:43.72px;" /><col style="width:39.92px;" /><col style="width:71.29px;" /><col style="width:89.35px;" /><col style="width:71.29px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td><td >H</td><td >M</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Name</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Date</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Mins</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Type</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Points</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">email</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">reset date</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Points to Date</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">21/05/2019</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >Employee 1</td><td style="text-align:right; ">5/20/19</td><td style="text-align:right; ">6</td><td >Late 2</td><td style="text-align:right; ">0.5</td><td >y</td><td style="text-align:right; ">20/11/2019</td><td style="text-align:right; ">0.5</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >Employee 2</td><td style="text-align:right; ">4/15/19</td><td style="text-align:right; ">20</td><td >Late 3</td><td style="text-align:right; ">1.5</td><td >y</td><td style="text-align:right; ">15/10/2019</td><td style="text-align:right; ">1.5</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >Employee 1</td><td style="text-align:right; ">5/21/19</td><td style="text-align:right; ">10</td><td >Late 2</td><td style="text-align:right; ">0.5</td><td >y</td><td style="text-align:right; ">21/11/2019</td><td style="text-align:right; ">1</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >Employee 1</td><td style="text-align:right; ">5/20/19</td><td style="text-align:right; ">6</td><td >Late 2</td><td style="text-align:right; ">0.5</td><td >y</td><td style="text-align:right; ">20/11/2019</td><td style="text-align:right; ">1.5</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td >Employee 2</td><td style="text-align:right; ">4/15/19</td><td style="text-align:right; ">20</td><td >Late 3</td><td style="text-align:right; ">1.5</td><td >y</td><td style="text-align:right; ">15/10/2019</td><td style="text-align:right; ">3</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td >Employee 1</td><td style="text-align:right; ">5/21/19</td><td style="text-align:right; ">10</td><td >Late 2</td><td style="text-align:right; ">0.5</td><td >y</td><td style="text-align:right; ">21/11/2019</td><td style="text-align:right; ">2</td><td > </td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >M1</td><td >=NOW()</td></tr><tr><td >H2</td><td >=SUMPRODUCT(($A$2:A2=A2)*($G$2:G2>$M$1)*($E$2:E2))</td></tr></table></td></tr></table>
 
Upvote 0
Just to mention, SUMIFS usually works faster than SUMPRODUCT:

=SUMIFS($E$2:E2,$A$2:A2,A2,$G$2:G2,">"&$M$1)
 
Upvote 0

Forum statistics

Threads
1,214,801
Messages
6,121,644
Members
449,045
Latest member
Marcus05

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