Formula to search for most previous match?

marteds

New Member
Joined
Aug 5, 2019
Messages
5
I'm setting up a spreadsheet to display monitoring data in the form of X, Y and Z coordinates.

I want to be able to show the relative and cumulative differences between measurements.
The formula for the relative difference is just comparing it to the cell above, whilst the cumulative is comparing the baseline value.

In the attached image, I would like to be able to use a formula to be able to search and compare to most recent reading with coordinates rather than just the blank cells above it.

Keeping in mind that this spreadsheet is going to be populated on an ongoing basis so hard coding formulas won't work.


qCTUueu
QG9tCVG
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
Hi,

F2 formula copied across to H2, and down as far as needed:


Book1
CDEFGH
1XYZrel. Xrel. Yrel. Z
2100.000500.000200.000 
3100.001500.002200.0000.0010.0020.000
4100.002500.003200.0030.0010.0010.003
5
6
7100.003500.004200.0020.0010.001-0.001
Sheet707
Cell Formulas
RangeFormula
F2=IFERROR(IF(C2="","",C2-LOOKUP(9.99999999999999E+307,C$1:C1)),"")
 
Upvote 0
This worked a treat!
Thanks mate!


Hi,

F2 formula copied across to H2, and down as far as needed:

CDEFGH
XYZrel. Xrel. Yrel. Z

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
[TD="align: center"]1[/TD]

[TD="align: center"]2[/TD]
[TD="align: right"]100.000[/TD]
[TD="align: right"]500.000[/TD]
[TD="align: right"]200.000[/TD]

[TD="align: center"]3[/TD]
[TD="align: right"]100.001[/TD]
[TD="align: right"]500.002[/TD]
[TD="align: right"]200.000[/TD]
[TD="align: right"]0.001[/TD]
[TD="align: right"]0.002[/TD]
[TD="align: right"]0.000[/TD]

[TD="align: center"]4[/TD]
[TD="align: right"]100.002[/TD]
[TD="align: right"]500.003[/TD]
[TD="align: right"]200.003[/TD]
[TD="align: right"]0.001[/TD]
[TD="align: right"]0.001[/TD]
[TD="align: right"]0.003[/TD]

[TD="align: center"]5[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]6[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]7[/TD]
[TD="align: right"]100.003[/TD]
[TD="align: right"]500.004[/TD]
[TD="align: right"]200.002[/TD]
[TD="align: right"]0.001[/TD]
[TD="align: right"]0.001[/TD]
[TD="align: right"]-0.001[/TD]

</tbody>
Sheet707

[TABLE="width: 85%"]
<tbody>[TR]
[TD]Worksheet Formulas[TABLE="width: 100%"]
<thead>[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]
[TH="width: 10px"]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
</thead><tbody>[TR]
[TH="width: 10px, bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]F2[/TH]
[TD="align: left"]=IFERROR(IF(C2="","",C2-LOOKUP(9.99999999999999E+307,C$1:C1)),"")[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
Okay so I wanted to expand on the sheet a bit more and will be having multiple points that I would be analyzing, how would you apply the lookup formula for a scenario like this?

VbeXurC.jpg
 
Upvote 0

Forum statistics

Threads
1,223,886
Messages
6,175,196
Members
452,616
Latest member
intern444

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