Index, row and match on validation

rex759

Well-known Member
Joined
Nov 8, 2004
Messages
608
Office Version
  1. 365
Platform
  1. Windows
Hello,
My goal is to show the IDs in column C if:

The IDs in Column E, have a corresponding date in Column D that matches Cell C3. My formula does that but I want to add a kind of validation so only the IDs appearing in Column C has a match in Column G.

In my example below, 1234 should not appear in column C because its missing from Column G. Cell C5 should be blank.

Any help is appreciated
Excel Workbook
ABCDEFGH
1
2DateDateIDApproved List
312/1/1712/1/171111333
41111112/1/1712342222
52123412/2/1722221111
6333312/1/17333
7
Sheet1
Excel 2010
#VALUE!
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
Try

Array formula in C4 copied down
=IFERROR(INDEX(E$3:E$6,SMALL(IF(D$3:D$6=C$3,IF(ISNUMBER(MATCH(E$3:E$6,G$3:G$5,0)),ROW(E$3:E$6)-ROW(E$3)+1)),ROWS(C$4:C4))),"")
Ctrl+Shift+Enter

M.
 
Upvote 0
Try

Array formula in C4 copied down
=IFERROR(INDEX(E$3:E$6,SMALL(IF(D$3:D$6=C$3,IF(ISNUMBER(MATCH(E$3:E$6,G$3:G$5,0)),ROW(E$3:E$6)-ROW(E$3)+1)),ROWS(C$4:C4))),"")
Ctrl+Shift+Enter

M.

Wow! Thats a combination I would have never figured out. Its perfect! Thank you
 
Upvote 0

Forum statistics

Threads
1,215,583
Messages
6,125,661
Members
449,247
Latest member
wingedshoes

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