|
| 1 | +# Using Roles in MySQL 8.0 to Grant Privileges to mysql.rds_topology |
| 2 | + |
| 3 | +For customers using the [Blue/Green plugin](UsingTheBlueGreenPlugin.md) for their planned [Blue/Green Deployment](https://docs.aws.amazon.com/whitepapers/latest/blue-green-deployments/introduction.html), every user account on the DB instance/cluster needs to be granted SELECT privileges to the `mysql.rds_topology` metadata table. This creates an extra operational overhead for customers to adopt fast switchovers. |
| 4 | + |
| 5 | +This document uses [MySQL roles](https://dev.mysql.com/doc/refman/8.0/en/roles.html) to reduce complexity for multi-user grant to read from `mysql.rds_topology`. |
| 6 | + |
| 7 | +## Prerequisites |
| 8 | + |
| 9 | +1. First we need to create a role that grants `SELECT` privilege to `mysql.rds_topology`. |
| 10 | + ```bash |
| 11 | + mysql> CREATE ROLE 'rds_topology_role'; |
| 12 | + Query OK, 0 rows affected (0.06 sec) |
| 13 | + |
| 14 | + mysql> GRANT SELECT ON mysql.rds_topology TO 'rds_topology_role'; |
| 15 | + Query OK, 0 rows affected (0.06 sec) |
| 16 | + ``` |
| 17 | +2. Then create our test application users. |
| 18 | + ```bash |
| 19 | + mysql> CREATE USER 'app1'@'%' IDENTIFIED BY 'Amaz0n1an_'; |
| 20 | + Query OK, 0 rows affected (0.06 sec) |
| 21 | + |
| 22 | + mysql> CREATE USER 'app2'@'%' IDENTIFIED BY 'Amaz0n1an_'; |
| 23 | + Query OK, 0 rows affected (0.07 sec) |
| 24 | + |
| 25 | + mysql> SHOW GRANTS FOR 'app1'@'%'; |
| 26 | + +----------------------------------+ |
| 27 | + | Grants for app1@% | |
| 28 | + +----------------------------------+ |
| 29 | + | GRANT USAGE ON *.* TO `app1`@`%` | |
| 30 | + +----------------------------------+ |
| 31 | + 1 row in set (0.06 sec) |
| 32 | + |
| 33 | + mysql> SHOW GRANTS FOR 'app2'@'%'; |
| 34 | + +----------------------------------+ |
| 35 | + | Grants for app2@% | |
| 36 | + +----------------------------------+ |
| 37 | + | GRANT USAGE ON *.* TO `app2`@`%` | |
| 38 | + +----------------------------------+ |
| 39 | + 1 row in set (0.07 sec) |
| 40 | + ``` |
| 41 | + |
| 42 | +## Activate the Role |
| 43 | + |
| 44 | +### Option 1: [mandatory_roles](https://dev.mysql.com/doc/refman/8.0/en/server-system-variables.html#sysvar_mandatory_roles) with [SET DEFAULT ROLE](https://dev.mysql.com/doc/refman/8.0/en/set-default-role.html) |
| 45 | + |
| 46 | +This is recommended if there is only a small and static set of user accounts that require the privileges. |
| 47 | + |
| 48 | +| Pros | Cons | |
| 49 | +|-------------------------------------------------------------------------------|---------------------------------------------------------------------------------------| |
| 50 | +| Assign roles to ALL user accounts by default, activate only for select users. | The list of user accounts to revoke/activate the role becomes a maintenance overhead. | |
| 51 | + |
| 52 | +First modify the cluster parameter group to add the role `rds_topology_role` we created as a global mandatory role. |
| 53 | + |
| 54 | +```bash |
| 55 | +mysql> select @@global.mandatory_roles; |
| 56 | ++--------------------------+ |
| 57 | +| @@global.mandatory_roles | |
| 58 | ++--------------------------+ |
| 59 | +| rds_topology_role | |
| 60 | ++--------------------------+ |
| 61 | +1 row in set (0.06 sec) |
| 62 | +
|
| 63 | +``` |
| 64 | +
|
| 65 | +When the application users connect, they will see that the role will be granted but not active. |
| 66 | +
|
| 67 | +```bash |
| 68 | +mysql> SELECT CURRENT_USER(); |
| 69 | ++----------------+ |
| 70 | +| CURRENT_USER() | |
| 71 | ++----------------+ |
| 72 | +| app1@% | |
| 73 | ++----------------+ |
| 74 | +1 row in set (0.07 sec) |
| 75 | +
|
| 76 | +mysql> SHOW GRANTS \G |
| 77 | +*************************** 1. row *************************** |
| 78 | +Grants for app1@%: GRANT USAGE ON *.* TO `app1`@`%` |
| 79 | +*************************** 2. row *************************** |
| 80 | +Grants for app1@%: GRANT `rds_topology_role`@`%` TO `app1`@`%` |
| 81 | +2 rows in set (0.06 sec) |
| 82 | +
|
| 83 | +mysql> SELECT * FROM mysql.rds_topology; |
| 84 | +ERROR 1142 (42000): SELECT command denied to user 'app1'@'172.44.75.29' |
| 85 | +for table 'rds_topology' |
| 86 | +``` |
| 87 | +
|
| 88 | +To activate the role, we can use `SET DEFAULT ROLE` via the customer admin account, then we should be able to query the |
| 89 | +metadata table. |
| 90 | +
|
| 91 | +```bash |
| 92 | +mysql> SET DEFAULT ROLE 'rds_topology_role' TO 'app1'@'%', 'app2'@'%'; |
| 93 | +Query OK, 0 rows affected (0.07 sec) |
| 94 | +``` |
| 95 | +
|
| 96 | +The application users should be able to query the topology metadata at this time. |
| 97 | +
|
| 98 | +```bash |
| 99 | +mysql> SHOW GRANTS \G |
| 100 | +*************************** 1. row *************************** |
| 101 | +Grants for app1@%: GRANT USAGE ON *.* TO `app1`@`%` |
| 102 | +*************************** 2. row *************************** |
| 103 | +Grants for app1@%: GRANT SELECT ON `mysql`.`rds_topology` TO `app1`@`%` |
| 104 | +*************************** 3. row *************************** |
| 105 | +Grants for app1@%: GRANT `rds_topology_role`@`%` TO `app1`@`%` |
| 106 | +3 rows in set (0.06 sec) |
| 107 | +
|
| 108 | +mysql> SELECT * FROM mysql.rds_topology; |
| 109 | ++------------+----------------------------------------------------------------------------+------+------------------------------+-----------+---------+ |
| 110 | +| id | endpoint | port | role | status | version | |
| 111 | ++------------+----------------------------------------------------------------------------+------+------------------------------+-----------+---------+ |
| 112 | +| 1116047085 | bgd113287-green-adbzs8.cluster-cyfc0ofzobmh.us-east-1-qa.rds.amazonaws.com | 3306 | |
| 113 | +BLUE_GREEN_DEPLOYMENT_TARGET | AVAILABLE | 1.0 | |
| 114 | +| 1125403360 | bgd113287.cluster-cyfc0ofzobmh.us-east-1-qa.rds.amazonaws.com | 3306 | BLUE_GREEN_DEPLOYMENT_SOURCE | |
| 115 | +AVAILABLE | 1.0 | |
| 116 | ++------------+----------------------------------------------------------------------------+------+------------------------------+-----------+---------+ |
| 117 | +2 rows in set (0.06 sec) |
| 118 | +
|
| 119 | +``` |
| 120 | +
|
| 121 | +### Option 2: [mandatory_roles](https://dev.mysql.com/doc/refman/8.0/en/server-system-variables.html#sysvar_mandatory_roles) with [activate_all_roles_on_login](https://dev.mysql.com/doc/refman/8.0/en/server-system-variables.html#sysvar_activate_all_roles_on_login) |
| 122 | +
|
| 123 | +This is recommended if the list of user accounts that require access to the topology metadata table is dynamic. |
| 124 | +
|
| 125 | +| Pros | Cons | |
| 126 | +|-------------------------------------------------------------|----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------| |
| 127 | +| Assign and activate the role at the same time to ALL users. | Existing users may have assigned but deactivated roles. `activate_all_roles_on_login` will override this behavior and also activate all roles assigned to existing users aside from `rds_topology_role`. | |
| 128 | +
|
| 129 | +First modify the cluster parameter group to add the role `rds_topology_role` we created as a global mandatory role and |
| 130 | +enable `activate_all_roles_on_login`. |
| 131 | +
|
| 132 | +```bash |
| 133 | +mysql> SELECT @@global.activate_all_roles_on_login, @@global.mandatory_roles; |
| 134 | ++--------------------------------------+--------------------------+ |
| 135 | +| @@global.activate_all_roles_on_login | @@global.mandatory_roles | |
| 136 | ++--------------------------------------+--------------------------+ |
| 137 | +| 1 | rds_topology_role | |
| 138 | ++--------------------------------------+--------------------------+ |
| 139 | +1 row in set (0.06 sec) |
| 140 | +``` |
| 141 | +
|
| 142 | +After these changes, ALL users will be assigned the new role and it will also be active. |
| 143 | +
|
| 144 | +```bash |
| 145 | +mysql> SHOW GRANTS \G |
| 146 | +*************************** 1. row *************************** |
| 147 | +Grants for app1@%: GRANT USAGE ON *.* TO `app1`@`%` |
| 148 | +*************************** 2. row *************************** |
| 149 | +Grants for app1@%: GRANT SELECT ON `mysql`.`rds_topology` TO `app1`@`%` |
| 150 | +*************************** 3. row *************************** |
| 151 | +Grants for app1@%: GRANT `rds_topology_role`@`%` TO `app1`@`%` |
| 152 | +3 rows in set (0.06 sec) |
| 153 | +
|
| 154 | +mysql> SELECT * FROM mysql.rds_topology; |
| 155 | ++------------+----------------------------------------------------------------------------+------+------------------------------+-----------+---------+ |
| 156 | +| id | endpoint | port | role | status | version | |
| 157 | ++------------+----------------------------------------------------------------------------+------+------------------------------+-----------+---------+ |
| 158 | +| 1116047085 | bgd113287-green-adbzs8.cluster-cyfc0ofzobmh.us-east-1-qa.rds.amazonaws.com | 3306 | |
| 159 | +BLUE_GREEN_DEPLOYMENT_TARGET | AVAILABLE | 1.0 | |
| 160 | +| 1125403360 | bgd113287.cluster-cyfc0ofzobmh.us-east-1-qa.rds.amazonaws.com | 3306 | BLUE_GREEN_DEPLOYMENT_SOURCE | |
| 161 | +AVAILABLE | 1.0 | |
| 162 | ++------------+----------------------------------------------------------------------------+------+------------------------------+-----------+---------+ |
| 163 | +2 rows in set (0.06 sec)Ò |
| 164 | +``` |
0 commit comments