Matching criteria in different rows

pxtan2

New Member
Joined
Apr 4, 2014
Messages
11
Hi everyone, I have two worksheets (A & B). I would like a formula/macros to lookup B, find the value in row n, and return it in A. I have provided examples in A (column 3) on what values should be obtained.

Worksheet A

UnitActivity NumberValue

1012222#N/A
1014444300
1025555#N/A
1037777#N/A

<colgroup><col><col><col></colgroup><tbody>
</tbody>

Worksheet B


Unit


Activity NumberActivityIn/OutPositionValue
1011111CloseInTom100
1011111OpenInTom100
1012222CloseIn10200
1012222OpenIn10200
1013333CloseInJane300
1013333OpenInJane300
1014444CloseOut20400
1014444OpenOut20400
1025555CloseOut30500
1025555OpenOut30500
1036666CloseInHarry600
1036666OpenInHarry600
1037777OpenOut40700
1037777OpenOut40700

<colgroup><col><col span="2"><col span="3"></colgroup><tbody>
</tbody>

As shown, there are specific criteria in Worksheet B that must be fulfilled before the value can be identified:


1. Matching "Activity Number" must be in row n+1.
2. "Activity" in row n must be "Open", while "Close" in row n+1.
3. "Position" in row n must be of non-numeric value.
4. "Unit" in row n must match that in Worksheet A.
5. "In/Out" in row n+1 must be "Out"

I would welcome any help! Thanks so much in advance!
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Assuming you have data like this:


Unknown
ABCDEF
1UnitActivity NumberActivityIn/OutPositionValue
2
31011111CloseInTom100
41011111OpenInTom100
51012222CloseIn10200
61012222OpenIn10200
71013333CloseInJane300
81013333OpenInJane300
91014444CloseOut20400
101014444OpenOut20400
111025555CloseOut30500
121025555OpenOut30500
131036666CloseInHarry600
141036666OpenInHarry600
151037777OpenOut40700
161037777OpenOut40700
17
Sheet B


<tbody></tbody>


Unknown
ABC
1UnitActivity NumberValue
210122220
31014444300
410255550
510377770
6
Sheet A
Cell Formulas
RangeFormula
C2=SUMPRODUCT(--('Sheet B'!$B$4:$B$17=B2),--('Sheet B'!$C$3:$C$16="Open"),--('Sheet B'!$C$4:$C$17="Close"),--NOT(ISNUMBER('Sheet B'!$E$3:$E$16)),--('Sheet B'!$A$3:$A$16=A2),--('Sheet B'!$D$4:$D$17="Out"),'Sheet B'!$F$3:$F$16)



Copy the formula down.
 
Last edited:
Upvote 0
Another Alternative:


Unknown
ABCDEF
1UnitActivity NumberActivityIn/OutPositionValue
2
31011111CloseInTom100
41011111OpenInTom100
51012222CloseIn10200
61012222OpenIn10200
71013333CloseInJane300
81013333OpenInJane300
91014444CloseOut20400
101014444OpenOut20400
111025555CloseOut30500
121025555OpenOut30500
131036666CloseInHarry600
141036666OpenInHarry600
151037777OpenOut40700
161037777OpenOut40700
17
Sheet B




Unknown
ABC
1UnitActivity NumberValue
21012222#N/A
31014444300
41025555#N/A
51037777#N/A
6
Sheet A
Cell Formulas
RangeFormula
C2=INDEX('Sheet B'!$F$3:$F$16,MATCH(1,('Sheet B'!$B$4:$B$17=B2)*('Sheet B'!$C$3:$C$16="Open")*('Sheet B'!$C$4:$C$17="Close")*(NOT(ISNUMBER('Sheet B'!$E$3:$E$16)))*('Sheet B'!$A$3:$A$16=A2)*('Sheet B'!$D$4:$D$17="Out"),0))
Press CTRL+SHIFT+ENTER to enter array formulas.



Copy the formula down.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,223
Messages
6,123,715
Members
449,118
Latest member
MichealRed

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