JDBC

Apps Script can connect to external databases through the JDBC service, a wrapper around the standard Java Database Connectivity technology. The JDBC service supports Google Cloud SQL, MySQL, Microsoft SQL Server, and Oracle databases.

To update an external database with JDBC, your script must open a connection to the database and then make changes by sending SQL statements.

Google Cloud SQL databases

Google Cloud SQL lets you create relational databases that live in Google's cloud. Note that, unlike Apps Script, Cloud SQL is not free.

You can create a Second Generation Google Cloud SQL instance by following the steps listed in the Cloud SQL Quickstart. If you have an existing First Generation instance, you can migrate it to a Second Generation instance.

Creating Google Cloud SQL connections

There are two ways of establishing a connection with a Google Cloud SQL database using Apps Script's JDBC service:

These methods are explained below. Both are valid, but the second method requires you to whitelist a set of IP ranges for access to your database.

This method creates a connection to a Google Cloud SQL instance using one of the Jdbc.getCloudSqlConnection(url) methods. The database URL has the form of either jdbc:google:mysql:subname or jdbc:google:rdbms:subname, where subname is the Instance connection name listed on the Cloud SQL instance Overview page in the Google Cloud Platform Console.

Using Jdbc.getConnection(url)

In order to use this method you must whitelist certain CIDR IP address ranges so that Apps Script's servers can connect to your database. Before running your script, complete the following steps:

  1. In your Google Cloud SQL instance, authorize the following IP ranges, one at at time:

    64.18.0.0/20
    64.233.160.0/19
    66.102.0.0/20
    66.249.80.0/20
    72.14.192.0/18
    74.125.0.0/16
    173.194.0.0/16
    207.126.144.0/20
    209.85.128.0/17
    216.239.32.0/19
    
  2. Copy the URL that was assigned to your database; it should have the form jdbc:mysql:subname.

Once you've whitelisted these IP ranges, you can create connections to your Google Cloud SQL instance using one of the Jdbc.getConnection(url) methods and the URL you copied above.

Other databases

If you already have your own MySQL, Microsoft SQL Server, or Oracle database, you can connect to it through Apps Script's JDBC service.

Creating other database connections

In order to create a database connection using the JDBC service you must whitelist certain IP ranges in your database settings to allow Apps Script to access it. These are the address ranges you'll need to whitelist:

64.18.0.0 - 64.18.15.255
64.233.160.0 - 64.233.191.255
66.102.0.0 - 66.102.15.255
66.249.80.0 - 66.249.95.255
72.14.192.0 - 72.14.255.255
74.125.0.0 - 74.125.255.255
173.194.0.0 - 173.194.255.255
207.126.144.0 - 207.126.159.255
209.85.128.0 - 209.85.255.255
216.239.32.0 - 216.239.63.255

Once these whitelists are in place, you can create a connection to the database using one of the Jdbc.getConnection(url) methods and your database's URL.

Sample code

The sample code below assumes you are connecting to a Google Cloud SQL database, and creates database connections using the Jdbc.getCloudSqlConnection(url) method. For other databases you must use the Jdbc.getConnection(url) method to create database connections.

For more information on the JDBC methods, see the Java documentation for JDBC.

Create a database, user, and table

Most developers use the MySQL command-line tool to create databases, users, and tables. However, it's possible to do the same thing in Apps Script, as shown below. It's a good idea to create at least one other user so that your script doesn't always have to connect to the database as root.

// Replace the variables in this block with real values.
// You can find the "Instance connection name" in the Google Cloud
//   Platform Console, on the instance Overview page.
var connectionName = 'Instance_connection_name';
var rootPwd = 'root_password';
var user = 'user_name';
var userPwd = 'user_password';
var db = 'database_name';

var root = 'root';
var instanceUrl = 'jdbc:google:mysql://' + connectionName;
var dbUrl = instanceUrl + '/' + db;

// Create a new database within a Cloud SQL instance.
function createDatabase() {
  var conn = Jdbc.getCloudSqlConnection(instanceUrl, root, rootPwd);
  conn.createStatement().execute('CREATE DATABASE ' + db);
}

// Create a new user for your database with full privileges.
function createUser() {
  var conn = Jdbc.getCloudSqlConnection(dbUrl, root, rootPwd);

  var stmt = conn.prepareStatement('CREATE USER ? IDENTIFIED BY ?');
  stmt.setString(1, user);
  stmt.setString(2, userPwd);
  stmt.execute();

  conn.createStatement().execute('GRANT ALL ON `%`.* TO ' + user);
}

// Create a new table in the database.
function createTable() {
  var conn = Jdbc.getCloudSqlConnection(dbUrl, user, userPwd);
  conn.createStatement().execute('CREATE TABLE entries '
      + '(guestName VARCHAR(255), content VARCHAR(255), '
      + 'entryID INT NOT NULL AUTO_INCREMENT, PRIMARY KEY(entryID));');
}

Write to the database

The examples below demonstrate how to write a single record to the database as well as a batch of 500 records. Batching is vital for bulk operations.

Note also the use of parameterized statements, in which the variables are denoted by ?. To prevent SQL injections, you should use parameterized statements to escape all user-supplied data.

// Replace the variables in this block with real values.
// You can find the "Instance connection name" in the Google Cloud
//   Platform Console, on the instance Overview page.
var connectionName = 'Instance_connection_name';
var user = 'user_name';
var userPwd = 'user_password';
var db = 'database_name';

var dbUrl = 'jdbc:google:mysql://' + connectionName + '/' + db;

// Write one row of data to a table.
function writeOneRecord() {
  var conn = Jdbc.getCloudSqlConnection(dbUrl, user, userPwd);

  var stmt = conn.prepareStatement('INSERT INTO entries '
      + '(guestName, content) values (?, ?)');
  stmt.setString(1, 'First Guest');
  stmt.setString(2, 'Hello, world');
  stmt.execute();
}

// Write 500 rows of data to a table in a single batch.
function writeManyRecords() {
  var conn = Jdbc.getCloudSqlConnection(dbUrl, user, userPwd);
  conn.setAutoCommit(false);

  var start = new Date();
  var stmt = conn.prepareStatement('INSERT INTO entries '
      + '(guestName, content) values (?, ?)');
  for (var i = 0; i < 500; i++) {
    stmt.setString(1, 'Name ' + i);
    stmt.setString(2, 'Hello, world ' + i);
    stmt.addBatch();
  }

  var batch = stmt.executeBatch();
  conn.commit();
  conn.close();

  var end = new Date();
  Logger.log('Time elapsed: %sms for %s rows.', end - start, batch.length);
}

Read from the database

This example demonstrates how to read a large number of records from the database, looping over the result set as necessary.

// Replace the variables in this block with real values.
// You can find the "Instance connection name" in the Google Cloud
//   Platform Console, on the instance Overview page.
var connectionName = 'Instance_connection_name';
var user = 'user_name';
var userPwd = 'user_password';
var db = 'database_name';

var dbUrl = 'jdbc:google:mysql://' + connectionName + '/' + db;

// Read up to 1000 rows of data from the table and log them.
function readFromTable() {
  var conn = Jdbc.getCloudSqlConnection(dbUrl, user, userPwd);

  var start = new Date();
  var stmt = conn.createStatement();
  stmt.setMaxRows(1000);
  var results = stmt.executeQuery('SELECT * FROM entries');
  var numCols = results.getMetaData().getColumnCount();

  while (results.next()) {
    var rowString = '';
    for (var col = 0; col < numCols; col++) {
      rowString += results.getString(col + 1) + '\t';
    }
    Logger.log(rowString)
  }

  results.close();
  stmt.close();

  var end = new Date();
  Logger.log('Time elapsed: %sms', end - start);
}

Closing connections

JDBC connections close automatically when a script finishes executing. (Keep in mind that a single google.script.run call counts as a complete execution, even if the HTML service page that made the call remains open.)

Nonetheless, if you know you're done with a connection, statement, or result set before the end of the script, it's a good idea to close them manually by calling JdbcConnection.close(), JdbcStatement.close(), or JdbcResultSet.close().

Showing an alert or prompt dialog also terminates any open JDBC connections. However, other showing UI elements—like custom menus or dialogs and sidebars with custom content—does not.

发送以下问题的反馈:

此网页
Apps Script
Apps Script