If cancelled retrieve data from the next row down

RSnap3232

New Member
Joined
Nov 20, 2020
Messages
43
Office Version
  1. 2016
  2. 2013
Platform
  1. Windows
Hello All,

is there a way to do something like a vlookup based on whether an order has been cancelled;
Ie; tab 1 has a checklist to ensure we have everything in reference to an order number that gets pulled from the second tab but if an order number is cancelled it can be used again at a later date therefore the information that needs to get pulled is from the live order not the cancelled.

order number will be in column A in both tabs, whether an order is live or cancelled will be in column B on the second tab and we need data to be filled from column C in tab 2 into the 1st tab, is it possible as I know Vlookup will only check the one closest to the top i have tried to add some IF statements but not getting anywhere.

any help will be appreciated thank you
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
Hi Rsnap3232,

VLOOKUP won't work with multiple criteria unless you add a work column. You'd do better using INDEX/MATCH/INDEX or INDEX/AGGREGATE.

RSnap3232-2.xlsx
ABHIJK
1OrderValueTab2 OrdersValueStatus
2X00299X00122Complete
3X00244Cancelled
4X00366WIP
5X00488WIP
6X00299WIP
7
Sheet1
Cell Formulas
RangeFormula
B2B2=INDEX($J$2:$J$9999,MATCH(1,INDEX((A2=$I$2:$I$9999)*($K$2:$K$9999<>"Cancelled"),),0))
 
Upvote 0
Solution

Forum statistics

Threads
1,213,501
Messages
6,114,010
Members
448,543
Latest member
MartinLarkin

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