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.


 

jtakw

Well-known Member
Joined
Jun 29, 2014
Messages
5,146
Hi,

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

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th><th>H</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style=";">X</td><td style=";">Y</td><td style=";">Z</td><td style=";">rel. X</td><td style=";">rel. Y</td><td style=";">rel. Z</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style="text-align: right;;">100.000</td><td style="text-align: right;;">500.000</td><td style="text-align: right;;">200.000</td><td style=";"></td><td style=";"></td><td style=";"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style="text-align: right;;">100.001</td><td style="text-align: right;;">500.002</td><td style="text-align: right;;">200.000</td><td style="text-align: right;;">0.001</td><td style="text-align: right;;">0.002</td><td style="text-align: right;;">0.000</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style="text-align: right;;">100.002</td><td style="text-align: right;;">500.003</td><td style="text-align: right;;">200.003</td><td style="text-align: right;;">0.001</td><td style="text-align: right;;">0.001</td><td style="text-align: right;;">0.003</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">5</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style=";"></td><td style=";"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style=";"></td><td style=";"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">7</td><td style="text-align: right;;">100.003</td><td style="text-align: right;;">500.004</td><td style="text-align: right;;">200.002</td><td style="text-align: right;;">0.001</td><td style="text-align: right;;">0.001</td><td style="text-align: right;;">-0.001</td></tr></tbody></table><p style="width:6.4em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet707</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">F2</th><td style="text-align:left">=IFERROR(<font color="Blue">IF(<font color="Red">C2="","",C2-LOOKUP(<font color="Green">9.99999999999999E+307,C$1:C1</font>)</font>),""</font>)</td></tr></tbody></table></td></tr></table><br />
 

marteds

New Member
Joined
Aug 5, 2019
Messages
5
This worked a treat!
Thanks mate!


Hi,

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

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

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet707

Worksheet Formulas
CellFormula
F2=IFERROR(IF(C2="","",C2-LOOKUP(9.99999999999999E+307,C$1:C1)),"")

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>
 

marteds

New Member
Joined
Aug 5, 2019
Messages
5
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?

 

Forum statistics

Threads
1,077,856
Messages
5,336,800
Members
399,103
Latest member
PX04

Some videos you may like

This Week's Hot Topics

Top