├── google-sheets-geocoding-macro.gif ├── google-sheets-geocoding-macro-forward.png ├── google-sheets-geocoding-macro-reverse.png ├── README.md └── Code.gs /google-sheets-geocoding-macro.gif: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/subtleGradient/google-sheets-geocoding-macro/master/google-sheets-geocoding-macro.gif -------------------------------------------------------------------------------- /google-sheets-geocoding-macro-forward.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/subtleGradient/google-sheets-geocoding-macro/master/google-sheets-geocoding-macro-forward.png -------------------------------------------------------------------------------- /google-sheets-geocoding-macro-reverse.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/subtleGradient/google-sheets-geocoding-macro/master/google-sheets-geocoding-macro-reverse.png -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Google Sheets Geocoding Macro 2 | 3 | ![How It Works](google-sheets-geocoding-macro.gif) 4 | 5 | Geocode from addresses to latitude / longitude, and vice versa using Google Sheets. 6 | 7 | ## Test Sheet 8 | 9 | Try the macro out on a [Test Sheet](https://docs.google.com/spreadsheets/d/1PZGulsMOTAjJxjPDzMrkunTCXQlFYOga50m3ZouzxHg/edit?usp=sharing) with sample address data. 10 | 11 | ## Google Sheets Add-On 12 | 13 | Coming soon, it's currently Pending Review. If it's accepted, it will be available as an Add-On for all of your Sheets. Until then, you've got to add it to each sheet you are using. 14 | 15 | ## Multicolumn Addresses → Latitude, Longitude 16 | 17 | Now it supports geocoding using address data spread across multiple columns. 18 | 19 | The way this works is: You select a set of columns containing the data, and the geocoding process puts the latitude, longitude data in the rightmost two columns. It will overwrite any data in those two columns. 20 | 21 | Some care is needed, as it will concatenate all columns except the rightmost two columns to create the address string. 22 | 23 | ![Multicolumn Address Geocoding](google-sheets-geocoding-macro-forward.png) 24 | 25 | ## Latitude, Longitude → Nearest Address 26 | 27 | It also supports reverse geocoding. 28 | 29 | Simply select the latitude, longitude columns and it will place the nearest address data in the rightmost column. It will overwrite any data in that column. 30 | 31 | Less care is needed, as it will automatically use the leftmost two columns as the latitude, longitude pair. 32 | 33 | ![Reverse Geocoding](google-sheets-geocoding-macro-reverse.png) 34 | -------------------------------------------------------------------------------- /Code.gs: -------------------------------------------------------------------------------- 1 | // Geocode Addresses 2 | // Copyright (c) 2016 - 2017 Max Vilimpoc 3 | // 4 | // Permission is hereby granted, free of charge, to any person obtaining a copy 5 | // of this software and associated documentation files (the "Software"), to deal 6 | // in the Software without restriction, including without limitation the rights 7 | // to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 8 | // copies of the Software, and to permit persons to whom the Software is 9 | // furnished to do so, subject to the following conditions: 10 | // 11 | // The above copyright notice and this permission notice shall be included in 12 | // all copies or substantial portions of the Software. 13 | // 14 | // THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 15 | // IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 16 | // FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 17 | // AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 18 | // LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 19 | // OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN 20 | // THE SOFTWARE. 21 | 22 | // Bias the geocoding results in favor of these geographic regions. 23 | // The regions are specified as ccTLD codes. 24 | // 25 | // See: https://en.wikipedia.org/wiki/Country_code_top-level_domain 26 | // 27 | // Used: 28 | // https://mbrownnyc.wordpress.com/misc/iso-3166-cctld-csv/ 29 | // http://www.convertcsv.com/csv-to-json.htm 30 | // to generate the functions for menu item handling. 31 | /* 32 | var REGIONS = { 33 | "Afghanistan": "af", 34 | "Aland Islands": "ax", 35 | "Albania": "al", 36 | "Algeria": "dz", 37 | "American Samoa": "as", 38 | "Andorra": "ad", 39 | "Angola": "ao", 40 | "Anguilla": "ai", 41 | "Antarctica": "aq", 42 | "Antigua and Barbuda": "ag", 43 | "Argentina": "ar", 44 | "Armenia": "am", 45 | "Aruba": "aw", 46 | "Ascension Island": "ac", 47 | "Australia": "au", 48 | "Austria": "at", 49 | "Azerbaijan": "az", 50 | "Bahamas": "bs", 51 | "Bahrain": "bh", 52 | "Bangladesh": "bd", 53 | "Barbados": "bb", 54 | "Belarus": "by", 55 | "Belgium": "be", 56 | "Belize": "bz", 57 | "Benin": "bj", 58 | "Bermuda": "bm", 59 | "Bhutan": "bt", 60 | "Bolivia": "bo", 61 | "Bosnia and Herzegovina": "ba", 62 | "Botswana": "bw", 63 | "Bouvet Island": "bv", 64 | "Brazil": "br", 65 | "British Indian Ocean Territory": "io", 66 | "Brunei Darussalam": "bn", 67 | "Bulgaria": "bg", 68 | "Burkina Faso": "bf", 69 | "Burundi": "bi", 70 | "Cambodia": "kh", 71 | "Cameroon": "cm", 72 | "Canada": "ca", 73 | "Cape Verde": "cv", 74 | "Cayman Islands": "ky", 75 | "Central African Republic": "cf", 76 | "Chad": "td", 77 | "Chile": "cl", 78 | "China": "cn", 79 | "Christmas Island": "cx", 80 | "Cocos (Keeling) Islands": "cc", 81 | "Colombia": "co", 82 | "Comoros": "km", 83 | "Congo": "cg", 84 | "Cook Islands": "ck", 85 | "Costa Rica": "cr", 86 | "Cote d'Ivoire": "ci", 87 | "Croatia": "hr", 88 | "Cuba": "cu", 89 | "Cyprus": "cy", 90 | "Czech Republic": "cz", 91 | "Democratic People's Republic of Korea (North Korea)": "kp", 92 | "Denmark": "dk", 93 | "Djibouti": "dj", 94 | "Dominica": "dm", 95 | "Dominican Republic": "do", 96 | "Ecuador": "ec", 97 | "Egypt": "eg", 98 | "El Salvador": "sv", 99 | "Equatorial Guinea": "gq", 100 | "Eritrea": "er", 101 | "Estonia": "ee", 102 | "Ethiopia": "et", 103 | "European Union": "eu", 104 | "Falkland Islands (Malvinas)": "fk", 105 | "Faroe Islands": "fo", 106 | "Federated States of Micronesia": "fm", 107 | "Fiji": "fj", 108 | "Finland": "fi", 109 | "France": "fr", 110 | "French Guiana": "gf", 111 | "French Polynesia": "pf", 112 | "French Southern Territories": "tf", 113 | "Gabon": "ga", 114 | "Gambia": "gm", 115 | "Georgia": "ge", 116 | "Germany": "de", 117 | "Ghana": "gh", 118 | "Gibraltar": "gi", 119 | "Greece": "gr", 120 | "Greenland": "gl", 121 | "Grenada": "gd", 122 | "Guadeloupe": "gp", 123 | "Guam": "gu", 124 | "Guatemala": "gt", 125 | "Guernsey": "gg", 126 | "Guinea": "gn", 127 | "Guinea-Bissau": "gw", 128 | "Guyana": "gy", 129 | "Haiti": "ht", 130 | "Heard Island and McDonald Islands": "hm", 131 | "Holy See (Vatican City State)": "va", 132 | "Honduras": "hn", 133 | "Hong Kong": "hk", 134 | "Hungary": "hu", 135 | "Iceland": "is", 136 | "India": "in", 137 | "Indonesia": "id", 138 | "Iraq": "iq", 139 | "Ireland": "ie", 140 | "Islamic Republic of Iran": "ir", 141 | "Isle of Man": "im", 142 | "Israel": "il", 143 | "Italy": "it", 144 | "Jamaica": "jm", 145 | "Japan": "jp", 146 | "Jersey": "je", 147 | "Jordan": "jo", 148 | "Kazakhstan": "kz", 149 | "Kenya": "ke", 150 | "Kiribati": "ki", 151 | "Kuwait": "kw", 152 | "Kyrgyzstan": "kg", 153 | "Lao People's Democratic Republic": "la", 154 | "Latvia": "lv", 155 | "Lebanon": "lb", 156 | "Lesotho": "ls", 157 | "Liberia": "lr", 158 | "Libyan Arab Jamahiriya": "ly", 159 | "Liechtenstein": "li", 160 | "Lithuania": "lt", 161 | "Luxembourg": "lu", 162 | "Macao": "mo", 163 | "Madagascar": "mg", 164 | "Malawi": "mw", 165 | "Malaysia": "my", 166 | "Maldives": "mv", 167 | "Mali": "ml", 168 | "Malta": "mt", 169 | "Marshall Islands": "mh", 170 | "Martinique": "mq", 171 | "Mauritania": "mr", 172 | "Mauritius": "mu", 173 | "Mayotte": "yt", 174 | "Mexico": "mx", 175 | "Moldova": "md", 176 | "Monaco": "mc", 177 | "Mongolia": "mn", 178 | "Montenegro": "me", 179 | "Montserrat": "ms", 180 | "Morocco": "ma", 181 | "Mozambique": "mz", 182 | "Myanmar": "mm", 183 | "Namibia": "na", 184 | "Nauru": "nr", 185 | "Nepal": "np", 186 | "Netherlands": "nl", 187 | "Netherlands Antilles": "an", 188 | "New Caledonia": "nc", 189 | "New Zealand": "nz", 190 | "Nicaragua": "ni", 191 | "Niger": "ne", 192 | "Nigeria": "ng", 193 | "Niue": "nu", 194 | "Norfolk Island": "nf", 195 | "Northern Mariana Islands": "mp", 196 | "Norway": "no", 197 | "Oman": "om", 198 | "Pakistan": "pk", 199 | "Palau": "pw", 200 | "Palestinian Territory (occupied)": "ps", 201 | "Panama": "pa", 202 | "Papua New Guinea": "pg", 203 | "Paraguay": "py", 204 | "Peru": "pe", 205 | "Philippines": "ph", 206 | "Pitcairn": "pn", 207 | "Poland": "pl", 208 | "Portugal": "pt", 209 | "Portuguese Timor": "tp", 210 | "Puerto Rico": "pr", 211 | "Qatar": "qa", 212 | "Republic of Korea (South Korea)": "kr", 213 | "Reunion": "re", 214 | "Romania": "ro", 215 | "Russian Federation": "ru", 216 | "Rwanda": "rw", 217 | "Saint Barthelemy": "bl", 218 | "Saint Helena": "sh", 219 | "Saint Kitts and Nevis": "kn", 220 | "Saint Lucia": "lc", 221 | "Saint Martin": "mf", 222 | "Saint Pierre and Miquelon": "pm", 223 | "Saint Vincent and the Grenadines": "vc", 224 | "Samoa": "ws", 225 | "San Marino": "sm", 226 | "Sao Tome and Principe": "st", 227 | "Saudi Arabia": "sa", 228 | "Senegal": "sn", 229 | "Serbia": "rs", 230 | "Seychelles": "sc", 231 | "Sierra Leone": "sl", 232 | "Singapore": "sg", 233 | "Slovakia": "sk", 234 | "Slovenia": "si", 235 | "Solomon Islands": "sb", 236 | "Somalia": "so", 237 | "South Africa": "za", 238 | "South Georgia and the South Sandwich Islands": "gs", 239 | "Soviet Union": "su", 240 | "Spain": "es", 241 | "Sri Lanka": "lk", 242 | "Sudan": "sd", 243 | "Suriname": "sr", 244 | "Svalbard and Jan Mayen": "sj", 245 | "Swaziland": "sz", 246 | "Sweden": "se", 247 | "Switzerland": "ch", 248 | "Syrian Arab Republic": "sy", 249 | "Taiwan": "tw", 250 | "Tajikistan": "tj", 251 | "Thailand": "th", 252 | "The Democratic Republic of the Congo": "cd", 253 | "The Former Yugoslav Republic of Macedonia": "mk", 254 | "Timor-Leste": "tl", 255 | "Togo": "tg", 256 | "Tokelau": "tk", 257 | "Tonga": "to", 258 | "Trinidad and Tobago": "tt", 259 | "Tunisia": "tn", 260 | "Turkey": "tr", 261 | "Turkmenistan": "tm", 262 | "Turks and Caicos Islands": "tc", 263 | "Tuvalu": "tv", 264 | "Uganda": "ug", 265 | "Ukraine": "ua", 266 | "United Arab Emirates": "ae", 267 | "United Kingdom": "uk", 268 | "United Kingdom": "gb", 269 | "United Republic of Tanzania ": "tz", 270 | "United States": "us", 271 | "United States Minor Outlying Islands": "um", 272 | "Uruguay": "uy", 273 | "Uzbekistan": "uz", 274 | "Vanuatu": "vu", 275 | "Venezuela": "ve", 276 | "Viet Nam": "vn", 277 | "Virgin Islands British": "vg", 278 | "Virgin Islands US": "vi", 279 | "Wallis and Futuna": "wf", 280 | "Western Sahara": "eh", 281 | "Yemen": "ye", 282 | "Yugoslavia": "yu", 283 | "Zambia": "zm", 284 | "Zimbabwe": "zw" 285 | }; 286 | */ 287 | 288 | function getGeocodingRegion() { 289 | return PropertiesService.getDocumentProperties().getProperty('GEOCODING_REGION') || 'us'; 290 | } 291 | 292 | /* 293 | function setGeocodingRegion(region) { 294 | PropertiesService.getDocumentProperties().setProperty('GEOCODING_REGION', region); 295 | updateMenu(); 296 | } 297 | 298 | function promptForGeocodingRegion() { 299 | var ui = SpreadsheetApp.getUi(); 300 | 301 | var result = ui.prompt( 302 | 'Set the Geocoding Country Code (currently: ' + getGeocodingRegion() + ')', 303 | 'Enter the 2-letter country code (ccTLD) that you would like ' + 304 | 'the Google geocoder to search first for results. ' + 305 | 'For example: Use \'uk\' for the United Kingdom, \'us\' for the United States, etc. ' + 306 | 'For more country codes, see: https://en.wikipedia.org/wiki/Country_code_top-level_domain', 307 | ui.ButtonSet.OK_CANCEL 308 | ); 309 | 310 | // Process the user's response. 311 | if (result.getSelectedButton() == ui.Button.OK) { 312 | setGeocodingRegion(result.getResponseText()); 313 | } 314 | } 315 | */ 316 | 317 | // Forward Geocoding -- convert address to GPS position. 318 | function addressToPosition() { 319 | var sheet = SpreadsheetApp.getActiveSheet(); 320 | var cells = sheet.getActiveRange(); 321 | 322 | var popup = SpreadsheetApp.getUi(); 323 | 324 | // Must have selected at least 3 columns (Address, Lat, Lng). 325 | // Must have selected at least 1 row. 326 | 327 | var columnCount = cells.getNumColumns(); 328 | 329 | if (columnCount < 3) { 330 | popup.alert("Select at least 3 columns: Address in the leftmost column(s); the geocoded Latitude, Longitude will go into the last 2 columns."); 331 | return; 332 | } 333 | 334 | var addressRow; 335 | 336 | // var addressColumnStart = 1; // Address data is in columns [1 .. columnCount - 2]. 337 | // var addressColumnStop = columnCount - 2; 338 | 339 | var addressColumn; 340 | 341 | var latColumn = columnCount - 1; // Latitude goes into the next-to-last column. 342 | var lngColumn = columnCount; // Longitude goes into the last column. 343 | 344 | var geocoder = Maps.newGeocoder().setRegion(getGeocodingRegion()); 345 | var location; 346 | 347 | // For each row of selected data... 348 | for (addressRow = 1; addressRow <= cells.getNumRows(); ++addressRow) { 349 | var address = ''; // Start with an empty String. 350 | var part = ''; // Part of the address to be concatenated. 351 | 352 | // Address data is in columns [1 .. columnCount - 2]. 353 | for (addressColumn = 1; addressColumn <= columnCount - 2; addressColumn++) { 354 | part = cells.getCell(addressRow, addressColumn).getValue(); 355 | 356 | if (part) { 357 | address += ' '; 358 | address += part; 359 | } 360 | } 361 | 362 | // Replace problem characters. 363 | address = address.replace(/'/g, "%27"); 364 | 365 | Logger.log(address); 366 | 367 | // Geocode the address and plug the lat, lng pair into the 368 | // last 2 elements of the current range row. 369 | location = geocoder.geocode(address); 370 | 371 | // Only change cells if geocoder seems to have gotten a 372 | // valid response. 373 | if (location.status == 'OK') { 374 | lat = location["results"][0]["geometry"]["location"]["lat"]; 375 | lng = location["results"][0]["geometry"]["location"]["lng"]; 376 | 377 | cells.getCell(addressRow, latColumn).setValue(lat); 378 | cells.getCell(addressRow, lngColumn).setValue(lng); 379 | } 380 | } 381 | }; 382 | 383 | // Reverse Geocode -- GPS position to nearest address. 384 | function positionToAddress() { 385 | var sheet = SpreadsheetApp.getActiveSheet(); 386 | var cells = sheet.getActiveRange(); 387 | 388 | var popup = SpreadsheetApp.getUi(); 389 | 390 | // Must have selected at least 3 columns (Address, Lat, Lng). 391 | // Must have selected at least 1 row. 392 | 393 | var columnCount = cells.getNumColumns(); 394 | 395 | if (columnCount < 3) { 396 | popup.alert("Select at least 3 columns: Latitude, Longitude in the first 2 columns; the reverse-geocoded Address will go into the last column."); 397 | return; 398 | } 399 | 400 | var latColumn = 1; 401 | var lngColumn = 2; 402 | 403 | var addressRow; 404 | var addressColumn = columnCount; 405 | 406 | var geocoder = Maps.newGeocoder().setRegion(getGeocodingRegion()); 407 | var location; 408 | 409 | for (addressRow = 1; addressRow <= cells.getNumRows(); ++addressRow) { 410 | var lat = cells.getCell(addressRow, latColumn).getValue(); 411 | var lng = cells.getCell(addressRow, lngColumn).getValue(); 412 | 413 | // Geocode the lat, lng pair to an address. 414 | location = geocoder.reverseGeocode(lat, lng); 415 | 416 | // Only change cells if geocoder seems to have gotten a 417 | // valid response. 418 | Logger.log(location.status); 419 | if (location.status == 'OK') { 420 | var address = location["results"][0]["formatted_address"]; 421 | 422 | cells.getCell(addressRow, addressColumn).setValue(address); 423 | } 424 | } 425 | }; 426 | 427 | function generateMenu() { 428 | // var setGeocodingRegionMenuItem = 'Set Geocoding Region (Currently: ' + getGeocodingRegion() + ')'; 429 | 430 | // { 431 | // name: setGeocodingRegionMenuItem, 432 | // functionName: "promptForGeocodingRegion" 433 | // }, 434 | 435 | var entries = [{ 436 | name: "Geocode Selected Cells (Address to Latitude, Longitude)", 437 | functionName: "addressToPosition" 438 | }, 439 | { 440 | name: "Geocode Selected Cells (Latitude, Longitude to Address)", 441 | functionName: "positionToAddress" 442 | }]; 443 | 444 | return entries; 445 | } 446 | 447 | function updateMenu() { 448 | SpreadsheetApp.getActiveSpreadsheet().updateMenu('Geocode', generateMenu()) 449 | } 450 | 451 | /** 452 | * Adds a custom menu to the active spreadsheet, containing a single menu item 453 | * for invoking the readRows() function specified above. 454 | * The onOpen() function, when defined, is automatically invoked whenever the 455 | * spreadsheet is opened. 456 | * 457 | * For more information on using the Spreadsheet API, see 458 | * https://developers.google.com/apps-script/service_spreadsheet 459 | */ 460 | function onOpen() { 461 | SpreadsheetApp.getActiveSpreadsheet().addMenu('Geocode', generateMenu()); 462 | // SpreadsheetApp.getActiveSpreadsheet().addMenu('Region', generateRegionMenu()); 463 | // SpreadsheetApp.getUi() 464 | // .createMenu(); 465 | }; 466 | --------------------------------------------------------------------------------