Starting with Connector/J 3.1.7, we've made available a variant
of the driver that will automatically send queries to a
read/write master, or a failover or round-robin loadbalanced set
of slaves based on the state of
Connection.getReadOnly()
.
An application signals that it wants a transaction to be
read-only by calling
Connection.setReadOnly(true)
, this
replication-aware connection will use one of the slave
connections, which are load-balanced per-vm using a round-robin
scheme (a given connection is sticky to a slave unless that
slave is removed from service). If you have a write transaction,
or if you have a read that is time-sensitive (remember,
replication in MySQL is asynchronous), set the connection to be
not read-only, by calling
Connection.setReadOnly(false)
and the driver
will ensure that further calls are sent to the master MySQL
server. The driver takes care of propagating the current state
of autocommit, isolation level, and catalog between all of the
connections that it uses to accomplish this load balancing
functionality.
To enable this functionality, use the "
com.mysql.jdbc.ReplicationDriver
" class when
configuring your application server's connection pool or when
creating an instance of a JDBC driver for your standalone
application. Because it accepts the same URL format as the
standard MySQL JDBC driver, ReplicationDriver
does not currently work with
java.sql.DriverManager
-based connection
creation unless it is the only MySQL JDBC driver registered with
the DriverManager
.
Here is a short, simple example of how ReplicationDriver might be used in a standalone application.
import java.sql.Connection; import java.sql.ResultSet; import java.util.Properties; import com.mysql.jdbc.ReplicationDriver; public class ReplicationDriverDemo { public static void main(String[] args) throws Exception { ReplicationDriver driver = new ReplicationDriver(); Properties props = new Properties(); // We want this for failover on the slaves props.put("autoReconnect", "true"); // We want to load balance between the slaves props.put("roundRobinLoadBalance", "true"); props.put("user", "foo"); props.put("password", "bar"); // // Looks like a normal MySQL JDBC url, with a // comma-separated list of hosts, the first // being the 'master', the rest being any number // of slaves that the driver will load balance against // Connection conn = driver.connect("jdbc:mysql://master,slave1,slave2,slave3/test", props); // // Perform read/write work on the master // by setting the read-only flag to "false" // conn.setReadOnly(false); conn.setAutoCommit(false); conn.createStatement().executeUpdate("UPDATE some_table ...."); conn.commit(); // // Now, do a query from a slave, the driver automatically picks one // from the list // conn.setReadOnly(true); ResultSet rs = conn.createStatement().executeQuery("SELECT a,b FROM alt_table"); ....... } }
You may also want to investigate the Load Balancing JDBC Pool (lbpol) tool, which provides a wrapper around the standard JDBC driver and allows you to use DB connection pools that includes checks for system failures and uneven load distribution. For more information, see Load Balancing JDBC Pool (lbpool).
User Comments
I had a lot of difficulty getting the replication connection working with JPA/Hibernate. The connection associated with the entity manager would always connect to the master, irrespective of whether I set the connection readonly or read/write (via calls to ((Session)em.getDelegate()).connection().setReadOnly(true);)
After trawling through the source code for Connector/J, I discovered that the driver understands URLs of the form
jdbc:mysql:replication://[server1],[server2],[server2]/[database]. Using such a URL in my persistence.xml makes everything work splendidly.
(I am using MySQL 5.0.something, Connector/J version 5.1.6. (Though I got the URL format by looking at the source for version 5.1.8. Thank god for open source.) I specify the last slave server twice to work around bug http://bugs.mysql.com/bug.php?id=39611, though that is fixed in version 5.1.7 it seems.)
Add your own comment.