IT World http://blog.yannickjaquier.com RDBMS, Unix and many more... Mon, 24 Jul 2017 10:02:45 +0000 en-US hourly 1 https://wordpress.org/?v=4.8.1 ProxySQL high availability tutorial with MariaDB replication http://blog.yannickjaquier.com/mysql/proxysql-high-availability-replication.html http://blog.yannickjaquier.com/mysql/proxysql-high-availability-replication.html#respond Mon, 24 Jul 2017 10:02:45 +0000 http://blog.yannickjaquier.com/?p=3812

Table Of Contents

  1. Preamble
  2. ProxySQL configuration
  3. ProxySQL testing
  4. ProxySQL high availability testing
    1. One slave dead
    2. Two slaves dead
    3. Master server dead
  5. ProxySQL additional features
    1. Query caching
    2. Query rewrite
  6. References
 

Preamble

In a recent webinar I attended I have seen mention of a Maxscale alternative called ProxySQL. Maxscale is a proven working high level proxy but ProxySQL author (René Cannaò) is quite dithyrambic on his product mainly on performance related benchmarks. So better I give a try to it but I will not make any comment on performance. Aim of the post is a simple ProxySQL implementation in a MariaDB replication architecture.

Testing has been done using three virtual machines running Oracle Enterprise Linux 7.2 64 bits:

  • server2.domain.com (192.168.56.102) is MariaDB 10.1.14 64 bits master server.
  • server3.domain.com (192.168.56.103) is MariaDB 10.1.14 64 bits slave server running two MariaDB slave instances.
  • server4.domain.com (192.168.56.104) is ProxySQL node with MysQL 5.7.13 64 bits for client binary.

The Java test application is running under Eclipse Java EE IDE for Web Developers version Neon Release (4.6.0) with MariaDB connector/J 1.4.6 and Oracle MySQL Connector/J 5.1.39.

The MariaDB replication architecture is made of:

  • server2.domain.com on port 3316 as master instance
  • server3.domain.com on port 3316 as first slave instance
  • server3.domain.com on port 3326 as second slave instance

I’m not re-entering in MariaDB replication implementation as we have already seen it.

ProxySQL release available at the time of this article is 1.2.0j. Last but not least ProxySQL can be used for query caching and query rewrite !!

ProxySQL configuration

To install ProxySQL either you compile it or you download a rpm for your release. I have used the one of Centos 7 (proxysql-1.2.0-1-centos7.x86_64.rpm) that is working fine on OEL 7 available at https://github.com/sysown/proxysql/releases.

[root@server4 tmp]# yum install proxysql-1.2.0-1-centos7.x86_64.rpm
Loaded plugins: ulninfo
Examining proxysql-1.2.0-1-centos7.x86_64.rpm: proxysql-1.2.0-1.x86_64
Marking proxysql-1.2.0-1-centos7.x86_64.rpm to be installed
Resolving Dependencies
--> Running transaction check
---> Package proxysql.x86_64 0:1.2.0-1 will be installed
--> Finished Dependency Resolution

Dependencies Resolved

===========================================================================================================================================================================================================
 Package                                    Arch                                     Version                                      Repository                                                          Size
===========================================================================================================================================================================================================
Installing:
 proxysql                                   x86_64                                   1.2.0-1                                      /proxysql-1.2.0-1-centos7.x86_64                                    11 M

Transaction Summary
===========================================================================================================================================================================================================
Install  1 Package

Total size: 11 M
Installed size: 11 M
Is this ok [y/d/N]: y
Downloading packages:
Running transaction check
Running transaction test
Transaction test succeeded
Running transaction
  Installing : proxysql-1.2.0-1.x86_64                                                                                                                                                                 1/1
  Verifying  : proxysql-1.2.0-1.x86_64                                                                                                                                                                 1/1

Installed:
  proxysql.x86_64 0:1.2.0-1

Complete!

Start it:

[root@server4 ~]# service proxysql start
Starting ProxySQL: Main init phase0 completed in 3.9e-05 secs.
Main init global variables completed in 0.000236 secs.
Main daemonize phase1 completed in 3.2e-05 secs.
DONE!

I expected a graphical interface to customize options but ProxySQL is fully command line, not an issue ! ProxySQL information is stored is a MySQL back end database so any modification will be done through SQL language. To connect to ProxySQL back-end database you need a MySQL client. Either you install the one of your Linux distribution via standard repository or you install your own one. I have chosen to use MySQL 5.7.13 installed in /mysql/software/mysql01 but new security rules has made things a little bit harder:

[mysql@server4 ~]$ /mysql/software/mysql01/bin/mysql -u admin -padmin -h 127.0.0.1 -P6032
mysql: [Warning] Using a password on the command line interface can be insecure.
ERROR 2026 (HY000): SSL connection error: socket layer receive error

I initially tried the skip-ssl option that is working but deprecated:

[mysql@server4 ~]$ /mysql/software/mysql01/bin/mysql -u admin -padmin -h 127.0.0.1 -P6032 --skip-ssl
mysql: [Warning] Using a password on the command line interface can be insecure.
WARNING: --ssl is deprecated and will be removed in a future version. Use --ssl-mode instead.
Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 0
Server version: 5.1.30 (ProxySQL Admin Module)

Copyright (c) 2000, 2016, Oracle and/or its affiliates. All rights reserved.

Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.

Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.

mysql>

The working up-to-date option is ssl-mode:

[mysql@server4 ~]$ /mysql/software/mysql01/bin/mysql -u admin -padmin -h 127.0.0.1 -P6032 --ssl-mode=disabled
mysql: [Warning] Using a password on the command line interface can be insecure.
Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 1
Server version: 5.1.30 (ProxySQL Admin Module)

Copyright (c) 2000, 2016, Oracle and/or its affiliates. All rights reserved.

Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.

Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.

mysql>

Insert your MariaDB replication topology, load it live and save it to disk with:

mysql> insert into mysql_servers(hostgroup_id, hostname, port) values (0,'192.168.56.102',3316);
Query OK, 1 row affected (0.00 sec)

mysql> insert into mysql_servers(hostgroup_id, hostname, port) values (1,'192.168.56.103',3316);
Query OK, 1 row affected (0.01 sec)

mysql> insert into mysql_servers(hostgroup_id, hostname, port) values (1,'192.168.56.103',3326);
Query OK, 1 row affected (0.00 sec)

mysql> select * from mysql_servers;
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| hostgroup_id | hostname       | port | status | weight | compression | max_connections | max_replication_lag | use_ssl | max_latency_ms |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| 0            | 192.168.56.102 | 3316 | ONLINE | 1      | 0           | 1000            | 0                   | 0       | 0              |
| 1            | 192.168.56.103 | 3316 | ONLINE | 1      | 0           | 1000            | 0                   | 0       | 0              |
| 1            | 192.168.56.103 | 3326 | ONLINE | 1      | 0           | 1000            | 0                   | 0       | 0              |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
3 rows in set (0.01 sec)

mysql> save mysql servers to disk;
Query OK, 0 rows affected (0.00 sec)

mysql> select * from disk.mysql_servers;
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| hostgroup_id | hostname       | port | status | weight | compression | max_connections | max_replication_lag | use_ssl | max_latency_ms |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| 0            | 192.168.56.102 | 3316 | ONLINE | 1      | 0           | 1000            | 0                   | 0       | 0              |
| 1            | 192.168.56.103 | 3316 | ONLINE | 1      | 0           | 1000            | 0                   | 0       | 0              |
| 1            | 192.168.56.103 | 3326 | ONLINE | 1      | 0           | 1000            | 0                   | 0       | 0              |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
3 rows in set (0.00 sec)

mysql> load mysql servers to runtime;
Query OK, 0 rows affected (0.00 sec)

Second step is to create an applicative account on ProxySQL. This account must also be created on the MariaDB replication architecture. On master instance, account creation will be replicated on slaves:

grant all privileges on replicationdb.* to 'test'@'%' identified by 'secure_password';

And do it in ProxySQL repository database:

mysql> insert into mysql_users (username,password) values ('test','secure_password');
Query OK, 1 row affected (0.00 sec)

mysql> save mysql users to disk;
Query OK, 0 rows affected (0.00 sec)

mysql> select * from disk.mysql_users;
+----------+-----------------+--------+---------+-------------------+----------------+---------------+------------------------+--------------+---------+----------+-----------------+
| username | password        | active | use_ssl | default_hostgroup | default_schema | schema_locked | transaction_persistent | fast_forward | backend | frontend | max_connections |
+----------+-----------------+--------+---------+-------------------+----------------+---------------+------------------------+--------------+---------+----------+-----------------+
| test     | secure_password | 1      | 0       | 0                 | NULL           | 0             | 0                      | 0            | 1       | 1        | 10000           |
+----------+-----------------+--------+---------+-------------------+----------------+---------------+------------------------+--------------+---------+----------+-----------------+
1 row in set (0.00 sec)

mysql> load mysql users to runtime;
Query OK, 0 rows affected (0.00 sec)

Humm passwords are stored in clear, it’s a planned feature to encrypt them… Note the default hostgroup set to 0 (master server).

Let’s do a test of a read-only SQL command:

[root@server4 ~]# /mysql/software/mysql01/bin/mysql --user=test --password=secure_password --host=127.0.0.1 --port=6033 -e 'SELECT @@hostname,@@port' --ssl-mode=disabled
mysql: [Warning] Using a password on the command line interface can be insecure.
+--------------------+--------+
| @@hostname         | @@port |
+--------------------+--------+
| server2.domain.com |   3316 |
+--------------------+--------+

If you execute above command multiple times only master server is chosen. Read/write split is not implemented by default and if you want a Maxscale behavior you have to create query routing rules…

I have also activated ProxySQL backend servers monitoring:

mysql> SELECT * FROM global_variables where variable_name like 'mysql-monitor%';
+----------------------------------------+---------------------------------------------------+
| variable_name                          | variable_value                                    |
+----------------------------------------+---------------------------------------------------+
| mysql-monitor_history                  | 600000                                            |
| mysql-monitor_connect_interval         | 120000                                            |
| mysql-monitor_connect_timeout          | 200                                               |
| mysql-monitor_ping_interval            | 60000                                             |
| mysql-monitor_ping_max_failures        | 3                                                 |
| mysql-monitor_ping_timeout             | 100                                               |
| mysql-monitor_read_only_interval       | 1000                                              |
| mysql-monitor_read_only_timeout        | 100                                               |
| mysql-monitor_replication_lag_interval | 10000                                             |
| mysql-monitor_replication_lag_timeout  | 1000                                              |
| mysql-monitor_username                 | monitor                                           |
| mysql-monitor_password                 | monitor                                           |
| mysql-monitor_query_variables          | SELECT * FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES |
| mysql-monitor_query_status             | SELECT * FROM INFORMATION_SCHEMA.GLOBAL_STATUS    |
| mysql-monitor_query_interval           | 60000                                             |
| mysql-monitor_query_timeout            | 100                                               |
| mysql-monitor_timer_cached             | true                                              |
| mysql-monitor_writer_is_also_reader    | true                                              |
+----------------------------------------+---------------------------------------------------+
18 rows in set (0.01 sec)

mysql> update global_variables set variable_value='secure_password' where variable_name='mysql-monitor_password';
Query OK, 1 row affected (0.00 sec)

mysql> load mysql variables to runtime;
Query OK, 0 rows affected (0.00 sec)

mysql> save mysql variables to disk;
Query OK, 64 rows affected (0.02 sec)

I create the ProxySQL monitor account on master server, it will be automatically replicated to slaves:

MariaDB [(none)]> grant replication client on *.* to 'monitor'@'%' identified by 'secure_password';
Query OK, 0 rows affected (0.00 sec)

After a small period you can control it runs successfully with:

mysql> select * from monitor.mysql_server_replication_lag_log order by time_start desc limit 10;
+----------------+------+------------------+--------------+----------+-------+
| hostname       | port | time_start       | success_time | repl_lag | error |
+----------------+------+------------------+--------------+----------+-------+
| 192.168.56.102 | 3316 | 1467715539097299 | 810          | NULL     | NULL  |
| 192.168.56.103 | 3316 | 1467715539097299 | 621          | 0        | NULL  |
| 192.168.56.103 | 3326 | 1467715539097299 | 1022         | 0        | NULL  |
| 192.168.56.102 | 3316 | 1467715529097105 | 780          | NULL     | NULL  |
| 192.168.56.103 | 3316 | 1467715529097105 | 816          | 0        | NULL  |
| 192.168.56.103 | 3326 | 1467715529097105 | 1024         | 0        | NULL  |
| 192.168.56.102 | 3316 | 1467715519096898 | 786          | NULL     | NULL  |
| 192.168.56.103 | 3316 | 1467715519096898 | 655          | 0        | NULL  |
| 192.168.56.103 | 3326 | 1467715519096898 | 1111         | 0        | NULL  |
| 192.168.56.102 | 3316 | 1467715509096195 | 885          | NULL     | NULL  |
+----------------+------+------------------+--------------+----------+-------+
10 rows in set (0.00 sec)

mysql> select * from monitor.mysql_server_ping_log order by time_start desc limit 10;
+----------------+------+------------------+-------------------+------------+
| hostname       | port | time_start       | ping_success_time | ping_error |
+----------------+------+------------------+-------------------+------------+
| 192.168.56.102 | 3316 | 1467715518924380 | 721               | NULL       |
| 192.168.56.103 | 3316 | 1467715518924380 | 525               | NULL       |
| 192.168.56.103 | 3326 | 1467715518924380 | 701               | NULL       |
| 192.168.56.102 | 3316 | 1467715458924137 | 682               | NULL       |
| 192.168.56.103 | 3316 | 1467715458924137 | 517               | NULL       |
| 192.168.56.103 | 3326 | 1467715458924137 | 703               | NULL       |
| 192.168.56.102 | 3316 | 1467715398923945 | 685               | NULL       |
| 192.168.56.103 | 3316 | 1467715398923945 | 531               | NULL       |
| 192.168.56.103 | 3326 | 1467715398923945 | 843               | NULL       |
| 192.168.56.102 | 3316 | 1467715338923725 | 678               | NULL       |
+----------------+------+------------------+-------------------+------------+
10 rows in set (0.00 sec)

mysql> select * from monitor.mysql_server_connect_log order by time_start desc limit 10;
+----------------+------+------------------+----------------------+---------------+
| hostname       | port | time_start       | connect_success_time | connect_error |
+----------------+------+------------------+----------------------+---------------+
| 192.168.56.102 | 3316 | 1467715518941492 | 1524                 | NULL          |
| 192.168.56.103 | 3316 | 1467715518941492 | 2105                 | NULL          |
| 192.168.56.103 | 3326 | 1467715518941492 | 2232                 | NULL          |
| 192.168.56.102 | 3316 | 1467715398941430 | 1734                 | NULL          |
| 192.168.56.103 | 3316 | 1467715398941430 | 2450                 | NULL          |
| 192.168.56.103 | 3326 | 1467715398941430 | 1357                 | NULL          |
| 192.168.56.102 | 3316 | 1467715278941119 | 1437                 | NULL          |
| 192.168.56.103 | 3316 | 1467715278941119 | 1937                 | NULL          |
| 192.168.56.103 | 3326 | 1467715278941119 | 4414                 | NULL          |
| 192.168.56.102 | 3316 | 1467715158941062 | 1806                 | NULL          |
+----------------+------+------------------+----------------------+---------------+
10 rows in set (0.00 sec)

I have not well understood if mysql_replication_hostgroups table must be configured, even without it, it should work:

mysql> insert into mysql_replication_hostgroups values(0,1);
Query OK, 1 row affected (0.01 sec)

mysql> save mysql servers to disk;
Query OK, 0 rows affected (0.01 sec)

mysql> load mysql servers to runtime;
Query OK, 0 rows affected (0.01 sec)

mysql> select * from mysql_replication_hostgroups;
+------------------+------------------+
| writer_hostgroup | reader_hostgroup |
+------------------+------------------+
| 0                | 1                |
+------------------+------------------+
1 row in set (0.00 sec)

mysql> select * from disk.mysql_replication_hostgroups;
+------------------+------------------+
| writer_hostgroup | reader_hostgroup |
+------------------+------------------+
| 0                | 1                |
+------------------+------------------+
1 row in set (0.01 sec)

If you hit strange behavior, like I had, showing duplicated nodes across hostgroup:

mysql> SELECT * FROM mysql_servers;
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| hostgroup_id | hostname       | port | status | weight | compression | max_connections | max_replication_lag | use_ssl | max_latency_ms |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| 0            | 192.168.56.102 | 3316 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
| 0            | 192.168.56.103 | 3326 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
| 0            | 192.168.56.103 | 3316 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
| 1            | 192.168.56.103 | 3326 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
| 1            | 192.168.56.103 | 3316 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
5 rows in set (0.00 sec)

mysql> select * from disk.mysql_server;
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| hostgroup_id | hostname       | port | status | weight | compression | max_connections | max_replication_lag | use_ssl | max_latency_ms |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| 0            | 192.168.56.102 | 3316 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
| 1            | 192.168.56.103 | 3316 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
| 1            | 192.168.56.103 | 3326 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
3 rows in set (0.01 sec)

You have to set your slaves read only with:

MariaDB [(none)]> set global read_only=ON;
Query OK, 0 rows affected (0.00 sec)

MariaDB [(none)]> show variables like 'read_only';
+---------------+-------+
| Variable_name | Value |
+---------------+-------+
| read_only     | ON    |
+---------------+-------+
1 row in set (0.00 sec)

For below error message when using MySQL Connector/J 5.1.39:

Error message: Unknown system variable 'language'

You have to set ProxySQL MySQL version above 5.1.31 with something like (mysql-server_version is just a display for ProxySQL):

mysql> set mysql-server_version='5.7.13';
Query OK, 1 row affected (0.00 sec)

mysql> load mysql variables to runtime;
Query OK, 0 rows affected (0.00 sec)

mysql> save mysql variables to disk;
Query OK, 64 rows affected (0.01 sec)

ProxySQL testing

As stated in ProxySQL website to simulate read/write split you have to create query routing rules, just using what is given in ProxySQL web site:

mysql> insert into mysql_query_rules(active,match_pattern,destination_hostgroup,apply) values (1,'^SELECT.*FOR UPDATE$',0,1);
Query OK, 1 row affected (0.00 sec)

mysql> insert into mysql_query_rules(active,match_pattern,destination_hostgroup,apply) values (1,'^SELECT',1,1);
Query OK, 1 row affected (0.00 sec)

mysql> select rule_id, match_pattern,destination_hostgroup, apply from mysql_query_rules;
+---------+----------------------+-----------------------+-------+
| rule_id | match_pattern        | destination_hostgroup | apply |
+---------+----------------------+-----------------------+-------+
| 1       | ^SELECT.*FOR UPDATE$ | 0                     | 1     |
| 2       | ^SELECT              | 1                     | 1     |
+---------+----------------------+-----------------------+-------+
2 rows in set (0.00 sec)

mysql> save mysql query rules to disk;
Query OK, 0 rows affected (0.00 sec)

mysql> load mysql query rules to runtime;
Query OK, 0 rows affected (0.00 sec)

This example query routing rules listed in official documentation are routing select queries (read-only) to hostgroup 1 (slave servers) and select for update queries (read-write) to master server. Queries not passing any of the rules goes to default hostgroup that is master server. With a classical MySQL client connection it gives:

[root@server4 ~]# /mysql/software/mysql01/bin/mysql --user=test --password=secure_password --host=127.0.0.1 --port=6033 -e 'SELECT @@hostname,@@port' --ssl-mode=disabled
mysql: [Warning] Using a password on the command line interface can be insecure.
+--------------------+--------+
| @@hostname         | @@port |
+--------------------+--------+
| server3.domain.com |   3326 |
+--------------------+--------+
[root@server4 ~]# /mysql/software/mysql01/bin/mysql --user=test --password=secure_password --host=127.0.0.1 --port=6033 -e 'SELECT @@hostname,@@port' --ssl-mode=disabled
mysql: [Warning] Using a password on the command line interface can be insecure.
+--------------------+--------+
| @@hostname         | @@port |
+--------------------+--------+
| server3.domain.com |   3316 |
+--------------------+--------+

To further test it I have used the typical Java application I have used in many other blog posts. Here I initiate a connection and loop to perform a read-write and a read-only query. Obviously I am not disconnecting and reconnecting after each loop mainly because a standard Java application would not do it.

To be honest I have faced lots of issue making this Java application work and round robin onto my slave servers, fortunately I have been helped by René directly at this forum thread https://groups.google.com/forum/#!topic/proxysql/Rzwd55xIQGk. First René explained that due to @ symbol ProxySQL multiplexing is disabled to ensure consistency on users’ variables. So he suggested to change my test query by something like:

SELECT (SELECT VARIABLE_VALUE FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE VARIABLE_NAME='hostname') `hostname`,(SELECT VARIABLE_VALUE FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE VARIABLE_NAME='port') `port`;

Then, directed by René, I realized that I stupidly changed the value of mysql-multiplexing to false (default value is true), so changed it back to original value:

mysql> set mysql-multiplexing='true';
Query OK, 1 row affected (0.01 sec)

mysql> load mysql variables to runtime;
Query OK, 0 rows affected (0.01 sec)

mysql> save mysql variables to disk;
Query OK, 64 rows affected (0.01 sec)

Finally below Java code (you can de-comment the Connector/J you wish to use, Java code is compliant with both):

package jdbcdemo7;

import java.sql.Connection;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.util.Properties;
import org.mariadb.jdbc.Driver;
//import com.mysql.jdbc.Driver;

public class jdbcdemo7 {
	public static void main(String[] args) throws Exception {
		Driver driver = new Driver();
		Properties props = new Properties();
		ResultSet rs;
		String variable_value;
		Connection conn = null;
		String JDBC_URL = "jdbc:mysql://address=(protocol=tcp)(host=192.168.56.104)(port=6033)";

		props.put("useSSL", "false");
		props.put("user", "test");
		props.put("password", "secure_password");

		System.out.println("\n------------ MariaDB Connector/J and ProxySQL Testing ------------\n");

		System.out.println("Trying connection...");
		try {
			conn = driver.connect(JDBC_URL, props);
		}
			catch (SQLException e) {
			System.out.println("Connection Failed!");
			System.out.println("Error cause: "+e.getCause());
			System.out.println("Error message: "+e.getMessage());
			return;
		}

		System.out.println("Connection established...");

		for(int i=1; i <= 50; i++) {
			System.out.println("\nQuery "+i+": ");
			// Read write query that can be performed ONLY on master server
			System.out.println("Read Write query...");
			try {
				rs = conn.createStatement().executeQuery("select (select variable_value from information_schema.global_variables where variable_name=\'hostname\') || \' on port \' || (select variable_value from information_schema.global_variables where variable_name=\'port\') variable_value for update");
				while (rs.next()) {
					variable_value = rs.getString("variable_value");
					System.out.println("variable_value : " + variable_value);
				}
			}
			catch (SQLException e) {
				System.out.println("Read/write query has failed...");
			}
	    

				// Read Only statement (that can also be done on master server if all slaves are down)
			System.out.println("Read Only query...");

			try {
				rs = conn.createStatement().executeQuery("select (select variable_value from information_schema.global_variables where variable_name=\'hostname\') || \' on port \' || (select variable_value from information_schema.global_variables where variable_name=\'port\') variable_value");
				while (rs.next()) {
					variable_value = rs.getString("variable_value");
					System.out.println("variable_value : " + variable_value);
				}
			}
			catch (SQLException e) {
				System.out.println("Read only query has failed...");
			}

			Thread.sleep(1000);
		}
		conn.close();
	}
}

To provide under Eclipse below nice result:

proxysql01
proxysql01

Few statistics tables are also available:

mysql> select * from stats_mysql_connection_pool;
+-----------+----------------+----------+--------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
| hostgroup | srv_host       | srv_port | status | ConnUsed | ConnFree | ConnOK | ConnERR | Queries | Bytes_data_sent | Bytes_data_recv | Latency_ms |
+-----------+----------------+----------+--------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
| 0         | 192.168.56.102 | 3316     | ONLINE | 0        | 0        | 23     | 0       | 1012    | 73908           | 61508           | 0          |
| 1         | 192.168.56.103 | 3316     | ONLINE | 0        | 0        | 32     | 0       | 307     | 18160           | 10868           | 0          |
| 1         | 192.168.56.103 | 3326     | ONLINE | 0        | 0        | 40     | 0       | 480     | 28544           | 17024           | 0          |
+-----------+----------------+----------+--------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
3 rows in set (0.00 sec)

mysql> select hostgroup, sum(queries), sum(bytes_data_sent), sum(bytes_data_recv) from stats_mysql_connection_pool group by hostgroup;
+-----------+--------------+----------------------+----------------------+
| hostgroup | SUM(Queries) | SUM(Bytes_data_sent) | SUM(Bytes_data_recv) |
+-----------+--------------+----------------------+----------------------+
| 0         | 667          | 48373                | 26196                |
| 1         | 664          | 40256                | 23712                |
+-----------+--------------+----------------------+----------------------+
2 rows in set (0.00 sec)

For the complete list of statistics tables use:

mysql> show tables from stats;
+--------------------------------+
| tables                         |
+--------------------------------+
| stats_mysql_query_rules        |
| stats_mysql_commands_counters  |
| stats_mysql_processlist        |
| stats_mysql_connection_pool    |
| stats_mysql_query_digest       |
| stats_mysql_query_digest_reset |
| stats_mysql_global             |
+--------------------------------+
7 rows in set (0.00 sec)

ProxySQL high availability testing

One slave dead

If I shutdown one of the slave above Java application is not throwing any error and continue to run transparently on only remaining slave.

mysql> SELECT * FROM stats_mysql_connection_pool;
+-----------+----------------+----------+---------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
| hostgroup | srv_host       | srv_port | status  | ConnUsed | ConnFree | ConnOK | ConnERR | Queries | Bytes_data_sent | Bytes_data_recv | Latency_ms |
+-----------+----------------+----------+---------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
| 0         | 192.168.56.102 | 3316     | ONLINE  | 0        | 1        | 1      | 0       | 28      | 6317            | 1192            | 587        |
| 1         | 192.168.56.103 | 3316     | ONLINE  | 0        | 1        | 1      | 0       | 18      | 4086            | 648             | 530        |
| 1         | 192.168.56.103 | 3326     | SHUNNED | 0        | 0        | 1      | 12      | 8       | 1816            | 288             | 901        |
+-----------+----------------+----------+---------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
3 rows in set (0.00 sec)

Once the dead slave is back to live ProxySQL use it automatically.

Two slaves dead

If I shutdown my two slaves then read only queries are no more possible:

mysql> SELECT * FROM stats_mysql_connection_pool;
+-----------+----------------+----------+---------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
| hostgroup | srv_host       | srv_port | status  | ConnUsed | ConnFree | ConnOK | ConnERR | Queries | Bytes_data_sent | Bytes_data_recv | Latency_ms |
+-----------+----------------+----------+---------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
| 0         | 192.168.56.102 | 3316     | ONLINE  | 0        | 1        | 1      | 0       | 92      | 21549           | 3496            | 919        |
| 1         | 192.168.56.103 | 3316     | SHUNNED | 0        | 0        | 1      | 18      | 76      | 17252           | 2700            | 896        |
| 1         | 192.168.56.103 | 3326     | SHUNNED | 0        | 0        | 2      | 84      | 13      | 2951            | 432             | 901        |
+-----------+----------------+----------+---------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
3 rows in set (0.00 sec)

With few ProxySQL commands it would be possible to correct this and allocate master server in hostgroup 1 to allow it to resolve read only queries.

When at least one of the slaves is back to life application return in normal running state...

Master server dead

Of course read write queries are no more possible when master server is down ! statistics are a bit strange:

mysql> SELECT * FROM stats_mysql_connection_pool;
+-----------+----------------+----------+--------------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
| hostgroup | srv_host       | srv_port | status       | ConnUsed | ConnFree | ConnOK | ConnERR | Queries | Bytes_data_sent | Bytes_data_recv | Latency_ms |
+-----------+----------------+----------+--------------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
| 0         | 192.168.56.102 | 3316     | OFFLINE_HARD | 0        | 0        | 1      | 0       | 127     | 29532           | 4940            | 622        |
| 1         | 192.168.56.103 | 3316     | ONLINE       | 0        | 1        | 2      | 131     | 84      | 19068           | 2988            | 759        |
| 1         | 192.168.56.103 | 3326     | ONLINE       | 0        | 1        | 3      | 198     | 22      | 4994            | 756             | 660        |
| 1         | 192.168.56.102 | 3316     | ONLINE       | 0        | 0        | 0      | 0       | 0       | 0               | 0               | 0          |
+-----------+----------------+----------+--------------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
4 rows in set (0.00 sec)

mysql> SELECT * FROM mysql_servers;
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| hostgroup_id | hostname       | port | status | weight | compression | max_connections | max_replication_lag | use_ssl | max_latency_ms |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| 1            | 192.168.56.103 | 3316 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
| 1            | 192.168.56.103 | 3326 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
| 0            | 192.168.56.102 | 3316 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
| 1            | 192.168.56.102 | 3316 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
4 rows in set (0.00 sec)

In this situation either you promote a slave to new master role and ProxySQL must be tuned, nothing complex here. Or you are able to restart your master server, most probable situation.

When my master server was again alive I have seen that ProxySQL has added it to read only group (hostgroup 1) and now read only queries are also served by it. I have resolved this weird situation with:

mysql> delete from mysql_servers where hostgroup_id=1 and hostname='192.168.56.102';
Query OK, 1 row affected (0.00 sec)

mysql> load mysql servers to runtime;
Query OK, 0 rows affected (0.01 sec)

mysql> select * from mysql_servers;
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| hostgroup_id | hostname       | port | status | weight | compression | max_connections | max_replication_lag | use_ssl | max_latency_ms |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
| 1            | 192.168.56.103 | 3316 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
| 1            | 192.168.56.103 | 3326 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
| 0            | 192.168.56.102 | 3316 | ONLINE | 1      | 0           | 1000            | 10                  | 0       | 10             |
+--------------+----------------+------+--------+--------+-------------+-----------------+---------------------+---------+----------------+
3 rows in set (0.00 sec)

mysql> select * from stats_mysql_connection_pool;
+-----------+----------------+----------+--------------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
| hostgroup | srv_host       | srv_port | status       | ConnUsed | ConnFree | ConnOK | ConnERR | Queries | Bytes_data_sent | Bytes_data_recv | Latency_ms |
+-----------+----------------+----------+--------------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
| 0         | 192.168.56.102 | 3316     | ONLINE       | 0        | 1        | 1      | 0       | 53      | 12614           | 1908            | 682        |
| 1         | 192.168.56.103 | 3316     | ONLINE       | 0        | 1        | 2      | 131     | 110     | 24970           | 3924            | 1477       |
| 1         | 192.168.56.103 | 3326     | ONLINE       | 0        | 1        | 3      | 198     | 47      | 10669           | 1656            | 1101       |
| 1         | 192.168.56.102 | 3316     | OFFLINE_HARD | 0        | 0        | 1      | 4       | 13      | 2951            | 468             | 682        |
+-----------+----------------+----------+--------------+----------+----------+--------+---------+---------+-----------------+-----------------+------------+
4 rows in set (0.01 sec)

If you restart ProxySQL everything is cleared...

ProxySQL additional features

Query caching

Use this trick to reset statistics:

select 1 from stats_mysql_query_digest_reset;

One nice feature is query caching that reminds me the benefit I have seen with Memcached. After a run of my Java test application with 1000 loop I get below obvious statistics:

mysql> select hostgroup,count_star,min_time,max_time,sum_time,digest_text from stats_mysql_query_digest;
+-----------+------------+----------+----------+----------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| hostgroup | count_star | min_time | max_time | sum_time | digest_text                                                                                                                                                                                                           |
+-----------+------------+----------+----------+----------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| 1         | 1000       | 1052     | 4287     | 1778360  | select (select variable_value from information_schema.global_variables where variable_name=?) || ?|| (select variable_value from information_schema.global_variables where variable_name=?) variable_value            |
| 0         | 1000       | 1018     | 2209     | 1554333  | select (select variable_value from information_schema.global_variables where variable_name=?) || ?|| (select variable_value from information_schema.global_variables where variable_name=?) variable_value for update |
| 0         | 1          | 536      | 536      | 536      | set session autocommit=?                                                                                                                                                                                              |
| 0         | 1          | 1722     | 1722     | 1722     | SHOW VARIABLES WHERE Variable_name in (?, ?, ?, ?)                                                                                                                                                                    |
+-----------+------------+----------+----------+----------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
4 rows in set (0.00 sec)

Let's cache for 10 seconds the read only query that is executed on hostgroup 1:

mysql> select * from mysql_query_rules;
+---------+--------+----------+------------+--------+-------------+------------+------------+--------+--------------+----------------------+----------------------+---------+-----------------+-----------------------+-----------+-----------+---------+---------+-------+----------------+------------------+-----------+-----+-------+
| rule_id | active | username | schemaname | flagIN | client_addr | proxy_addr | proxy_port | digest | match_digest | match_pattern        | negate_match_pattern | flagOUT | replace_pattern | destination_hostgroup | cache_ttl | reconnect | timeout | retries | delay | mirror_flagOUT | mirror_hostgroup | error_msg | log | apply |
+---------+--------+----------+------------+--------+-------------+------------+------------+--------+--------------+----------------------+----------------------+---------+-----------------+-----------------------+-----------+-----------+---------+---------+-------+----------------+------------------+-----------+-----+-------+
| 1       | 1      | NULL     | NULL       | 0      | NULL        | NULL       | NULL       | NULL   | NULL         | ^SELECT.*FOR UPDATE$ | 0                    | NULL    | NULL            | 0                     | NULL      | NULL      | NULL    | NULL    | NULL  | NULL           | NULL             | NULL      | NULL | 1     |
| 2       | 1      | NULL     | NULL       | 0      | NULL        | NULL       | NULL       | NULL   | NULL         | ^SELECT              | 0                    | NULL    | NULL            | 1                     | NULL      | NULL      | NULL    | NULL    | NULL  | NULL           | NULL             | NULL      | NULL | 1     |
+---------+--------+----------+------------+--------+-------------+------------+------------+--------+--------------+----------------------+----------------------+---------+-----------------+-----------------------+-----------+-----------+---------+---------+-------+----------------+------------------+-----------+-----+-------+
2 rows in set (0.00 sec)

mysql> update mysql_query_rules set cache_ttl=10000 where rule_id=2;
Query OK, 1 row affected (0.00 sec)

mysql> load mysql query rules to runtime;
Query OK, 0 rows affected (0.00 sec)

If I re-execute my Java test application we can see that on the 1000 loop only the first one is executed on my MariaDB backend layer, all the remaining ones are served directly by ProxySQL under the special hostgroup -1:

mysql> select hostgroup,count_star,min_time,max_time,sum_time,digest_text from stats_mysql_query_digest;
+-----------+------------+----------+----------+----------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| hostgroup | count_star | min_time | max_time | sum_time | digest_text                                                                                                                                                                                                           |
+-----------+------------+----------+----------+----------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| -1        | 999        | 0        | 0        | 0        | select (select variable_value from information_schema.global_variables where variable_name=?) || ?|| (select variable_value from information_schema.global_variables where variable_name=?) variable_value            |
| 1         | 1001       | 1052     | 4287     | 1780439  | select (select variable_value from information_schema.global_variables where variable_name=?) || ?|| (select variable_value from information_schema.global_variables where variable_name=?) variable_value            |
| 0         | 2000       | 1018     | 2858     | 3236456  | select (select variable_value from information_schema.global_variables where variable_name=?) || ?|| (select variable_value from information_schema.global_variables where variable_name=?) variable_value for update |
| 0         | 2          | 536      | 546      | 1082     | set session autocommit=?                                                                                                                                                                                              |
| 0         | 2          | 1722     | 1775     | 3497     | SHOW VARIABLES WHERE Variable_name in (?, ?, ?, ?)                                                                                                                                                                    |
+-----------+------------+----------+----------+----------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
5 rows in set (0.01 sec)

Query rewrite

Let's imagine I have my application running a query to get maximum value of a column of below table:

MariaDB [(none)]> show create table replicationdb.test1;
+-------+-------------------------------------------------------------------------------------------------------------------------------+
| Table | Create Table                                                                                                                  |
+-------+-------------------------------------------------------------------------------------------------------------------------------+
| test1 | CREATE TABLE `test1` (
  `val` int(11) DEFAULT NULL,
  `descr` varchar(50) DEFAULT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf32 |
+-------+-------------------------------------------------------------------------------------------------------------------------------+
1 row in set (0.00 sec)

MariaDB [(none)]> explain extended select max(val) from replicationdb.test1;
+------+-------------+-------+------+---------------+------+---------+------+------+----------+-------+
| id   | select_type | table | type | possible_keys | key  | key_len | ref  | rows | filtered | Extra |
+------+-------------+-------+------+---------------+------+---------+------+------+----------+-------+
|    1 | SIMPLE      | test1 | ALL  | NULL          | NULL | NULL    | NULL |    2 |   100.00 |       |
+------+-------------+-------+------+---------------+------+---------+------+------+----------+-------+
1 row in set, 1 warning (0.00 sec)

As you know this is going to do a full table scan on replicationdb.test1 table to get this value. Now let's imagine this table is static and I want to change the query each time it is fired to ProxySQL by something like (I assume I have three rows in my table):

select 3

Let's add needed rule, as rule 2 will be fired before newly created rule 10 I deactivate it as well. Here the rule you enter is following regexp way of working so almost no limitation in what it is possible to do:

mysql> insert into mysql_query_rules (rule_id,active,match_pattern,replace_pattern,apply) values (10,1,'^select max\(val\) from replicationdb.test1$','select 3',1);
Query OK, 1 row affected (0.00 sec)

mysql> update mysql_query_rules set active=0 where rule_id=2;
Query OK, 1 row affected (0.01 sec)

mysql> select * from mysql_query_rules;
+---------+--------+----------+------------+--------+-------------+------------+------------+--------+--------------+----------------------------------------------+----------------------+---------+-----------------+-----------------------+-----------+-----------+---------+---------+-------+----------------+------------------+-----------+-----+-------+
| rule_id | active | username | schemaname | flagIN | client_addr | proxy_addr | proxy_port | digest | match_digest | match_pattern                                | negate_match_pattern | flagOUT | replace_pattern | destination_hostgroup | cache_ttl | reconnect | timeout | retries | delay | mirror_flagOUT | mirror_hostgroup | error_msg | log | apply |
+---------+--------+----------+------------+--------+-------------+------------+------------+--------+--------------+----------------------------------------------+----------------------+---------+-----------------+-----------------------+-----------+-----------+---------+---------+-------+----------------+------------------+-----------+-----+-------+
| 1       | 1      | NULL     | NULL       | 0      | NULL        | NULL       | NULL       | NULL   | NULL         | ^SELECT.*FOR UPDATE$                         | 0                    | NULL    | NULL            | 0                     | NULL      | NULL      | NULL    | NULL    | NULL  | NULL           | NULL             | NULL      | NULL | 1     |
| 2       | 0      | NULL     | NULL       | 0      | NULL        | NULL       | NULL       | NULL   | NULL         | ^SELECT                                      | 0                    | NULL    | NULL            | 1                     | NULL      | NULL      | NULL    | NULL    | NULL  | NULL           | NULL             | NULL      | NULL | 1     |
| 10      | 1      | NULL     | NULL       | 0      | NULL        | NULL       | NULL       | NULL   | NULL         | ^select max\(val\) from replicationdb.test1$ | 0                    | NULL    | select 3        | NULL                  | NULL      | NULL      | NULL    | NULL    | NULL  | NULL           | NULL             | NULL      | NULL | 1     |
+---------+--------+----------+------------+--------+-------------+------------+------------+--------+--------------+----------------------------------------------+----------------------+---------+-----------------+-----------------------+-----------+-----------+---------+---------+-------+----------------+------------------+-----------+-----+-------+
3 rows in set (0.00 sec)

mysql> load mysql query rules to runtime;
Query OK, 0 rows affected (0.00 sec)

Now I execute the query with:

[mysql@server4 ~]$ /mysql/software/mysql01/bin/mysql --user=test --password=secure_password --host=127.0.0.1 --port=6033 -e "SELECT MAX(val) from replicationdb.test1" --ssl-mode=disabled
mysql: [Warning] Using a password on the command line interface can be insecure.
+----------+
| MAX(val) |
+----------+
|        3 |
+----------+

I get my result, but has it been transformed by ProxySQL ?:

mysql> select hostgroup,count_star,min_time,max_time,sum_time,digest_text from stats_mysql_query_digest;
+-----------+------------+----------+----------+----------+------------------------------------------+
| hostgroup | count_star | min_time | max_time | sum_time | digest_text                              |
+-----------+------------+----------+----------+----------+------------------------------------------+
| 0         | 1          | 3080     | 3080     | 3080     | SELECT MAX(val) from replicationdb.test1 |
| 0         | 1          | 0        | 0        | 0        | select @@version_comment limit ?         |
+-----------+------------+----------+----------+----------+------------------------------------------+
2 rows in set (0.00 sec)

mysql> select * from stats_mysql_query_rules;
+---------+------+
| rule_id | hits |
+---------+------+
| 1       | 0    |
| 10      | 1    |
+---------+------+
2 rows in set (0.01 sec)

The hits column increases so we can say query rewrite is in action !

References

]]>
http://blog.yannickjaquier.com/mysql/proxysql-high-availability-replication.html/feed 0
Orchestrator MySQL replication topology tool tutorial http://blog.yannickjaquier.com/mysql/orchestrator-tutorial.html http://blog.yannickjaquier.com/mysql/orchestrator-tutorial.html#respond Mon, 26 Jun 2017 10:38:28 +0000 http://blog.yannickjaquier.com/?p=3793

Table Of Contents

  1. Preamble
  2. Orchestrator installation
  3. Orchestrator testing
  4. References
 

Preamble

MySQL replication is simple to put in place but it could be a little bit harder when it comes to monitoring and promoting slave servers to master role. Orchestrator is super easy to put in place and if you do not like command line tools or have not subscribed to MONyog this is the tool to give a try. Orchestrator also forbid you operations that would result in an error.

I have already tested multiple solution like Master High Availability Manager and tools for MySQL (MHA), MySQL Utilities, Multi-Master Replication Manager for MySQL (MMM), Maxscale and MySQL Fabric. Orchestrator simply aim at graphically or command line representing your configuration and perform few re-configuration. It is anyway not a pure monitoring tool as SNMP traps cannot be send to your favorite corporate monitoring tool.

In below post I have used three virtual machines running Oracle Linux Server release 7.2 64 bits. I expected to do my tests with a simple master-slave configuration but realized this was not really interesting so created two slaves of my master instance. So I have:

  • server2.domain.com (192.168.56.102) is MariaDB 10.1.14 64 bits master server.
  • server3.domain.com (192.168.56.103) is MariaDB 10.1.14 64 bits slave server running two MariaDB instances.
  • server4.domain.com (192.168.56.104) is Orchestrator node with MySQL 5.7.13 64 bits for repository database.

For MariaDB instances I have:

  • server2.domain.com on port 3316 as master instance
  • server3.domain.com on port 3316 as first slave instance
  • server3.domain.com on port 3326 as second slave instance

Orchestrator installation

I’m not re-entering in MySQL replication (more specifically here MariaDB) as we have seen it recently in a previous post.

Orchestrator requires a MySQL backend database to store its information. I have to say that I’m a bit disappointed by that as I would have expected information to be saved in a JSON file or something similar. But according to Orchestrator author (Shlomi Noach) this is planned !

In your MySQL 5.7 repository instance create a database and an account to use it:

mysql> CREATE DATABASE IF NOT EXISTS orchestrator;
Query OK, 1 row affected (0.00 sec)

mysql> GRANT ALL PRIVILEGES ON `orchestrator`.* TO 'orchestrator'@'%' IDENTIFIED BY 'secure_password';
Query OK, 0 rows affected (0.00 sec)

Copy and edit the Orchestrator configuration file:

[root@server4 ~]# cd /usr/local/orchestrator/
[root@server4 orchestrator]# cp orchestrator-sample.conf.json /etc/orchestrator.conf.json
[root@server4 orchestrator]# vi /etc/orchestrator.conf.json

What I have changed inside to match my configuration:

  "MySQLOrchestratorHost": "127.0.0.1",
  "MySQLOrchestratorPort": 3316,
  "MySQLOrchestratorDatabase": "orchestrator",
  "MySQLOrchestratorUser": ""orchestrator",
  "MySQLOrchestratorPassword": "secure_password",

For better display I have also customized:

  "RemoveTextFromHostnameDisplay": ".domain.com",

And also remove the default verbose output, re-activate it if you face any issue:

  "Debug": false,

Log file in case of issue is located at /var/log/orchestrator.log.

On all MariaDB instance create the Orchestrator account with:

GRANT SUPER, PROCESS, REPLICATION SLAVE, RELOAD ON *.* TO 'orchestrator'@'%' IDENTIFIED BY 'secure_password';

To start Orchestrator you need to move first to its directory because if you issue:

[root@server4 ~]# /usr/local/orchestrator/orchestrator --debug http &

You will get below error message:

html/template: "templates/layout" is undefined

Because resources directory is not accessible by daemon at startup so better use:

[root@server4 ~]# cd  /usr/local/orchestrator/
[root@server4 orchestrator]# ./orchestrator --debug http &
2016-06-24 15:05:20 INFO starting orchestrator
2016-06-24 15:05:20 INFO Read config: /etc/orchestrator.conf.json
2016-06-24 15:05:20 DEBUG Initializing orchestrator
2016-06-24 15:05:20 DEBUG Migrating database schema
2016-06-24 15:05:20 FATAL Cannot initiate orchestrator: Error 1067: Invalid default value for 'end_timestamp'

If you encounter this error this is because of the value of SQL mode for your backend repository instance and more specifically the NO_ZERO_DATE option:

mysql> show variables like 'sql_mode';
+---------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Variable_name | Value                                                                                                                                                                |
+---------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| sql_mode      | PIPES_AS_CONCAT,STRICT_TRANS_TABLES,STRICT_ALL_TABLES,NO_ZERO_IN_DATE,NO_ZERO_DATE,ERROR_FOR_DIVISION_BY_ZERO,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION |
+---------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------+
1 row in set (0.01 sec)

So change sql_mode to something like:

sql_mode=oracle

Which gives:

mysql> show variables like 'sql_mode';
+---------------+----------------------------------------------------------------------------------------------------------------------+
| Variable_name | Value                                                                                                                |
+---------------+----------------------------------------------------------------------------------------------------------------------+
| sql_mode      | PIPES_AS_CONCAT,ANSI_QUOTES,IGNORE_SPACE,ORACLE,NO_KEY_OPTIONS,NO_TABLE_OPTIONS,NO_FIELD_OPTIONS,NO_AUTO_CREATE_USER |
+---------------+----------------------------------------------------------------------------------------------------------------------+
1 row in set (0.04 sec)

When started access your Orchestrator node on default port 3000 and in Discover menu start to add the node of your topology. At then end you should get something like:

orchestrator01
orchestrator01

If you click on gear icon along server name you have access to few customization, for master server:

orchestrator02
orchestrator02

For slave server (read only option is directly accessible):

orchestrator03
orchestrator03

You can also use commend line to display it:

[root@server4 ~]# /usr/local/orchestrator/orchestrator -c topology -i server2:3316 cli
server2.domain.com:3316   [0s,ok,10.1.14-MariaDB,rw,ROW]
+ server3.domain.com:3316 [0s,ok,10.1.14-MariaDB,rw,ROW,GTID]
+ server3.domain.com:3326 [0s,ok,10.1.14-MariaDB,rw,ROW,GTID]

Orchestrator testing

I have faced issues when trying to drag and drop my slaves, for example if I try to make server3.domain.com:3326 a slave of server3.domain.com:3316 then it is not possible:

orchestrator04
orchestrator04

If my master server fails Orchestrator report it but I have no option to restart it. To do this it would require an agent or a system connection to remote, Orchestrator agent is available but it would be a much complex implementation. Here, same, if I try to make make server3.domain.com:3326 a slave of server3.domain.com:3316 then it is not possible:

orchestrator05
orchestrator05

As no error message with graphical interface I have tried command line and now error message is clear:

[root@server4 ~]# /usr/local/orchestrator/orchestrator -c relocate -i server3.domain.com:3326 -d server3.domain.com:3316
2016-06-29 15:45:51 DEBUG Initializing orchestrator
2016-06-29 15:45:51 ERROR server3.domain.com:3326 cannot replicate from server3.domain.com:3316. Reason: instance does not have log_slave_updates enabled: server3.domain.com:3316
2016-06-29 15:45:51 FATAL 2016-06-29 15:45:51 ERROR server3.domain.com:3326 cannot replicate from server3.domain.com:3316. Reason: instance does not have log_slave_updates enabled: server3.domain.com:3316

So I activated log_slave_updates parameter in my.cnf file of all my instances (in case my master becomes a slave) as the parameter is not dynamic:

MariaDB [(none)]> show variables like '%log_slave_updates%';
+-------------------+-------+
| Variable_name     | Value |
+-------------------+-------+
| log_slave_updates | OFF   |
+-------------------+-------+
1 row in set (0.00 sec)

MariaDB [(none)]> set global log_slave_updates=on;
ERROR 1238 (HY000): Variable 'log_slave_updates' is a read only variable

Once activated we see a difference in printing with the stripes along the servers either graphical or command line:

[root@server4 ~]# /usr/local/orchestrator/orchestrator -c topology -i server2:3316 cli
server2.domain.com:3316   [0s,ok,10.1.14-MariaDB,rw,ROW,>>]
+ server3.domain.com:3316 [0s,ok,10.1.14-MariaDB,rw,ROW,>>,GTID]
+ server3.domain.com:3326 [0s,ok,10.1.14-MariaDB,rw,ROW,>>,GTID]

If my master fail (or in case you want to cascade the slaves) I make server3.domain.com:3316 my new master and stop replication on it (you would do the same in case you have only one slave). I set server3.domain.com:3326 a slave of server3.domain.com:3116:

orchestrator06
orchestrator06
orchestrator07
orchestrator07

But the graphical interface does not allow me to put back server2.domain.com:3316 a slave and even command line is asking me to do it manually:

[root@server4 ~]# /usr/local/orchestrator/orchestrator -c relocate -i server2.domain.com:3316 -d server3.domain.com:3316
2016-06-30 15:12:36 ERROR Relocating server2.domain.com:3316 below server3.domain.com:3316 turns to be too complex; please do it manually
2016-06-30 15:12:36 FATAL 2016-06-30 15:12:36 ERROR Relocating server2.domain.com:3316 below server3.domain.com:3316 turns to be too complex; please do it manually

So you end up with this configuration made of two clusters:

orchestrator08
orchestrator08

And the main one is made of two servers:

orchestrator09
orchestrator09

Obviously nothing cannot be done command line to recover original situation but for this Orchestrator is of no help…

References

]]>
http://blog.yannickjaquier.com/mysql/orchestrator-tutorial.html/feed 0
Directory naming configuration and usage (ldap.ora) – part 3 http://blog.yannickjaquier.com/oracle/directory-naming-configuration-usage-3.html http://blog.yannickjaquier.com/oracle/directory-naming-configuration-usage-3.html#comments Fri, 02 Jun 2017 09:33:18 +0000 http://blog.yannickjaquier.com/?p=3771

Table Of Contents

  1. Preamble
  2. Directory naming configuration
  3. References
 

Preamble

In first part we have seen WebLogic installation and configuration, in second part we have seen Oracle Internet directory (OID) installation and configuration. This final third part is about configuring directory naming for your client to make use of Oracle connect descriptors you have inserted in LDAP directory.

Directory naming configuration

We are finally ready to add Oracle connect descriptors in our newly created OID. What I recommend to do is to use the SQL*Net layer of your Oracle database repository.

In $ORACLE_HOME/network/admin directory of your repository database activate directory naming by creating a ldap.ora file that should looks like:

DIRECTORY_SERVERS = (server1.domain.com:3060:3131)
DIRECTORY_SERVER_TYPE = OID
DEFAULT_ADMIN_CONTEXT = "dc=sgp, dc=st, dc=com"

And modify below parameter in sqlnet.ora file in same directory to handle LDAP directory. I prefer to keep TNSNAMES first to let a chance to user to overwrite LDAP entries, could be dangerous but more flexible for them. This sqlnet.ora file should be modified for all clients that you wish to use your directory server.:

NAMES.DIRECTORY_PATH= (TNSNAMES, LDAP)

Execute Network Manager (netmgr):

directory_naming57
directory_naming57

Expand directory part and connect with cn=orcladmin account and password you specified when installing OID:

directory_naming58
directory_naming58

Press green arrow in left toolbar when selection is Service Naming to create a new LDAP Oracle connect descriptor. You can even create one for your repository database as a test:

directory_naming59
directory_naming59

Protocol for your Oracle connect descriptor:

directory_naming60
directory_naming60

Server and port where is the database:

directory_naming61
directory_naming61

Service of the listener:

directory_naming62
directory_naming62

Test or finish to validate:

directory_naming63
directory_naming63

It now appears as a new entry under directory structure:

directory_naming64
directory_naming64

If you rush to test it it will most probably fail:

[oracle@server1 admin]$ tnsping orcl

TNS Ping Utility for Linux: Version 12.1.0.2.0 - Production on 13-JUN-2016 16:14:33

Copyright (c) 1997, 2014, Oracle.  All rights reserved.

Used parameter files:
/u01/app/oracle/product/12.1.0/dbhome_1/network/admin/sqlnet.ora

TNS-03505: Failed to resolve name

We have to change one property of OID to allow anonymous bind. And Enterprise Manager we have just configured will be of great help. Connect to it, still on http://server1.domain.com:7001/em, expand Identity and Access and select oid1. In management menu choose Administration and Server Properties as shown below:

directory_naming65
directory_naming65

Allow Anonymous bind as below and push Apply button to save:

directory_naming66
directory_naming66

If you do not have the graphical interface (in the case on no WebLogic) follow MOS note 947285.1. Create a text file like:

[oracle@server1 ~]$ cat ~oracle/anonymousbind.ldif
dn: cn=oid1,cn=osdldapd,cn=subconfigsubentry
changetype: modify
replace: orclAnonymousBindsFlag
orclAnonymousBindsFlag: 1

Then execute it with ldapmodify binary to change your LDAP directory (OID) property:

[oracle@server1 ~]$ export ORACLE_HOME=/u01/Middleware/Oracle_IDM1
[oracle@server1 ~]$ export PATH=$PATH:$ORACLE_HOME/bin
[oracle@server1 ~]$ ldapmodify -D cn=orcladmin -q -p 3060 -h server1.domain.com -f ~oracle/anonymousbind.ldif
Please enter bind password:
modifying entry cn=oid1,cn=osdldapd,cn=subconfigsubentry

Then when retesting the newly created OID service naming it should positively answer:

[oracle@server1 admin]$ tnsping orcl

TNS Ping Utility for Linux: Version 12.1.0.2.0 - Production on 13-JUN-2016 16:15:57

Copyright (c) 1997, 2014, Oracle.  All rights reserved.

Used parameter files:
/u01/app/oracle/product/12.1.0/dbhome_1/network/admin/sqlnet.ora

Used LDAP adapter to resolve the alias
Attempting to contact (DESCRIPTION=(ADDRESS_LIST=(ADDRESS=(PROTOCOL=TCP)(HOST=server1.domain.com)(PORT=1531)))(CONNECT_DATA=(SERVICE_NAME=orcl)))
OK (10 msec)

Notice the Used LDAP adapter to resolve the alias sentence to confirm Oracle connect descriptor has been resolved by your directory and not by your local tnsnames.ora file…

If you do not like Network Manager to handle your Oracle connect descriptors you can also use a generic LDAP browser as OID behaves like a normal LDAP directory. Here is an example with the first free one I have found searching on Google (JXplorer):

directory_naming67
directory_naming67

This graphical tool can also be used to modify LDAP property of your directory, for example the famous anonymous bind one from 2 to 1:

directory_naming71
directory_naming71

References

]]>
http://blog.yannickjaquier.com/oracle/directory-naming-configuration-usage-3.html/feed 1
Directory naming configuration and usage (ldap.ora) – part 2 http://blog.yannickjaquier.com/oracle/directory-naming-configuration-usage-2.html http://blog.yannickjaquier.com/oracle/directory-naming-configuration-usage-2.html#comments Fri, 02 Jun 2017 09:32:59 +0000 http://blog.yannickjaquier.com/?p=3770

Table Of Contents

  1. Preamble
  2. OID repository creation
  3. OID installation
  4. OID configuration
  5. References
 

Preamble

We have seen in first part how to install and configure WebLogic application server. This second part is about configuring the database repository with Repository Creation utility (RCU) and installing Oracle Internet Directory (OID).

OID repository creation

Before you can install Oracle Internet Directory (OID) you must first fill your repository database with required schemas. On the Oracle Identity Management 11g Downloads page download below utility:

  • Oracle Fusion Middleware Repository Creation Utility 11g (11.1.1.9.0)

The database I have used is an Enterprise Edition (we use only this edition) in 12.1.0.2.0, set processes and open_cursors parameters to 500 to avoid any warning. I’m not detailing this part as it should be more than obvious for you with, for example, Database Configuration Assistant (DBCA).

The downloaded file (ofm_rcu_linux_11.1.1.9.0_64_disk1_1of1.zip) can be unzip anywhere. In ./rcuHome/bin directory invoke Repository Creation Utility with rcu binary:

directory_naming21
directory_naming21

Choose to create the repository:

directory_naming22
directory_naming22

Supply your database information with, preferably, a SYS connection. After having supplied the connection credentials few checks are performed, if all is good press Ok or correct any raised problems:

directory_naming23
directory_naming23

Choose OID repository creation:

directory_naming24
directory_naming24

Choose a password for the accounts (ODS and ODSSM):

directory_naming25
directory_naming25

I have changed only the temporary tablespace:

directory_naming26
directory_naming26
directory_naming27
directory_naming27

Do not change the default tablespace or you will end up with:

ORA-01917: user or role 'ODS' does not exist

The tablespaces are hard coded in creation scripts so if you change to something else they are not created and RCU will fail… Wondering why they have left the capability to change then…

Summary of what will be done:

directory_naming28
directory_naming28

Ending window if all goes well:

directory_naming29
directory_naming29

OID installation

On the Oracle Identity Management 11g Downloads page download below files:

  • Identity Management (11.1.1.9.0)

Unzip the two files (ofm_idm_linux_11.1.1.9.0_64_disk1_1of2.zip and ofm_idm_linux_11.1.1.9.0_64_disk1_2of2.zip) and execute runInstaller in Disk1 directory:

directory_naming31
directory_naming31

For proxy reason and internet access restriction on my server I usually chose to avoid software update:

directory_naming32
directory_naming32

Choose install and configure:

directory_naming33
directory_naming33

Pre-requisites check, even if OEL 7 is certified I had few warning about too recent packages, I have obviously decided to ignore:

directory_naming34
directory_naming34

Specify credentials for your WebLogic domain:

directory_naming35
directory_naming35

I had this warning that I have also decided to ignore:

directory_naming36
directory_naming36

If you have decided not to install WebLogic you must choose below option instead:

directory_naming68
directory_naming68

Specify installation directories, WebLogic home and application name your have chosen (I kept at maximum default values):

directory_naming37
directory_naming37

The window is slightly different if you have chosen not to install WebLogic:

directory_naming69
directory_naming69

Again I already received plenty of security alerts:

directory_naming38
directory_naming38

Choose OID and I have also chosen Oracle Directory Service Manager (ODSM) but you will see later on that I have not been able to use it so not mandatory at all:

directory_naming39
directory_naming39

The window is much simpler in the case of no WebLogic:

directory_naming70
directory_naming70

Automatic port configuration but if you have special port requirements it can be customized

directory_naming40
directory_naming40

OID database schema that has been created with RCU:

directory_naming41
directory_naming41

OID domain. I have chosen the one I setup with OID 10g for ascending compatibility, choose anything you like that match your company. You also choose the password of LDAP administrator (cn=orcladmin):

directory_naming42
directory_naming42

Summary window:

directory_naming43
directory_naming43

You classically end up installation with execution of /u01/Middleware/Oracle_IDM1/oracleRoot.sh script as root…

directory_naming44
directory_naming44

OID configuration

While configuring all components I got an error saying my WebLogic server was not reachable. When moving to widow where I executed it I discovered it has failed…

Configuration of component follow installation process:

directory_naming45
directory_naming45

Ending successful window:

directory_naming46
directory_naming46

You can now control with Oracle Process Manager and Notification Server (OPMN) tool that everything is started and running well:

[oracle@server1 ~]$ /u01/Middleware/asinst_1/bin/opmnctl status

Processes in Instance: asinst_1
---------------------------------+--------------------+---------+---------
ias-component                    | process-type       |     pid | status
---------------------------------+--------------------+---------+---------
oid1                             | oidldapd           |   26401 | Alive
oid1                             | oidldapd           |   26397 | Alive
oid1                             | oidmon             |   26389 | Alive
EMAGENT                          | EMAGENT            |   25953 | Alive

OID is listening on port 3060 (LDAP, insecure) and 3131 (LDAPS, secure):

[oracle@server1 ~]$ netstat -an | grep LISTEN | grep -e 3060 -e 3131
tcp6       0      0 :::3060                 :::*                    LISTEN
tcp6       0      0 :::3131                 :::*                    LISTEN

You have also Oracle Directory Services Manager (ODSM) at http://server1.domain.com:7005/odsm but it was so buggy that I have not been able to really use it:

directory_naming47
directory_naming47

One tool that is nice to configure afterwards is Enterprise Manager. To do so execute the configuration utility of your WebLogic domain with /u01/Middleware/oracle_common/common/bin/config.sh and choose to configure an existing domain:

directory_naming48
directory_naming48

Chose your domain in directory list:

directory_naming49
directory_naming49

Add Oracle Enterprise Manager component:

directory_naming50
directory_naming50

Application location for your domain:

directory_naming51
directory_naming51

Let default:

directory_naming52
directory_naming52

Summary window:

directory_naming53
directory_naming53

I had a warning for an used port that is the one of WebLogic, maybe I should have stopped WebLogic before re-configuring it

directory_naming54
directory_naming54

Ending window:

directory_naming55
directory_naming55

Then stop and restart WebLogic by exiting and restarting /u01/Middleware/user_projects/domains/base_domain/startWebLogic.sh. You should then see at http://server1.domain.com:7001/em Enterprise Manager console that will help us to graphically modify an important setup of OID:

directory_naming56
directory_naming56

We are almost done move on to next part of the series (see references section below) to finally configure directory naming with your clients…

References

]]>
http://blog.yannickjaquier.com/oracle/directory-naming-configuration-usage-2.html/feed 1
Directory naming configuration and usage (ldap.ora) – part 1 http://blog.yannickjaquier.com/oracle/directory-naming-configuration-usage-1.html http://blog.yannickjaquier.com/oracle/directory-naming-configuration-usage-1.html#comments Fri, 02 Jun 2017 09:32:24 +0000 http://blog.yannickjaquier.com/?p=3693

Table Of Contents

  1. Preamble
  2. WebLogic installation
  3. WebLogic configuration
  4. References
 

Preamble

In a big company the need to have a central location for Oracle connect descriptors (SQL*Net connect strings) is more or less a must. At least the team handling PC support will ask for it to ease their job. Imagine that if you have a local tnsnames.ora file on all your clients, what if one day you need to change the name of one server when you migrate a database to a new hardware ?

The solution is called directory naming and is there since very long handle by different products as Oracle release is increasing.

The legacy product that centralize your Oracle connect descriptors (TNS string) entries is Oracle Names Server. This was a simple system process and a text file with all your entries, and yes we still have it:

orans1{oranames}# namesctl status

Oracle Names Control for HPUX: Version 9.2.0.6.0 - Production on 09-JUN-2016 11:22:05

Copyright (c) 1993, 2002 Oracle Corporation.  All rights reserved.

Currently managing name server "orans1.domain.com"
Version banner is "Oracle Names for HPUX: Version 9.2.0.6.0 - Production"

Version banner is "Oracle Names for HPUX: Version 9.2.0.6.0 - Production"

Server name:                              orans1.domain.com
Server has been running for:              249 days 11 hours 32 minutes 53.93 seconds
Request processing enabled:               yes
Request forwarding enabled:               yes
Requests received:                        2707
Requests forwarded:                       0
Foreign data items cached:                0
Region data next checked for reload in:   not set
Region data reload check failures:        0
Cache next checkpointed in:               not set
Cache checkpoint interval:                not set
Cache checkpoint file name:               /ora_names/software/network/names/ckpcch.ora
Statistic counters next reset in:         not set
Statistic counter reset interval:         not set
Statistic counters next logged in:        not set
Statistic counter logging interval:       not set
Trace level:                              0
Trace file name:                          /ora_names/software/network/trace/names.trc
Log file name:                            /ora_names/software/network/log/names.log
System parameter file name:               /ora_names/software/network/admin/names.ora
Command-line parameter file name:         ""
Administrative region name:               ""
Administrative region description:        ""
ApplTable Index:                          0
Contact                                   ""
Operational Status                        1
Save Config on Stop                       no

And the Oracle connect descriptors file:

orans1{oranames}# tail /ora_names/software/network/names/ckpdom.ora
        )

sid1_DB.world. = (DATA_LIST=(FLAGS=0x1)(TTL=86400)
    (DATA=(TYPE=a.smd.)(DESCRIPTION=(SOURCE_ROUTE=OFF)(ADDRESS_LIST=(ADDRESS=(PROTOCOL=TCP)(HOST=server1.domain.com)(PORT=1529)))(CONNECT_DATA=(SID=sid1)(SRVR=DEDICATED))) )
        )

sid2_eu.world. = (DATA_LIST=(FLAGS=0x1)(TTL=86400)
    (DATA=(TYPE=a.smd.)(DESCRIPTION=(SOURCE_ROUTE=OFF)(ADDRESS_LIST=(ADDRESS=(PROTOCOL=TCP)(HOST=server2.domain.com)(PORT=1525)))(CONNECT_DATA=(SID=sid2)(SRVR=DEDICATED))) )
        )

On your client you had to setup your sqlnet.ora file with something like:

NAMES.DEFAULT_DOMAIN = world

NAMES.PREFERRED_SERVERS =
  (ADDRESS_LIST =
    (ADDRESS = (PROTOCOL = TCP)(HOST = orans1.domain.com)(PORT = 1688))
  )

NAMES.DIRECTORY_PATH= (ONAMES)

It was really simple to setup and maintain. But starting with 10gR1 Oracle has decided this was too simple and replaced this implementation by a much complex one based on an LDAP-compliant directory. On latest 12cR1 Oracle client only Microsoft Active Directory (AD) and Oracle Internet Directory (OID) are supported. OID is part of Oracle Identity Management family. Their application server called WebLogic is not mandatory to run OID but without it you will have access to no graphical interface, which is ok if you are a bit familiar with LDAP.

If you install all those Oracle components to exclusively use them to serve Oracle connect descriptors then you have no licenses to purchase.

I started with Oracle Identity Management page and obviously tried latest release (at the time of writing this post) i.e. 11gR2 or more precisely 11gR2PS3 (11.1.2.3.0). After many unsuccessful tries I realized that OID was not yet available in this release which is confirmed by certification page where 1.1.1.9.0 is latest available certification page:

directory_naming01
directory_naming01

We also see that WebLogic 12cR2 cannot be used as only WebLogic 10.3.6 is certified !

My testing has been done on a virtual machine running Oracle Enterprise Linux 7.2 64 bits with an 12cR1 (12.1.0.2.0) Unicode (AL32UTF8) backend database.

You also need Java JDK on your server, at the time of writing it is 1.8.0_92, that I have installed with the provided rpm (jdk-8u92-linux-x64.rpm) and so under /usr/java. In certification page you can see that only Java 1.7 is certified and it should be the one you install. I’m anyway using latest one as from past experience Java descending compatibility as always been good even for product not yet certified on latest Java. Also from security point of view it makes no sense to install Java 1.7.

WebLogic installation

This component is optional, just remind that without it you will end up with no graphical interface.

From WebLogic 10.3.6 download page the generic Installers with Oracle WebLogic Server and Oracle Coherence cannot be used for OID as you will require below component for OID:

  • Java Required Files (JRF)

So the one to use is Installers with Oracle WebLogic Server, Oracle Coherence and Oracle Enterprise Pack for Eclipse, so downloading Linux x86 with 32-bit JVM (1.5 GB) hoping to use the 64 bits Java I have already installed on my server… File oepe-wls-indigo-installer-11.1.1.8.0.201110211138-10.3.6-linux32.bin is an executable so is not launched same as other with java -jar file.jar.

First installation screen:

directory_naming02
directory_naming02

Choose installation directory (/u01/Middleware for me):

directory_naming03
directory_naming03

Do you wish to receive security information:

directory_naming04
directory_naming04

Custom installation for better control:

directory_naming05
directory_naming05

Keep WebLogic installation option by default:

directory_naming06
directory_naming06

Choose to add Oracle Application Development Framework:

directory_naming07
directory_naming07

Choose the JDK you have installed, that is not default option, the ones that come with installation binaries are a bit obsolete. If you refer to certification picture above normally only JDK 1.7.0 is certified:

directory_naming08
directory_naming08

Let default installation sub directories:

directory_naming09
directory_naming09

Summary of what will be done:

directory_naming10
directory_naming10

Ending windows if you got no issue:

directory_naming11
directory_naming11

WebLogic configuration

Once WebLogic has been installed launch the configuration script available at /u01/Middleware/oracle_common/common/bin/config.sh. Choose to create a new WebLogic domain:

directory_naming12
directory_naming12

Add Oracle JRF mandatory option:

directory_naming13
directory_naming13

I have left default name and default deployment directory:

directory_naming14
directory_naming14

Choose a password for your WebLogic administrator account:

directory_naming15
directory_naming15

I have chosen production mode with my already installed Java release:

directory_naming16
directory_naming16

Check Administration Server to benefit from graphical administrative tool:

directory_naming17
directory_naming17

Feeding with server name and kept default port (7001):

directory_naming18
directory_naming18

Summary of what will be done:

directory_naming19
directory_naming19

Ending window with url to be used for graphical interface:

directory_naming20
directory_naming20

Finally start WebLogic with:

[oracle@server1 ~]$ /u01/Middleware/user_projects/domains/base_domain/startWebLogic.sh

This will most probably fail after you have interactively entered account with:

Enter username to boot WebLogic server:weblogic
Java HotSpot(TM) 64-Bit Server VM warning: You have loaded library /u01/Middleware/wlserver_10.3/server/native/linux/i686/libterminalio.so which might have disabled stack guard. The VM will try to fix the stack guard now.
It's highly recommended that you fix the library with 'execstack -c ', or link it with '-z noexecstack'.
    
    
    >
    

Follow MOS note 1354736.1 to correct it.

Or you can also follow MOS note 475060.1 to avoid to be obliged to supply account/password each time you start it…

This is last one I have decided to follow. In short you create a boot.properties file with account and password:

[oracle@server1 ~]$ cd /u01/Middleware/user_projects/domains/base_domain/servers/server1.domain.com
[oracle@server1 server1.domain.com]$ mkdir security
[oracle@server1 server1.domain.com]$ cd security
[oracle@server1 server1.domain.com]$ vit boot.properties
[oracle@server1 server1.domain.com]$ cat boot.properties
username=weblogic
password=secure_password

When you start WebLogic server, of course account and password are no more requested, and the file is encrypted to protect password value:

[oracle@server1 ~]$ cat /u01/Middleware/user_projects/domains/base_domain/servers/server1.domain.com/security/boot.properties
#Fri Jun 10 12:16:32 CEST 2016
password={AES}mrdERtPxVBTSr5lsdau1gPC2rjVxBN1MdyAaIUD8qQo\=
username={AES}p4aYO8sUChgMxKINU2fc8dgc0kidumyPBlDVmKNGthU\=

You can then access to administrative web interface on http://server1.domain.com:7001/console:

directory_naming30
directory_naming30

This, optional, first part of the series for directory naming implementation is over (!!). I told you Oracle has not made it simple. Move on to second part with link in references section.

References

]]>
http://blog.yannickjaquier.com/oracle/directory-naming-configuration-usage-1.html/feed 2
MariaDB Connector/J high availability features testing http://blog.yannickjaquier.com/mysql/mariadb-connectorj-high-availability.html http://blog.yannickjaquier.com/mysql/mariadb-connectorj-high-availability.html#respond Thu, 04 May 2017 13:45:28 +0000 http://blog.yannickjaquier.com/?p=3573

Table Of Contents

  1. Preamble
  2. MariaDB replication setup
  3. MariaDB Connector/J high availability testing
  4. Conclusion
  5. References
 

Preamble

I have already tested MySQL Connector/J in high availability scenarios using MySQL replication (master/slave). The testing has not gone as expected and I reached the conclusion that an additional product must be put in loop to achieve what I expected.

MariaDB foundation is also proposing it’s own Connector/J obviously called MariaDB Connector/J. Is it different from the one of Oracle ? Working better ? Working worst ? One feature that MariaDB does not have versus the one of Oracle is dynamic reconfiguration of replication group though JMX (if you add or delete a slave or master). It’s also not 100% clear (not tested) if MariaDB connector/J load balance the load on slaves in case you have multiple slaves, MySQL Connector/J does it and it is well written in documentation…

I have decided to test it in a typical MySQL replication scenario. Where the master could failed or when my only slave could failed.

For testing I have used two virtual machines running Oracle Linux Server release 7.2 64 bits and MariaDB 10.1.13. The virtual servers are:

  • server3.domain.com using non routable IP address 192.168.56.103
  • server4.domain.com using non routable IP address 192.168.56.104

The Java application is running on my desktop under Eclipse with Java 1.8.0_77 and MariaDB Connector/J 1.4.0. The is almost the same code as the one used for MySQL Connecter/J with few minor changes.

MariaDB replication setup

First step is to setup MariaDB replication that is slightly different from the one of MySQL. Please note that if they both use GTID they are not compatible…

On both server I create a test database, test table and the replication account:

MariaDB [(none)]> GRANT REPLICATION SLAVE ON *.* TO 'repadmin'@'%' IDENTIFIED BY 'secure_password';
Query OK, 0 rows affected (0.00 sec)

MariaDB [(none)]> CREATE DATABASE replicationdb CHARACTER SET utf32 COLLATE utf32_general_ci;
Query OK, 1 row affected (0.00 sec)

MariaDB [(none)]> use replicationdb
Database changed

MariaDB [replicationdb]> CREATE TABLE test1(val int, descr varchar(50));
Query OK, 0 rows affected (0.01 sec)

MariaDB [replicationdb]> insert into test1 values(1,'One');
Query OK, 1 row affected (0.00 sec)

On master server I get current position (not to start from beginning):

MariaDB [replicationdb]> SHOW MASTER STATUS;
+------------------+----------+--------------+------------------+
| File             | Position | Binlog_Do_DB | Binlog_Ignore_DB |
+------------------+----------+--------------+------------------+
| mysql-bin.000001 |     2631 |              |                  |
+------------------+----------+--------------+------------------+
1 row in set (0.00 sec)

MariaDB [replicationdb]> SELECT BINLOG_GTID_POS("mysql-bin.000001",2631);
+------------------------------------------+
| BINLOG_GTID_POS("mysql-bin.000001",2631) |
+------------------------------------------+
| 0-1-8                                    |
+------------------------------------------+

On slave server I setup replication with:

MariaDB [(none)]> SET GLOBAL gtid_slave_pos = "0-1-8";
Query OK, 0 rows affected (0.00 sec)

MariaDB [(none)]> change master to master_host='server3.domain.com', master_port=3316,master_user='repadmin', 
               -> master_password='secure_password', master_use_gtid=slave_pos;
Query OK, 0 rows affected (0.00 sec)

MariaDB [(none)]> start slave;
Query OK, 0 rows affected (0.00 sec)

MariaDB [(none)]> SHOW SLAVE STATUS\G
*************************** 1. row ***************************
               Slave_IO_State: Waiting for master to send event
                  Master_Host: server3.domain.com
                  Master_User: repadmin
                  Master_Port: 3316
                Connect_Retry: 60
              Master_Log_File: mysql-bin.000001
          Read_Master_Log_Pos: 2631
               Relay_Log_File: mysql01-relay-bin.000002
                Relay_Log_Pos: 640
        Relay_Master_Log_File: mysql-bin.000001
             Slave_IO_Running: Yes
            Slave_SQL_Running: Yes
              Replicate_Do_DB:
          Replicate_Ignore_DB:
           Replicate_Do_Table:
       Replicate_Ignore_Table:
      Replicate_Wild_Do_Table:
  Replicate_Wild_Ignore_Table:
                   Last_Errno: 0
                   Last_Error:
                 Skip_Counter: 0
          Exec_Master_Log_Pos: 2631
              Relay_Log_Space: 940
              Until_Condition: None
               Until_Log_File:
                Until_Log_Pos: 0
           Master_SSL_Allowed: No
           Master_SSL_CA_File:
           Master_SSL_CA_Path:
              Master_SSL_Cert:
            Master_SSL_Cipher:
               Master_SSL_Key:
        Seconds_Behind_Master: 0
Master_SSL_Verify_Server_Cert: No
                Last_IO_Errno: 0
                Last_IO_Error:
               Last_SQL_Errno: 0
               Last_SQL_Error:
  Replicate_Ignore_Server_Ids:
             Master_Server_Id: 1
               Master_SSL_Crl:
           Master_SSL_Crlpath:
                   Using_Gtid: Slave_Pos
                  Gtid_IO_Pos: 0-1-8
      Replicate_Do_Domain_Ids:
  Replicate_Ignore_Domain_Ids:
                Parallel_Mode: conservative
1 row in set (0.00 sec)

And you are done already !

Let’s do a small test by inserting a new row on master server:

MariaDB [replicationdb]> insert into replicationdb.test1 values(2,'Two');
Query OK, 1 row affected (0.00 sec)

MariaDB [replicationdb]> select * from replicationdb.test1;
+------+-------+
| val  | descr |
+------+-------+
|    1 | One   |
|    2 | Two   |
+------+-------+
2 rows in set (0.00 sec)

On slave server the row is replicated:

MariaDB [(none)]>  select * from replicationdb.test1;
+------+-------+
| val  | descr |
+------+-------+
|    1 | One   |
|    2 | Two   |
+------+-------+
2 rows in set (0.00 sec)

MariaDB Connector/J high availability testing

To test this I’m using the same dummy application I have already used doing read/write and read/only connections. The read/write connection can be initiated only on master server while the read/only connection can be issued on master server when slave server is down.

To start the application all servers must be up and running unless the connection does not succeed or you may need to change the JDBC_URL variable value to reflect remaining servers.

The different scenarios I’m planning to test are:

  • Failure of my unique slave, no impact expected as master can serve read/only transactions
  • Failure of master server, all read/write transactions are no more possible as only read/only ones can be served by surviving slave server

The source code of my application is the following, please note I initiate one unique connection and I do not reconnect each time. The java code is a loop of set the transaction read/write do a query, then set the transaction read/only and do a query. To know on which server the query is executed I simply select the environment variable that is returning server name:

package jdbcdemo1;

import org.mariadb.jdbc.Driver;

import java.sql.ResultSet;
import java.util.Properties;
import java.sql.Connection;
import java.sql.SQLException;

public class jdbcdemo1 {
  public static void main(String[] args) throws Exception {
    Driver driver = new Driver();
    Properties props = new Properties();
    ResultSet rs;
    String variable_value;
    Connection conn = null;
    String JDBC_URL = "jdbc:mysql:replication://address=(host=192.168.56.103)(port=3316)(type=master),"
    				+ "address=(host=192.168.56.104)(port=3316)(type=slave)";
		
    props.put("retriesAllDown","5");
    props.put("user", "yjaquier");
    props.put("password", "secure_password");

    System.out.println("\n------------ MariaDB Connector/J and MariaDB Replication Testing ------------\n");

    System.out.println("Trying connection...");
    try {
    	conn = driver.connect(JDBC_URL, props);
    	}
    catch (SQLException e) {
    	System.out.println("Connection Failed!");
    	System.out.println("Error cause: "+e.getCause());
    	System.out.println("Error message: "+e.getMessage());
    	return;
    }

    System.out.println("Connection established...");

    for(int i=1; i <= 1000; i++) {
    
// Read write query that can be performed ONLY on master server

        System.out.println("\nQuery "+i+": ");
    	// Fake Read Write SQL statement (just to see where it goes)
    	System.out.println("Read Write query...");
    	try {
    		conn.setReadOnly(false);
    	}
    	catch (SQLException e) {
    		System.out.println("Connection read write property set has failed...");
    	}

    	if (conn.isReadOnly() == false) {
    		try {
    			rs = conn.createStatement().executeQuery("SELECT variable_value FROM information_schema.global_variables " +
                                                                 "WHERE variable_name='hostname'");
    			while (rs.next()) {
    				variable_value = rs.getString("variable_value");
    				System.out.println("variable_value : " + variable_value);
    			}
    		}
    		catch (SQLException e) {
    			System.out.println("Read/write query has failed...");
    		}
    	}

// Read Only statement (that can also be done on master server if all slaves are down)
    	System.out.println("Read Only query...");
    	try {
    		conn.setReadOnly(true);	
    	}
    	catch (SQLException e) {
    		System.out.println("Connection read only property set has failed...");
    	}
   		try {
   			rs = conn.createStatement().executeQuery("SELECT variable_value FROM information_schema.global_variables " +
                                                                 "WHERE variable_name='hostname'");
   			while (rs.next()) {
   				variable_value = rs.getString("variable_value");
   				System.out.println("variable_value : " + variable_value);
   				}
   			}
   		catch (SQLException e) {
   			System.out.println("Read only query has failed...");
   			}
    	
    	Thread.sleep(2000);
    }
    conn.close();
  }
}

The only MariaDB Connector/J parameter I have used is retriesAllDown otherwise you wait really too long to have the read/write status setting to false failing...

First testing is a failure of my unique slave server (if you have multiple that's not even a failure as your others slaves can handle the work). This case is nicely done by MariaDB connector/J. When the slave fail the current query fails but the further ones are proceeded by master server (as expected). Read/write queries are unaffected:

mariadbconnectorj01
mariadbconnectorj01

When you recover you slave server read/only queries go to it automatically without re-connection:

mariadbconnectorj02
mariadbconnectorj02

Second testing is master server failure. In this situation we expect slave server to handle read/only queries but read/write ones cannot be proceeded. This is handle is my java code by forbidding them in case the read/write property cannot be set:

mariadbconnectorj03
mariadbconnectorj03

Once master server is recovered the read/write queries are again possible:

mariadbconnectorj04
mariadbconnectorj04

Conclusion

Upfront MariaDB Connector/J might not be seen so appealing versus MySQL Connector/J. The MariaDB Connector/J is (apparently) lacking many advanced features. But what I have tested is that it does very well the basic we expect from such Java connector when working with a massively deployed MySQL (or MariaDB) replication environment. This is not what I have seen with MySQL Connector/J with similar architecture...

One issue I have seen is that they are not exact drop-ins replacement as MySQL Connecter/J 5.1.28 is not working with MariaDB 10.1.13. I have anyway no doubt, even if untested, that MariaDB Connecter/J works with MySQL 5.6 and above... So once you have decided which backend MySQL fork you will use it may, for compatibility issues, decide for yourself which Connector/J to implement...

References

]]>
http://blog.yannickjaquier.com/mysql/mariadb-connectorj-high-availability.html/feed 0