Connecting to ODBC Data Sources in Google Apps Script
Learn how to connect to an ODBC Driver from Google Apps Script and configure the SQL Broker, and get sample scripting for processing the data in a Google Spreadsheet.
Join the DZone community and get the full member experience.
Join For FreeGoogle Apps Script gives you the ability to create custom functionality within Google Sheets, Google Docs, and more. With the CData SQL Broker, you can create a MySQL interface for any ODBC driver, including the 90+ ODBC drivers by CData. The MySQL protocol is natively supported through the JDBC service in Google Apps Script, so by utilizing the SQL Broker, you gain access to ODBC data within your Google documents.
This article discusses connecting to an ODBC Driver from Google Apps Script, walking through the process of configuring the SQL Broker and providing sample scripting for processing the data in a Google Spreadsheet.
Our script only executes a SELECT
to read data from a specified table, but you can easily extend it to execute an INSERT
, UPDATE
, or DELETE
.
Real-Time Connectivity Through SQL Broker
With SQL Broker, your local ODBC data sources can look and behave like a standard MySQL database. Simply create a new MySQL remoting service in SQL Broker for the ODBC driver and ensure that the SQL Broker is installed on a Web-facing machine (or can connect to a hosted SSH server).
Create a MySQL Remoting Service
The MySQL Remoting feature of the SQL Broker enables you to access an ODBC data source as a virtual MySQL database. The SQL Broker runs a service process that listens for MySQL requests from clients. The service can be configured in the SQL Broker UI.
Connecting to ODBC Data Sources With Apps Script
At this point, you have configured the SQL Broker for your ODBC driver. All that is left now is to use Google Apps Script to access the SQL Broker and work with your ODBC data source in Google Sheets.
In this section, you will create a script (with a menu option to call the script) to populate a spreadsheet with your data. We have created a sample script and explained the different parts. You can view the raw script at the end of the article.
1. Create an Empty Script
To create a script for your Google Sheet, click Tools > Script editor... from the Google Sheets menu:
2. Declare Class Variables
Create a handful of class variables that are available for any functions created in the script.
//replace the variables in this block with real values as needed
var address = 'my.server.address:port';
var user = 'SQL_BROKER_USER';
var userPwd = 'SQL_BROKER_PASSWORD';
var db = 'DSN_HERE';
var dbUrl = 'jdbc:mysql://' + address + '/' + db;
3. Add a Menu Option
This function adds a menu option to your Google Sheet, allowing you to use the UI to call your function.
function onOpen() {
var spreadsheet = SpreadsheetApp.getActive();
var menuItems = [
{name: 'Write data to a sheet', functionName: 'connectToODBCData'}
];
spreadsheet.addMenu('ODBC Data', menuItems);
}
4. Write a Helper Function
This function is used to find the first empty row in a spreadsheet.
/*
* Finds the first empty row in a spreadsheet by scanning an array of columns
* @return The row number of the first empty row.
*/
function getFirstEmptyRowByColumnArray(spreadSheet, column) {
var column = spreadSheet.getRange(column + ":" + column);
var values = column.getValues(); // get all data in one call
var ct = 0;
while ( values[ct] && values[ct][0] != "" ) {
ct++;
}
return (ct+1);
}
5. Write a Function to Write ODBC Data to a Spreadsheet
The function below writes the data using the Google Apps Script JDBC functionality to connect to the MySQL remoting service, SELECT
data, and populate a spreadsheet. When the script is run, two input boxes appear.
The first one asking the user to input the name of a sheet to hold the data (if the spreadsheet does not exist, the function creates it):
And the second one asking the user to input the name of an ODBC table to read. If an invalid table is chosen, an error message appears and the function is exited:
It is worth noting that while the function is designed to be used as a menu option, it could be extended for use as a formula in a spreadsheet.
/*
* Reads data from a specified ODBC 'table' and writes it to the specified sheet.
* (If the specified sheet does not exist, it is created.)
*/
function connectToODBCData() {
var thisWorkbook = SpreadsheetApp.getActive();
//select a sheet and create it if it does not exist
var selectedSheet = Browser.inputBox('Which sheet would you like the data to post to?',Browser.Buttons.OK_CANCEL);
if (selectedSheet == 'cancel')
return;
if (thisWorkbook.getSheetByName(selectedSheet) == null)
thisWorkbook.insertSheet(selectedSheet);
var resultSheet = thisWorkbook.getSheetByName(selectedSheet);
var rowNum = 2;
//select an ODBC 'table'
var table = Browser.inputBox('Which ODBC data table would you like to pull data from?',Browser.Buttons.OK_CANCEL);
if (table == 'cancel')
return;
var conn = Jdbc.getConnection(dbUrl, user, userPwd);
//confirm that var table is a valid table/view
var dbMetaData = conn.getMetaData();
var tableSet = dbMetaData.getTables(null, null, table, null);
var validTable = false;
while (tableSet.next()) {
var tempTable = tableSet.getString(3);
if (table.toUpperCase() == tempTable.toUpperCase()){
table = tempTable;
validTable = true;
break;
}
}
tableSet.close();
if (!validTable) {
Browser.msgBox("Invalid table name: " + table, Browser.Buttons.OK);
return;
}
var stmt = conn.createStatement();
var results = stmt.executeQuery('SELECT * FROM ' + table);
var rsmd = results.getMetaData();
var numCols = rsmd.getColumnCount();
//if the sheet is empty, populate the first row with the headers
var firstEmptyRow = getFirstEmptyRowByColumnArray(resultSheet, "A");
if (firstEmptyRow == 1) {
//collect column names
var headers = new Array(new Array(numCols));
for (var col = 0; col < numCols; col++){
headers[0][col] = rsmd.getColumnName(col+1);
}
resultSheet.getRange(1, 1, headers.length, headers[0].length).setValues(headers);
} else {
rowNum = firstEmptyRow;
}
//write rows of data to the sheet
var values = new Array(new Array(numCols));
while (results.next()) {
for (var col = 0; col < numCols; col++) {
values[0][col] = results.getString(col + 1);
}
resultSheet.getRange(rowNum, 1, 1, numCols).setValues(values);
rowNum++;
}
results.close();
stmt.close();
}
When the function is completed, you have a spreadsheet populated with data from your ODBC driver and you can now leverage all of the calculating, graphing, and charting functionality of Google Sheets anywhere you have access to the Internet.
Complete Google Apps Script
//replace the variables in this block with real values as needed
var address = 'my.server.address:port';
var user = 'SQL_BROKER_USER';
var userPwd = 'SQL_BROKER_PASSWORD';
var db = 'DSN_HERE';
var dbUrl = 'jdbc:mysql://' + address + '/' + db;
function onOpen() {
var spreadsheet = SpreadsheetApp.getActive();
var menuItems = [
{name: 'Write table data to a sheet', functionName: 'connectToODBCData'}
];
spreadsheet.addMenu('ODBC Data', menuItems);
}
/*
* Finds the first empty row in a spreadsheet by scanning an array of columns
* @return The row number of the first empty row.
*/
function getFirstEmptyRowByColumnArray(spreadSheet, column) {
var column = spreadSheet.getRange(column + ":" + column);
var values = column.getValues(); // get all data in one call
var ct = 0;
while ( values[ct] && values[ct][0] != "" ) {
ct++;
}
return (ct+1);
}
/*
* Reads data from a specified 'table' and writes it to the specified sheet.
* (If the specified sheet does not exist, it is created.)
*/
function connectToODBCData() {
var thisWorkbook = SpreadsheetApp.getActive();
//select a sheet and create it if it does not exist
var selectedSheet = Browser.inputBox('Which sheet would you like the data to post to?',Browser.Buttons.OK_CANCEL);
if (selectedSheet == 'cancel')
return;
if (thisWorkbook.getSheetByName(selectedSheet) == null)
thisWorkbook.insertSheet(selectedSheet);
var resultSheet = thisWorkbook.getSheetByName(selectedSheet);
var rowNum = 2;
//select an ODBC 'table'
var table = Browser.inputBox('Which ODBC data table would you like to pull data from?',Browser.Buttons.OK_CANCEL);
if (table == 'cancel')
return;
var conn = Jdbc.getConnection(dbUrl, user, userPwd);
//confirm that var table is a valid table/view
var dbMetaData = conn.getMetaData();
var tableSet = dbMetaData.getTables(null, null, table, null);
var validTable = false;
while (tableSet.next()) {
var tempTable = tableSet.getString(3);
if (table.toUpperCase() == tempTable.toUpperCase()){
table = tempTable;
validTable = true;
break;
}
}
tableSet.close();
if (!validTable) {
Browser.msgBox("Invalid table name: " + table, Browser.Buttons.OK);
return;
}
var stmt = conn.createStatement();
var results = stmt.executeQuery('SELECT * FROM ' + table);
var rsmd = results.getMetaData();
var numCols = rsmd.getColumnCount();
//if the sheet is empty, populate the first row with the headers
var firstEmptyRow = getFirstEmptyRowByColumnArray(resultSheet, "A");
if (firstEmptyRow == 1) {
//collect column names
var headers = new Array(new Array(numCols));
for (var col = 0; col < numCols; col++){
headers[0][col] = rsmd.getColumnName(col+1);
}
resultSheet.getRange(1, 1, headers.length, headers[0].length).setValues(headers);
} else {
rowNum = firstEmptyRow;
}
//write rows of data to the sheet
var values = new Array(new Array(numCols));
while (results.next()) {
for (var col = 0; col < numCols; col++) {
values[0][col] = results.getString(col + 1);
}
resultSheet.getRange(rowNum, 1, 1, numCols).setValues(values);
rowNum++;
}
results.close();
stmt.close();
}
Published at DZone with permission of Jerod Johnson, DZone MVB. See the original article here.
Opinions expressed by DZone contributors are their own.
Comments