Skip to content

Commit

Permalink
feat[mysql_info]: add 'users_info' filter (#580)
Browse files Browse the repository at this point in the history
* add documentation for new mysql_info users_info filter

* Add integration tests for mysql_info users_info

* fix list parsing when cursor come from mysql_info

Mysql_info use a DictCursor and mysql_user a normal cursor.

* fix case when an account as same user but different host and password

* document why certain authentications plugins cause issues

* add version_added for users_info to the documentation

* Add 'users' description to differentiate it from 'users_info'

---------

Co-authored-by: Andrew Klychkov <[email protected]>
  • Loading branch information
laurent-indermuehle and Andersson007 authored Oct 23, 2023
1 parent 6b7cc14 commit 3ef9bda
Show file tree
Hide file tree
Showing 6 changed files with 492 additions and 12 deletions.
5 changes: 5 additions & 0 deletions changelogs/fragments/lie_mysql_info_users_info.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
---

minor_changes:

- mysql_info - add filter ``users_info`` (https://github.com/ansible-collections/community.mysql/pull/580).
59 changes: 49 additions & 10 deletions plugins/module_utils/user.py
Original file line number Diff line number Diff line change
Expand Up @@ -112,23 +112,40 @@ def get_grants(cursor, user, host):
return grants.split(", ")


def get_existing_authentication(cursor, user):
def get_existing_authentication(cursor, user, host):
# Return the plugin and auth_string if there is exactly one distinct existing plugin and auth_string.
cursor.execute("SELECT VERSION()")
if 'mariadb' in cursor.fetchone()[0].lower():
srv_type = cursor.fetchone()
# Mysql_info use a DictCursor so we must convert back to a list
# otherwise we get KeyError 0
if isinstance(srv_type, dict):
srv_type = list(srv_type.values())

if 'mariadb' in srv_type[0].lower():
# before MariaDB 10.2.19 and 10.3.11, "password" and "authentication_string" can differ
# when using mysql_native_password
cursor.execute("""select plugin, auth from (
select plugin, password as auth from mysql.user where user=%(user)s
and host=%(host)s
union select plugin, authentication_string as auth from mysql.user where user=%(user)s
) x group by plugin, auth limit 2
""", {'user': user})
and host=%(host)s) x group by plugin, auth limit 2
""", {'user': user, 'host': host})
else:
cursor.execute("""select plugin, authentication_string as auth from mysql.user where user=%(user)s
group by plugin, authentication_string limit 2""", {'user': user})
cursor.execute("""select plugin, authentication_string as auth
from mysql.user where user=%(user)s and host=%(host)s
group by plugin, authentication_string limit 2""", {'user': user, 'host': host})
rows = cursor.fetchall()
if len(rows) == 1:
return {'plugin': rows[0][0], 'auth_string': rows[0][1]}

# Mysql_info use a DictCursor so we must convert back to a list
# otherwise we get KeyError 0
if isinstance(rows, dict):
rows = list(rows.values())

if isinstance(rows[0], tuple):
return {'plugin': rows[0][0], 'plugin_auth_string': rows[0][1]}

if isinstance(rows[0], dict):
return {'plugin': rows[0].get('plugin'), 'plugin_auth_string': rows[0].get('auth')}
return None


Expand All @@ -149,7 +166,7 @@ def user_add(cursor, user, host, host_all, password, encrypted,

used_existing_password = False
if reuse_existing_password:
existing_auth = get_existing_authentication(cursor, user)
existing_auth = get_existing_authentication(cursor, user, host)
if existing_auth:
plugin = existing_auth['plugin']
plugin_hash_string = existing_auth['auth_string']
Expand Down Expand Up @@ -478,6 +495,12 @@ def pick(x):
return x

for grant in grants:

# Mysql_info use a DictCursor so we must convert back to a list
# otherwise we get KeyError 0
if isinstance(grant, dict):
grant = list(grant.values())

if not maria_role:
res = re.match("""GRANT (.+) ON (.+) TO (['`"]).*\\3@(['`"]).*\\4( IDENTIFIED BY PASSWORD (['`"]).+\\6)? ?(.*)""", grant[0])
else:
Expand Down Expand Up @@ -777,6 +800,11 @@ def get_resource_limits(cursor, user, host):
cursor.execute(query, (user, host))
res = cursor.fetchone()

# Mysql_info use a DictCursor so we must convert back to a list
# otherwise we get KeyError 0
if isinstance(res, dict):
res = list(res.values())

if not res:
return None

Expand All @@ -788,11 +816,22 @@ def get_resource_limits(cursor, user, host):
}

cursor.execute("SELECT VERSION()")
if 'mariadb' in cursor.fetchone()[0].lower():
srv_type = cursor.fetchone()
# Mysql_info use a DictCursor so we must convert back to a list
# otherwise we get KeyError 0
if isinstance(srv_type, dict):
srv_type = list(srv_type.values())

if 'mariadb' in srv_type[0].lower():
query = ('SELECT max_statement_time AS MAX_STATEMENT_TIME '
'FROM mysql.user WHERE User = %s AND Host = %s')
cursor.execute(query, (user, host))
res_max_statement_time = cursor.fetchone()

# Mysql_info use a DictCursor so we must convert back to a list
# otherwise we get KeyError 0
if isinstance(res_max_statement_time, dict):
res_max_statement_time = list(res_max_statement_time.values())
current_limits['MAX_STATEMENT_TIME'] = res_max_statement_time[0]

return current_limits
Expand Down
149 changes: 147 additions & 2 deletions plugins/modules/mysql_info.py
Original file line number Diff line number Diff line change
Expand Up @@ -19,7 +19,7 @@
description:
- Limit the collected information by comma separated string or YAML list.
- Allowable values are C(version), C(databases), C(settings), C(global_status),
C(users), C(engines), C(master_status), C(slave_status), C(slave_hosts).
C(users), C(users_info), C(engines), C(master_status), C(slave_status), C(slave_hosts).
- By default, collects all subsets.
- You can use '!' before value (for example, C(!settings)) to exclude it from the information.
- If you pass including and excluding values to the filter, for example, I(filter=!settings,version),
Expand Down Expand Up @@ -74,6 +74,9 @@
# Display only databases and users info:
# ansible mysql-hosts -m mysql_info -a 'filter=databases,users'
# Display all users privileges:
# ansible mysql-hosts -m mysql_info -a 'filter=users_info'
# Display only slave status:
# ansible standby -m mysql_info -a 'filter=slave_status'
Expand Down Expand Up @@ -122,6 +125,38 @@
- databases
exclude_fields: db_size
return_empty_dbs: true
- name: Clone users from one server to another
block:
# Step 1
- name: Fetch information from a source server
delegate_to: server_source
community.mysql.mysql_info:
filter:
- users_info
register: result
# Step 2
# Don't work with sha256_password and cache_sha2_password
- name: Clone users fetched in a previous task to a target server
community.mysql.mysql_user:
name: "{{ item.name }}"
host: "{{ item.host }}"
plugin: "{{ item.plugin | default(omit) }}"
plugin_auth_string: "{{ item.plugin_auth_string | default(omit) }}"
plugin_hash_string: "{{ item.plugin_hash_string | default(omit) }}"
tls_require: "{{ item.tls_require | default(omit) }}"
priv: "{{ item.priv | default(omit) }}"
resource_limits: "{{ item.resource_limits | default(omit) }}"
column_case_sensitive: true
state: present
loop: "{{ result.users_info }}"
loop_control:
label: "{{ item.name }}@{{ item.host }}"
when:
- item.name != 'root' # In case you don't want to import admin accounts
- item.name != 'mariadb.sys'
- item.name != 'mysql'
'''

RETURN = r'''
Expand Down Expand Up @@ -181,11 +216,31 @@
sample:
- { "Innodb_buffer_pool_read_requests": 123, "Innodb_buffer_pool_reads": 32 }
users:
description: Users information.
description: Return a dictionnary of users grouped by host and with global privileges only.
returned: if not excluded by filter
type: dict
sample:
- { "localhost": { "root": { "Alter_priv": "Y", "Alter_routine_priv": "Y" } } }
users_info:
description:
- Information about users accounts.
- The output can be used as an input of the M(community.mysql.mysql_user) plugin.
- Useful when migrating accounts to another server or to create an inventory.
- Does not support proxy privileges. If an account has proxy privileges, they won't appear in the output.
- Causes issues with authentications plugins C(sha256_password) and C(caching_sha2_password).
If the output is fed to M(community.mysql.mysql_user), the
``plugin_auth_string`` will most likely be unreadable due to non-binary
characters.
returned: if not excluded by filter
type: dict
sample:
- { "plugin_auth_string": '*1234567',
"name": "user1",
"host": "host.com",
"plugin": "mysql_native_password",
"priv": "db1.*:SELECT/db2.*:SELECT",
"resource_limits": { "MAX_USER_CONNECTIONS": 100 } }
version_added: '3.8.0'
engines:
description: Information about the server's storage engines.
returned: if not excluded by filter
Expand Down Expand Up @@ -238,6 +293,12 @@
get_connector_name,
get_connector_version,
)

from ansible_collections.community.mysql.plugins.module_utils.user import (
privileges_get,
get_resource_limits,
get_existing_authentication,
)
from ansible.module_utils.six import iteritems
from ansible.module_utils._text import to_native

Expand Down Expand Up @@ -274,6 +335,7 @@ def __init__(self, module, cursor):
'global_status': {},
'engines': {},
'users': {},
'users_info': {},
'master_status': {},
'slave_hosts': {},
'slave_status': {},
Expand Down Expand Up @@ -342,6 +404,9 @@ def __collect(self, exclude_fields, return_empty_dbs, wanted):
if 'users' in wanted:
self.__get_users()

if 'users_info' in wanted:
self.__get_users_info()

if 'master_status' in wanted:
self.__get_master_status()

Expand Down Expand Up @@ -480,6 +545,86 @@ def __get_users(self):
if vname not in ('Host', 'User'):
self.info['users'][host][user][vname] = self.__convert(val)

def __get_users_info(self):
"""Get user privileges, passwords, resources_limits, ...
Query the server to get all the users and return a string
of privileges that can be used by the mysql_user plugin.
For instance:
"users_info": [
{
"host": "users_info.com",
"priv": "*.*: ALL,GRANT",
"name": "users_info_adm"
},
{
"host": "users_info.com",
"priv": "`mysql`.*: SELECT/`users_info_db`.*: SELECT",
"name": "users_info_multi"
}
]
"""
res = self.__exec_sql('SELECT * FROM mysql.user')
if not res:
return None

output = list()
for line in res:
user = line['User']
host = line['Host']

user_priv = privileges_get(self.cursor, user, host)

if not user_priv:
self.module.warn("No privileges found for %s on host %s" % (user, host))
continue

priv_string = list()
for db_table, priv in user_priv.items():
# Proxy privileges are hard to work with because of different quotes or
# backticks like ''@'', ''@'%' or even ``@``. In addition, MySQL will
# forbid you to grant a proxy privileges through TCP.
if set(priv) == {'PROXY', 'GRANT'} or set(priv) == {'PROXY'}:
continue

unquote_db_table = db_table.replace('`', '').replace("'", '')
priv_string.append('%s:%s' % (unquote_db_table, ','.join(priv)))

# Only keep *.* USAGE if it's the only user privilege given
if len(priv_string) > 1 and '*.*:USAGE' in priv_string:
priv_string.remove('*.*:USAGE')

resource_limits = get_resource_limits(self.cursor, user, host)

copy_ressource_limits = dict.copy(resource_limits)
output_dict = {
'name': user,
'host': host,
'priv': '/'.join(priv_string),
'resource_limits': copy_ressource_limits,
}

# Prevent returning a resource limit if empty
if resource_limits:
for key, value in resource_limits.items():
if value == 0:
del output_dict['resource_limits'][key]
if len(output_dict['resource_limits']) == 0:
del output_dict['resource_limits']

authentications = get_existing_authentication(self.cursor, user, host)
if authentications:
output_dict.update(authentications)

# TODO password_option
# TODO lock_option
# but both are not supported by mysql_user atm. So no point yet.

output.append(output_dict)

self.info['users_info'] = output

def __get_databases(self, exclude_fields, return_empty_dbs):
"""Get info about databases."""
if not exclude_fields:
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
DELIMITER //
DROP PROCEDURE IF EXISTS users_info_db.get_all_items;
CREATE PROCEDURE users_info_db.get_all_items()
BEGIN
SELECT * from users_info_db.t1;
END //
DELIMITER ;
Loading

0 comments on commit 3ef9bda

Please sign in to comment.