Index/Match to determine closest coordinates?

drogers

New Member
Joined
Mar 1, 2011
Messages
2
I have a data set that has four columns (i,j,Latitude,Longitude). The i and j represent a grid location on a grid overlaid onto a map projection. Can I use the index function to give me the i and j values for a particular latitude and longitude that I input?
What happens if the Lat/Long coordinates I input are close to but not exactly the same as those in the list? For example what happens the lat/long input happens to be in the middle of a grid point?

The data I am using can be found at http://www.meteo.gc.ca/grib/30kmgridpoints_e.html

Thanks for any help!
 

Excel Facts

What is the shortcut key for Format Selection?
Ctrl+1 (the number one) will open the Format dialog for whatever is selected.
This is what I was able to come up with.

Note: The table must be sorted with Latitude (Ascending) and then by Longitute (Ascending).

The returned values may not be perfect to what you need, but at least it will get you close.

<b>Excel 2003</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</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: #161120;text-align: center;">1</td><td style=";">ni</td><td style=";">nj</td><td style=";">Latitude</td><td style=";">Longitude</td><td style="text-align: right;;"></td><td style=";">Latitude</td><td style="text-align: right;;">24.8</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">247</td><td style="text-align: right;;">1</td><td style="text-align: right;;">24.5363</td><td style="text-align: right;;">-72.3753</td><td style="text-align: right;;"></td><td style=";">Longitude</td><td style="text-align: right;;">-72.71</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">246</td><td style="text-align: right;;">1</td><td style="text-align: right;;">24.6639</td><td style="text-align: right;;">-72.5515</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;">247</td><td style="text-align: right;;">2</td><td style="text-align: right;;">24.6961</td><td style="text-align: right;;">-72.2345</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;">245</td><td style="text-align: right;;">1</td><td style="text-align: right;;">24.7911</td><td style="text-align: right;;">-72.7285</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;">246</td><td style="text-align: right;;">2</td><td style="text-align: right;;">24.8243</td><td style="text-align: right;;">-72.4108</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Both values below</td><td style=";">At least one value larger</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: right;;">247</td><td style="text-align: right;;">3</td><td style="text-align: right;;">24.856</td><td style="text-align: right;;">-72.0928</td><td style="text-align: right;;"></td><td style=";">ni</td><td style="text-align: right;;">245</td><td style="text-align: right;;">246</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: right;;">244</td><td style="text-align: right;;">1</td><td style="text-align: right;;">24.9181</td><td style="text-align: right;;">-72.9064</td><td style="text-align: right;;"></td><td style=";">nj</td><td style="text-align: right;;">1</td><td style="text-align: right;;">2</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: right;;">245</td><td style="text-align: right;;">2</td><td style="text-align: right;;">24.9522</td><td style="text-align: right;;">-72.5881</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: right;;">246</td><td style="text-align: right;;">3</td><td style="text-align: right;;">24.9848</td><td style="text-align: right;;">-72.2693</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: right;;">247</td><td style="text-align: right;;">4</td><td style="text-align: right;;">25.0157</td><td style="text-align: right;;">-71.9502</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: right;;">243</td><td style="text-align: right;;">1</td><td style="text-align: right;;">25.0447</td><td style="text-align: right;;">-73.0852</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="text-align: right;;">244</td><td style="text-align: right;;">2</td><td style="text-align: right;;">25.0798</td><td style="text-align: right;;">-72.7662</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style="text-align: right;;">245</td><td style="text-align: right;;">3</td><td style="text-align: right;;">25.1133</td><td style="text-align: right;;">-72.4468</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style="text-align: right;;">246</td><td style="text-align: right;;">4</td><td style="text-align: right;;">25.1452</td><td style="text-align: right;;">-72.1269</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">16</td><td style="text-align: right;;">242</td><td style="text-align: right;;">1</td><td style="text-align: right;;">25.171</td><td style="text-align: right;;">-73.2648</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">17</td><td style="text-align: right;;">247</td><td style="text-align: right;;">5</td><td style="text-align: right;;">25.1755</td><td style="text-align: right;;">-71.8067</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">18</td><td style="text-align: right;;">243</td><td style="text-align: right;;">2</td><td style="text-align: right;;">25.207</td><td style="text-align: right;;">-72.9452</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">19</td><td style="text-align: right;;">244</td><td style="text-align: right;;">3</td><td style="text-align: right;;">25.2415</td><td style="text-align: right;;">-72.6251</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">20</td><td style="text-align: right;;">245</td><td style="text-align: right;;">4</td><td style="text-align: right;;">25.2743</td><td style="text-align: right;;">-72.3046</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr></tbody></table><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style="background-color: #E0E0F0;text-align: center;color: #161120"><th><b>Sheet3</b></th></tr></td></thead></table><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><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: #E0E0F0;color: #161120">G7</th><td style="text-align:left">{=INDEX(<font color="Blue">A2:A49401,MATCH(<font color="Red">9.99E+307,IF(<font color="Green">C2:C49401<G1,IF(<font color="Purple">D2:D49401<G2,1,""</font>)</font>)</font>)</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">H7</th><td style="text-align:left">{=OFFSET(<font color="Blue">INDEX(<font color="Red">A2:A49401,MATCH(<font color="Green">1,IF(<font color="Purple">A2:A49401=G7,IF(<font color="Teal">B2:B49401=G8,1,""</font>)</font>),0</font>)</font>),1,0</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G8</th><td style="text-align:left">{=INDEX(<font color="Blue">B2:B49401,MATCH(<font color="Red">9.99E+307,IF(<font color="Green">C2:C49401<G1,IF(<font color="Purple">D2:D49401<G2,1,""</font>)</font>)</font>)</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">H8</th><td style="text-align:left">{=OFFSET(<font color="Blue">INDEX(<font color="Red">B2:B49401,MATCH(<font color="Green">1,IF(<font color="Purple">A2:A49401=G7,IF(<font color="Teal">B2:B49401=G8,1,""</font>)</font>),0</font>)</font>),1,0</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />
 
Upvote 0

Forum statistics

Threads
1,224,525
Messages
6,179,317
Members
452,905
Latest member
deadwings

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