├── geocode-details.png ├── google-sheets-geocoder-census-google.gif ├── google-sheets-geocoder-census-geographies.gif ├── .github └── FUNDING.yml ├── geocoder-census-geographies.gs ├── README.md ├── geocoder-census-google.gs └── geocoder-mapzen-testing.gs /geocode-details.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HandsOnDataViz/google-sheets-geocoder/HEAD/geocode-details.png -------------------------------------------------------------------------------- /google-sheets-geocoder-census-google.gif: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HandsOnDataViz/google-sheets-geocoder/HEAD/google-sheets-geocoder-census-google.gif -------------------------------------------------------------------------------- /google-sheets-geocoder-census-geographies.gif: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HandsOnDataViz/google-sheets-geocoder/HEAD/google-sheets-geocoder-census-geographies.gif -------------------------------------------------------------------------------- /.github/FUNDING.yml: -------------------------------------------------------------------------------- 1 | # These are supported funding model platforms 2 | 3 | github: [handsondataviz]# Replace with up to 4 GitHub Sponsors-enabled usernames e.g., [user1, user2] 4 | patreon: # Replace with a single Patreon username 5 | open_collective: # Replace with a single Open Collective username 6 | ko_fi: # Replace with a single Ko-fi username 7 | tidelift: # Replace with a single Tidelift platform-name/package-name e.g., npm/babel 8 | community_bridge: # Replace with a single Community Bridge project-name e.g., cloud-foundry 9 | liberapay: # Replace with a single Liberapay username 10 | issuehunt: # Replace with a single IssueHunt username 11 | otechie: # Replace with a single Otechie username 12 | custom: # Replace with up to 4 custom sponsorship URLs e.g., ['link1', 'link2'] 13 | -------------------------------------------------------------------------------- /geocoder-census-geographies.gs: -------------------------------------------------------------------------------- 1 | var ui = SpreadsheetApp.getUi(); 2 | 3 | var addressColumn = 1; 4 | var latColumn = 2; 5 | var lngColumn = 3; 6 | var foundAddressColumn = 4; 7 | var qualityColumn = 5; 8 | var sourceColumn = 6; 9 | var geoIdColumn = 7; 10 | var tractColumn = 8; 11 | 12 | /** 13 | * Use US Census geocoder 14 | */ 15 | function geocode() { 16 | var sheet = SpreadsheetApp.getActiveSheet(); 17 | var cells = sheet.getActiveRange(); 18 | 19 | if (cells.getNumColumns() != 8) { 20 | ui.alert( 21 | 'Warning', 22 | 'You must select 8 columns: Location, Latitude, Longitude, Found, Quality, Source, GeoID, Tract', 23 | ui.ButtonSet.OK 24 | ); 25 | return; 26 | } 27 | 28 | var nAll = 0; 29 | var nFailure = 0; 30 | var quality; 31 | var printComplete = true; 32 | 33 | for (addressRow = 1; addressRow <= cells.getNumRows(); addressRow++) { 34 | var address = cells.getCell(addressRow, addressColumn).getValue(); 35 | 36 | if (!address) {continue} 37 | nAll++; 38 | 39 | nFailure += withUSCensus(cells, addressRow, address); 40 | } 41 | 42 | if (printComplete) { 43 | ui.alert('Completed!', 'Geocoded: ' + (nAll - nFailure) 44 | + '\nFailed: ' + nFailure, ui.ButtonSet.OK); 45 | } 46 | 47 | } 48 | 49 | /** 50 | * Geocoding with US Census Geocoder https://geocoding.geo.census.gov/geocoder/ 51 | */ 52 | function withUSCensus(cells, row, address) { 53 | var url = 'https://geocoding.geo.census.gov/' 54 | + 'geocoder/geographies/onelineaddress?address=' 55 | + encodeURIComponent(address) 56 | + '&vintage=Current_Current' 57 | + '&benchmark=Public_AR_Current' 58 | + '&format=json'; 59 | 60 | var response = JSON.parse(UrlFetchApp.fetch(url)); 61 | var matches = (response.result.addressMatches.length > 0) ? 'Match' : 'No Match'; 62 | 63 | if (matches !== 'Match') { 64 | insertDataIntoSheet(cells, row, [ 65 | [foundAddressColumn, ''], 66 | [latColumn, ''], 67 | [lngColumn, ''], 68 | [qualityColumn, 'No Match'], 69 | [sourceColumn, ''] 70 | ]); 71 | return 1; 72 | } 73 | 74 | var z = response.result.addressMatches[0]; 75 | 76 | var quality; 77 | if (address.toLowerCase().replace(/[,\']/g, '') == 78 | z.matchedAddress.toLowerCase().replace(/[,\']/g, '')) { 79 | quality = 'Exact'; 80 | } else { 81 | quality = 'Match'; 82 | } 83 | 84 | insertDataIntoSheet(cells, row, [ 85 | [foundAddressColumn, z.matchedAddress], 86 | [latColumn, z.coordinates.y], 87 | [lngColumn, z.coordinates.x], 88 | [qualityColumn, quality], 89 | [sourceColumn, 'US Census 2010'], 90 | [geoIdColumn, z.geographies['2010 Census Blocks'][0].GEOID], 91 | [tractColumn, z.geographies['Census Tracts'][0].BASENAME] 92 | ]); 93 | 94 | return 0; 95 | } 96 | 97 | 98 | /** 99 | * Sets cells from a 'row' to values in data 100 | */ 101 | function insertDataIntoSheet(cells, row, data) { 102 | for (d in data) { 103 | cells.getCell(row, data[d][0]).setValue(data[d][1]); 104 | } 105 | } 106 | 107 | function onOpen() { 108 | ui.createMenu('Geocoder') 109 | .addItem('US Census 2010 Geographies', 'geocode') 110 | .addToUi(); 111 | } 112 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Google Sheets Geocoder 2 | Geocode addresses into latitude/longitude coordinates inside Google Sheets, 3 | with US Census or Google Apps service. 4 | 5 | ## UPDATE 6 | To geocode multiple addresses inside your spreadsheet, we now recommend that beginniners install a free Google Sheets Add-on called [Geocoding by SmartMonkey](https://gsuite.google.com/marketplace/app/geocoding_by_smartmonkey/1033231575312), instead of the Google Apps Geocoder script below. 7 | 8 | See geocoding instructions in *Hands-On Data Visualization* chapter 2: https://handsondataviz.org/geocode.html 9 | 10 | ![Geocoding by SmartMonkey screenshot](geocode-details.png) 11 | 12 | 13 | ## Demo Geocoder US Census or Google 14 | - Geocode locations into latitude, longitude, with source and match quality, inside a Google Sheet 15 | - Go to Google Sheet template, sign in to your account, and File > Make a Copy to your Google Drive https://docs.google.com/spreadsheets/d/1XvtkzuVyQ_7Ud47ypDJ4KOmz_5lOpC9sqeEDBbJ5Pbg/edit#gid=0 16 | - Insert locations, select 6 columns, and select Geocoder menu: US Census or Google (limit 1000 daily per user) 17 | - Google Sheets script will ask for permission to run the first time 18 | 19 | ![Screencast](google-sheets-geocoder-census-google.gif) 20 | 21 | ## Demo Geocoder US Census Geographies 22 | - Geocode US addresses into latitude, longitude, GeoID census tract, inside a Google Sheet 23 | - Go to Google Sheet template, sign in to your account, and File > Make a Copy to your Google Drive 24 | https://docs.google.com/spreadsheets/d/1x_E9KwZ88c_kZvhZ13IF7BNwYKTJFxbfDu77sU1vn5w/edit#gid=0 25 | - Insert locations, select 8 columns, and select Geocoder menu: US Census 2010 Geographies 26 | - Google Sheets script will ask for permission to run the first time 27 | 28 | ![Screencast](google-sheets-geocoder-census-geographies.gif) 29 | 30 | #### About 15-character GeoID 31 | - Make sure that column G is formatted as text (to preserve leading zeros), not number 32 | - Break down a sample GeoID: 090035245022001 33 | - state = 09 34 | - county = 003 35 | - tract = 524502 = 5245.02 36 | - block group = 2 37 | - block = 001 38 | 39 | ## How to insert script into any Google Sheet 40 | - Download or fork the Google Sheets scripts (.gs) from this GitHub repo 41 | - Go to your Google Sheets > Tools > Script Editor 42 | - File > Create New Script File 43 | - Copy and paste contents of your preferred script (such as geocoder-census-google.gs) 44 | - Save as Code.gs (or save, then rename to geocoder-census-google.gs) 45 | - Refresh your Google Sheet and look for new Geocoder menu 46 | 47 | ## See also: Batch upload to US Census 48 | - Available at US Census Geocoder https://geocoding.geo.census.gov/geocoder/ 49 | - Upload up to 1000 rows 50 | - Find Locations using > Address Batch (returns latitude, longitude coordinates) 51 | - Find Geographies using > Address Batch (returns lat, lng, census geographies) 52 | - Upload CSV table with up to 1000 rows for faster processing, in this format: 53 | 54 | | AnyID | Street | City | State | Zip | 55 | |:----- |:----- |:--- |:---- |:--- | 56 | | 1 | 300 Summit St | Hartford | CT | 06106 | 57 | 58 | ## Learn more 59 | - **Hands-On Data Visualization** book, see *Transform Your Data* chapter, https://HandsOnDataViz.org/ 60 | 61 | ## Credits 62 | - Developed by [Ilya Ilyankou](https://github.com/ilyankou) and [Jack Dougherty](https://github.com/jackdougherty) with support from Trinity College CT, for [Hands-On Data Visualization](https://HandsOnDataViz.org/) 63 | - Inspired by Google Sheets Geocoding Macro (2016) https://github.com/nuket/google-sheets-geocoding-macro (no license) 64 | - Geocoding services: 65 | - US Census Geocoder https://geocoding.geo.census.gov/geocoder/ 66 | - Geocode with Google Apps: The Maps Service of Google Apps allows users to geocode street addresses without using the Google Maps API, limit 1,000 searches daily per user, https://developers.google.com/apps-script/reference/maps/geocoder 67 | 68 | 69 | 70 | ### Testing 71 | - Geocoder-with-Mapzen.gs -- need to focus search within a country or prioritize area https://mapzen.com/documentation/search/search/#search-within-a-particular-country 72 | -------------------------------------------------------------------------------- /geocoder-census-google.gs: -------------------------------------------------------------------------------- 1 | var ui = SpreadsheetApp.getUi(); 2 | var addressColumn = 1; 3 | var latColumn = 2; 4 | var lngColumn = 3; 5 | var foundAddressColumn = 4; 6 | var qualityColumn = 5; 7 | var sourceColumn = 6; 8 | 9 | googleGeocoder = Maps.newGeocoder().setRegion( 10 | PropertiesService.getDocumentProperties().getProperty('GEOCODING_REGION') || 'us' 11 | ); 12 | 13 | function geocode(source) { 14 | var sheet = SpreadsheetApp.getActiveSheet(); 15 | var cells = sheet.getActiveRange(); 16 | 17 | if (cells.getNumColumns() != 6) { 18 | ui.alert( 19 | 'Warning', 20 | 'You must select 6 columns: Location, Latitude, Longitude, Found, Quality, Source', 21 | ui.ButtonSet.OK 22 | ); 23 | return; 24 | } 25 | 26 | var nAll = 0; 27 | var nFailure = 0; 28 | var quality; 29 | var printComplete = true; 30 | 31 | for (addressRow = 1; addressRow <= cells.getNumRows(); addressRow++) { 32 | var address = cells.getCell(addressRow, addressColumn).getValue(); 33 | 34 | if (!address) {continue} 35 | nAll++; 36 | 37 | if (source == 'US Census') { 38 | nFailure += withUSCensus(cells, addressRow, address); 39 | } else { 40 | nFailure += withGoogle(cells, addressRow, address); 41 | } 42 | } 43 | 44 | if (printComplete) { 45 | ui.alert('Completed!', 'Geocoded: ' + (nAll - nFailure) 46 | + '\nFailed: ' + nFailure, ui.ButtonSet.OK); 47 | } 48 | 49 | } 50 | 51 | /** 52 | * Geocode address with Google Apps https://developers.google.com/apps-script/reference/maps/geocoder 53 | */ 54 | function withGoogle(cells, row, address) { 55 | location = googleGeocoder.geocode(address); 56 | 57 | if (location.status !== 'OK') { 58 | insertDataIntoSheet(cells, row, [ 59 | [foundAddressColumn, ''], 60 | [latColumn, ''], 61 | [lngColumn, ''], 62 | [qualityColumn, 'No Match'], 63 | [sourceColumn, 'Google'] 64 | ]); 65 | 66 | return 1; 67 | } 68 | 69 | lat = location['results'][0]['geometry']['location']['lat']; 70 | lng = location['results'][0]['geometry']['location']['lng']; 71 | foundAddress = location['results'][0]['formatted_address']; 72 | 73 | var quality; 74 | if (location['results'][0]['partial_match']) { 75 | quality = 'Partial Match'; 76 | } else { 77 | quality = 'Match'; 78 | } 79 | 80 | insertDataIntoSheet(cells, row, [ 81 | [foundAddressColumn, foundAddress], 82 | [latColumn, lat], 83 | [lngColumn, lng], 84 | [qualityColumn, quality], 85 | [sourceColumn, 'Google'] 86 | ]); 87 | 88 | return 0; 89 | } 90 | 91 | /** 92 | * Geocoding with US Census Geocoder https://geocoding.geo.census.gov/geocoder/ 93 | */ 94 | function withUSCensus(cells, row, address) { 95 | var url = 'https://geocoding.geo.census.gov/' 96 | + 'geocoder/locations/onelineaddress?address=' 97 | + encodeURIComponent(address) 98 | + '&benchmark=Public_AR_Current&format=json'; 99 | 100 | var response = JSON.parse(UrlFetchApp.fetch(url)); 101 | var matches = (response.result.addressMatches.length > 0) ? 'Match' : 'No Match'; 102 | 103 | if (matches !== 'Match') { 104 | insertDataIntoSheet(cells, row, [ 105 | [foundAddressColumn, ''], 106 | [latColumn, ''], 107 | [lngColumn, ''], 108 | [qualityColumn, 'No Match'], 109 | [sourceColumn, 'US Census'] 110 | ]); 111 | return 1; 112 | } 113 | 114 | var z = response.result.addressMatches[0]; 115 | 116 | var quality; 117 | if (address.toLowerCase().replace(/[,\']/g, '') == 118 | z.matchedAddress.toLowerCase().replace(/[,\']/g, '')) { 119 | quality = 'Exact'; 120 | } else { 121 | quality = 'Match'; 122 | } 123 | 124 | insertDataIntoSheet(cells, row, [ 125 | [foundAddressColumn, z.matchedAddress], 126 | [latColumn, z.coordinates.y], 127 | [lngColumn, z.coordinates.x], 128 | [qualityColumn, quality], 129 | [sourceColumn, 'US Census'] 130 | ]); 131 | 132 | return 0; 133 | } 134 | 135 | 136 | /** 137 | * Sets cells from a 'row' to values in data 138 | */ 139 | function insertDataIntoSheet(cells, row, data) { 140 | for (d in data) { 141 | cells.getCell(row, data[d][0]).setValue(data[d][1]); 142 | } 143 | } 144 | 145 | function censusAddressToPosition() { 146 | geocode('US Census'); 147 | } 148 | 149 | function googleAddressToPosition() { 150 | geocode('Google'); 151 | } 152 | 153 | function onOpen() { 154 | ui.createMenu('Geocoder') 155 | .addItem('with US Census', 'censusAddressToPosition') 156 | .addItem('with Google (limit 1000 per day)', 'googleAddressToPosition') 157 | .addToUi(); 158 | } 159 | -------------------------------------------------------------------------------- /geocoder-mapzen-testing.gs: -------------------------------------------------------------------------------- 1 | var ui = SpreadsheetApp.getUi(); 2 | var addressColumn = 1; 3 | var latColumn = 2; 4 | var lngColumn = 3; 5 | var foundAddressColumn = 4; 6 | var qualityColumn = 5; 7 | var sourceColumn = 6; 8 | 9 | var mapzenKey = ''; 10 | var mapzenSource = ''; 11 | var mapzenRegion = ''; 12 | 13 | googleGeocoder = Maps.newGeocoder().setRegion( 14 | PropertiesService.getDocumentProperties().getProperty('GEOCODING_REGION') || 'us' 15 | ); 16 | 17 | function geocode(source) { 18 | var sheet = SpreadsheetApp.getActiveSheet(); 19 | var cells = sheet.getActiveRange(); 20 | 21 | if (cells.getNumColumns() != 6) { 22 | ui.alert( 23 | 'Warning', 24 | 'You must select 6 columns: Location, Latitude, Longitude, Found, Match Quality, Source', 25 | ui.ButtonSet.OK 26 | ); 27 | return; 28 | } 29 | 30 | var nAll = 0; 31 | var nFailure = 0; 32 | var quality; 33 | var printComplete = true; 34 | 35 | for (addressRow = 1; addressRow <= cells.getNumRows(); addressRow++) { 36 | var address = cells.getCell(addressRow, addressColumn).getValue(); 37 | 38 | if (!address) {continue} 39 | nAll++; 40 | 41 | if (source == 'US Census') { 42 | nFailure += withUSCensus(cells, addressRow, address); 43 | } else if (source == 'Google') { 44 | nFailure += withGoogle(cells, addressRow, address); 45 | } else if (source == 'Mapzen') { 46 | code = withMapzen(cells, addressRow, address); 47 | if (code == 2) { 48 | printComplete = false; 49 | break; 50 | } 51 | nFailure += code; 52 | } 53 | } 54 | 55 | if (printComplete) { 56 | ui.alert('Completed!', 'Geocoded: ' + (nAll - nFailure) 57 | + '\nFailed: ' + nFailure, ui.ButtonSet.OK); 58 | } 59 | 60 | } 61 | 62 | /** 63 | * Geocode address with Google Apps https://developers.google.com/apps-script/reference/maps/geocoder 64 | */ 65 | function withGoogle(cells, row, address) { 66 | location = googleGeocoder.geocode(address); 67 | 68 | if (location.status !== 'OK') { 69 | insertDataIntoSheet(cells, row, [ 70 | [foundAddressColumn, ''], 71 | [latColumn, ''], 72 | [lngColumn, ''], 73 | [qualityColumn, 'No Match'], 74 | [sourceColumn, 'Google'] 75 | ]); 76 | 77 | return 1; 78 | } 79 | 80 | lat = location['results'][0]['geometry']['location']['lat']; 81 | lng = location['results'][0]['geometry']['location']['lng']; 82 | foundAddress = location['results'][0]['formatted_address']; 83 | 84 | var quality; 85 | if (location['results'][0]['partial_match']) { 86 | quality = 'Partial Match'; 87 | } else { 88 | quality = 'Match'; 89 | } 90 | 91 | insertDataIntoSheet(cells, row, [ 92 | [foundAddressColumn, foundAddress], 93 | [latColumn, lat], 94 | [lngColumn, lng], 95 | [qualityColumn, quality], 96 | [sourceColumn, 'Google'] 97 | ]); 98 | 99 | return 0; 100 | } 101 | 102 | /** 103 | * Geocoding with US Census Geocoder https://geocoding.geo.census.gov/geocoder/ 104 | */ 105 | function withUSCensus(cells, row, address) { 106 | var url = 'https://geocoding.geo.census.gov/' 107 | + 'geocoder/locations/onelineaddress?address=' 108 | + encodeURIComponent(address) 109 | + '&benchmark=Public_AR_Current&format=json'; 110 | 111 | var response = JSON.parse(UrlFetchApp.fetch(url)); 112 | var matches = (response.result.addressMatches.length > 0) ? 'Match' : 'No Match'; 113 | 114 | if (matches !== 'Match') { 115 | insertDataIntoSheet(cells, row, [ 116 | [foundAddressColumn, ''], 117 | [latColumn, ''], 118 | [lngColumn, ''], 119 | [qualityColumn, 'No Match'], 120 | [sourceColumn, 'US Census'] 121 | ]); 122 | return 1; 123 | } 124 | 125 | var z = response.result.addressMatches[0]; 126 | 127 | var quality; 128 | if (address.toLowerCase().replace(/[,\']/g, '') == 129 | z.matchedAddress.toLowerCase().replace(/[,\']/g, '')) { 130 | quality = 'Exact'; 131 | } else { 132 | quality = 'Match'; 133 | } 134 | 135 | insertDataIntoSheet(cells, row, [ 136 | [foundAddressColumn, z.matchedAddress], 137 | [latColumn, z.coordinates.y], 138 | [lngColumn, z.coordinates.x], 139 | [qualityColumn, quality], 140 | [sourceColumn, 'US Census'] 141 | ]); 142 | 143 | return 0; 144 | } 145 | 146 | /** 147 | * Geocoding with Mapzen Search https://mapzen.com/documentation/search/search/ 148 | */ 149 | function withMapzen(cells, row, address) { 150 | var url = 'https://search.mapzen.com/v1/search?' 151 | + 'api_key=' + mapzenKey 152 | + '&text=' + encodeURIComponent(address) 153 | + '&sources=' + mapzenSource 154 | + '&size=1'; 155 | 156 | if (mapzenRegion != '') { 157 | url += '&boundary.country=' + mapzenRegion; 158 | } 159 | 160 | var response = JSON.parse(UrlFetchApp.fetch(url, {muteHttpExceptions: true})); 161 | 162 | // If response is an HTTP exception, print it and exit with code 2 so that 163 | // geocoding won't continue 164 | if (response.results) { 165 | if (response.results.error) { 166 | ui.alert('Error', response.results.error.message, ui.ButtonSet.OK); 167 | return 2; 168 | } 169 | } 170 | 171 | if (response.features.length == 0) { 172 | insertDataIntoSheet(cells, row, [ 173 | [foundAddressColumn, ''], 174 | [latColumn, ''], 175 | [lngColumn, ''], 176 | [qualityColumn, 'No Match'], 177 | [sourceColumn, 'Mapzen ' + mapzenSource.toUpperCase()] 178 | ]); 179 | return 1; 180 | } 181 | 182 | var lat = response.features[0].geometry.coordinates[0]; 183 | var lng = response.features[0].geometry.coordinates[1]; 184 | var confidence = response.features[0].properties.confidence; 185 | var address = response.features[0].properties.label; 186 | 187 | insertDataIntoSheet(cells, row, [ 188 | [foundAddressColumn, address], 189 | [latColumn, lat], 190 | [lngColumn, lng], 191 | [qualityColumn, confidence], 192 | [sourceColumn, 'Mapzen ' + mapzenSource.toUpperCase()] 193 | ]); 194 | 195 | return 0; 196 | } 197 | 198 | /** 199 | * Sets cells from a 'row' to values in data 200 | */ 201 | function insertDataIntoSheet(cells, row, data) { 202 | for (d in data) { 203 | cells.getCell(row, data[d][0]).setValue(data[d][1]); 204 | } 205 | } 206 | 207 | function censusAddressToPosition() { 208 | geocode('US Census'); 209 | } 210 | 211 | function googleAddressToPosition() { 212 | geocode('Google'); 213 | } 214 | 215 | function mapzen() { 216 | mapzenKey = ui.prompt('Insert Mapzen Key:').getResponseText(); 217 | mapzenRegion = ui.prompt('Country code (e.g. GBR, USA, DEU, CAN, CHN):').getResponseText(); 218 | geocode('Mapzen'); 219 | } 220 | 221 | function mapzenOA() { 222 | mapzenSource = 'oa'; 223 | mapzen(); 224 | } 225 | 226 | function mapzenOSM() { 227 | mapzenSource = 'osm'; 228 | mapzen(); 229 | } 230 | 231 | function onOpen() { 232 | ui.createMenu('Geocoder') 233 | .addItem('with US Census (limit 1000 per batch)', 'censusAddressToPosition') 234 | .addItem('with Google (limit 1000 per day)', 'googleAddressToPosition') 235 | .addSubMenu(ui.createMenu('with Mapzen (requires API key)') 236 | .addItem('OpenAddress', 'mapzenOA') 237 | .addItem('OpenStreetMap', 'mapzenOSM')) 238 | .addToUi(); 239 | } 240 | --------------------------------------------------------------------------------