Help with Index / Match / SumIf

danielrussell2

New Member
Joined
Mar 17, 2016
Messages
17
Hello all,

I am trying to find a formula that will help me sum the totals from another sheet based on two separate criteria.

The first image is from a sheet named "DR LIST" and the second image is from a sheet named "Job Setup"


XaXbVOjjJJacnIpZsrb4gs2e0nX0-zDtF21iZ1cTzGEDCogQgnZ_iqUXd9SvTGQbegrZOMgsZ0MRyn8KSvctKWPtn2Z-P-_8feqGtT9cZWSmC4VOoefRyxXSkIH02InrOSradWgOYqFdlYQjih7t0TbeEsPTLd2aTc2FDF5zmkeQ1FaxaVtAN3fFMQBCXV_phmXpHcBgi8abzgy9JLaJZeAzjRbMigQOYEVHhsArf3fMjR95UQk7yMAS-myAje4-q4oFMGkh_n3iN9Uvm7YKfGY3uaqFsxsaSr831f7JcanzHzP_OMXqp_6utGDXylJes6z5k040lBU2wH_Vkk1xslOCv08ODVQxBZznkxp4ieZnNfVAXjkB62myO6TDrqDeVX2Isz5TsyDK0g52074StnY22QcjMx8kvnGrfanGdWq510Ny_d5i0n_a9Bo0jX9uZRFXuDpHK3LhzSNs__-rBPHxoN7b_gblQBLfP7kHQJBrTkWTjXhYpCJFHXEvd1INnr973zIWgswjjUw91aH7phMKihh6DZKXjA5iyArep8l9HpRtfL9DeuLFQFGTpICddwQY4STKjuIs-Ru5vsqz4YFxTwBzCcMc_vPdiipq7d5n18NbhTwy=w365-h205-no
fGj24IQnX212e3sV45kf9Bgb46daORPxSNChrWNNXmKIT43KSc8gFD_cnPmnLBZ-OYwsMbabJQWuw-JoSPb5_g4tq4alB7wszQcBPRCj3744-zn78AFNiTyGcRxW4sRDJHxKPkgTKMa7e7qT2VMz5UDz9eLaB97tfV46q9o2ruetu2oYpfhTFO-dukwxR2DY5wVnGJDEBnftp96TT1f4AmuuvptcTxUheUHWooO-RLdUzwjjorpAnH1XbXvykPAs9X5ZbZsjo_2HOvo0yYfBx8qpF8IGqVzY-lTVM7QNzq2nhv8NXzASGjSqQeSXemplCZOTvmzXiCdoGo_ryxqAm_UDLfP-GyBRKxYx8mL7GlJXInUPr78W3dofcpZFl9USm1YyYoe6WBJOBR66v3HzU59m-MMEJyPg2AhfOY4ETn2H8BPfh2NtMDrTeWapSVAeedReDPphwHB7MeZ5-3x_IiAQEhSBUk0DFGg9J-X7_cmrUBYEiV5wylxjXK07eYONKisEzTI4Uts7oZ1G_LNg1LJ2rV-ivBNochANufun9hKi-6-fgpaBcY0j6cRYdTrZDBCuradYj-RUZ-OLle1eqXnd2kXIiq9MrrQSrrYvxTpXzLzP=w364-h302-no



What I'm trying to do is have the total of "LH" (left hand) doors from the "Job Setup" sheet (in blue) show in the "DR List" sheet (in orange). But, this total will have to match two criteria: 1) Unit - in the example the unit is A1; 2) Door Number - lets say we are looking for door E1.

So, I need to sum the number of LH doors in blue that match the criteria of Unit Type A1 and Door Number E1 into cell C12 in orange. I'll need to search a big range in column D (blue) as all the doors for the building will be listed eventually - there will be more of Door Number E1 but in different unit types - so I only want to sum the ones for unit type A1 in cell C12 (orange).

I hope this makes sense, please let me know if I can clarify anything.
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
danielrussell2, Good afternoon.

Try to use:

Using your images reference,

Sheet DR List --> C12 --> FORMULA

C12 -->
=SUMIFS('Job Setup'!D70:D79, 'Job Setup'!A70:A79, 'DR List'!B10, 'Job Setup'!C70:C79, 'DR List'!B12)

Adapt the reference to your reality.

Is that what you want?
I hope it helps.
 
Upvote 0
Hi,

You could test following formula in cell C12 :

=SUMPRODUCT(('Job Setup'!$C$70:$C$79='DR LIST'!$B12)*('Job Setup'!$A$70:$A$79='DR LIST'!$B$10)*('Job Setup'!D70:D79))

You can adjust the ranges to your needs ...

HTH
 
Upvote 0
@marcilio This worked perfectly! After changing the references I believe this will do exactly what I want it to! Thank you!
 
Last edited:
Upvote 0
danielrussell2,

Thanks for the feedback.

Glad to have helped.

Have a nice day!

................................................................
Marcílio Lobão
Belo Horizonte, MG - Brazil
 
Upvote 0

Forum statistics

Threads
1,214,979
Messages
6,122,550
Members
449,088
Latest member
davidcom

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