Skip to content

Commit

Permalink
postgresql_db: add comment feature (#646)
Browse files Browse the repository at this point in the history
* postgresql_db: add comment feature

* Reset the comment

* Fix tests

* Fix spelling

(cherry picked from commit 94f8b87)
  • Loading branch information
Andersson007 authored and patchback[bot] committed Dec 12, 2023
1 parent 167a93f commit 9dcc77f
Show file tree
Hide file tree
Showing 4 changed files with 207 additions and 5 deletions.
2 changes: 2 additions & 0 deletions changelogs/fragments/0-postgresql_db.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
minor_changes:
- postgresql_db - add the ``comment`` argument (https://github.com/ansible-collections/community.postgresql/issues/614).
34 changes: 29 additions & 5 deletions plugins/modules/postgresql_db.py
Original file line number Diff line number Diff line change
Expand Up @@ -130,6 +130,12 @@
type: bool
default: true
version_added: '0.2.0'
comment:
description:
- Sets a comment on the database.
- To reset the comment, pass an empty string.
type: str
version_added: '3.3.0'
seealso:
- name: CREATE DATABASE reference
description: Complete reference of the CREATE DATABASE command documentation.
Expand Down Expand Up @@ -164,6 +170,7 @@
- name: Create a new database with name "acme"
community.postgresql.postgresql_db:
name: acme
comment: My test DB
# Note: If a template different from "template0" is specified,
# encoding and locale settings must match those of the template.
Expand Down Expand Up @@ -314,6 +321,13 @@ def set_conn_limit(cursor, db, conn_limit):
return True


def set_comment(cursor, db, comment):
query = "COMMENT ON DATABASE \"%s\" IS '%s'" % (db, comment)
executed_commands.append(query)
cursor.execute(query)
return True


def get_encoding_id(cursor, encoding):
query = "SELECT pg_char_to_encoding(%(encoding)s) AS encoding_id;"
cursor.execute(query, {'encoding': encoding})
Expand All @@ -325,7 +339,8 @@ def get_db_info(cursor, db):
SELECT rolname AS owner,
pg_encoding_to_char(encoding) AS encoding, encoding AS encoding_id,
datcollate AS lc_collate, datctype AS lc_ctype, pg_database.datconnlimit AS conn_limit,
spcname AS tablespace
spcname AS tablespace,
pg_catalog.shobj_description(pg_database.oid, 'pg_database') AS comment
FROM pg_database
JOIN pg_roles ON pg_roles.oid = pg_database.datdba
JOIN pg_tablespace ON pg_tablespace.oid = pg_database.dattablespace
Expand Down Expand Up @@ -371,7 +386,7 @@ def db_delete(cursor, db, force=False):
return False


def db_create(cursor, db, owner, template, encoding, lc_collate, lc_ctype, conn_limit, tablespace):
def db_create(cursor, db, owner, template, encoding, lc_collate, lc_ctype, conn_limit, tablespace, comment):
params = dict(enc=encoding, collate=lc_collate, ctype=lc_ctype, conn_limit=conn_limit, tablespace=tablespace)
if not db_exists(cursor, db):
query_fragments = ['CREATE DATABASE "%s"' % db]
Expand All @@ -392,6 +407,8 @@ def db_create(cursor, db, owner, template, encoding, lc_collate, lc_ctype, conn_
query = ' '.join(query_fragments)
executed_commands.append(cursor.mogrify(query, params))
cursor.execute(query, params)
if comment:
set_comment(cursor, db, comment)
return True
else:
db_info = get_db_info(cursor, db)
Expand Down Expand Up @@ -422,10 +439,13 @@ def db_create(cursor, db, owner, template, encoding, lc_collate, lc_ctype, conn_
if tablespace and tablespace != db_info['tablespace']:
changed = set_tablespace(cursor, db, tablespace)

if comment is not None and comment != db_info['comment']:
changed = set_comment(cursor, db, comment)

return changed


def db_matches(cursor, db, owner, template, encoding, lc_collate, lc_ctype, conn_limit, tablespace):
def db_matches(cursor, db, owner, template, encoding, lc_collate, lc_ctype, conn_limit, tablespace, comment):
if not db_exists(cursor, db):
return False
else:
Expand All @@ -442,6 +462,8 @@ def db_matches(cursor, db, owner, template, encoding, lc_collate, lc_ctype, conn
return False
elif tablespace and tablespace != db_info['tablespace']:
return False
elif comment is not None and comment != db_info['comment']:
return False
else:
return True

Expand Down Expand Up @@ -654,6 +676,7 @@ def main():
dump_extra_args=dict(type='str', default=None),
trust_input=dict(type='bool', default=True),
force=dict(type='bool', default=False),
comment=dict(type='str', default=None),
)

module = AnsibleModule(
Expand All @@ -678,6 +701,7 @@ def main():
dump_extra_args = module.params['dump_extra_args']
trust_input = module.params['trust_input']
force = module.params['force']
comment = module.params['comment']

if state == 'rename':
if not target:
Expand Down Expand Up @@ -726,7 +750,7 @@ def main():
changed = db_exists(cursor, db)

elif state == "present":
changed = not db_matches(cursor, db, owner, template, encoding, lc_collate, lc_ctype, conn_limit, tablespace)
changed = not db_matches(cursor, db, owner, template, encoding, lc_collate, lc_ctype, conn_limit, tablespace, comment)

elif state == "rename":
changed = rename_db(module, cursor, db, target, check_mode=True)
Expand All @@ -741,7 +765,7 @@ def main():

elif state == "present":
try:
changed = db_create(cursor, db, owner, template, encoding, lc_collate, lc_ctype, conn_limit, tablespace)
changed = db_create(cursor, db, owner, template, encoding, lc_collate, lc_ctype, conn_limit, tablespace, comment)
except SQLParseError as e:
module.fail_json(msg=to_native(e), exception=traceback.format_exc())

Expand Down
3 changes: 3 additions & 0 deletions tests/integration/targets/postgresql_db/tasks/main.yml
Original file line number Diff line number Diff line change
Expand Up @@ -45,3 +45,6 @@

# Simple test to create and then drop with force
- import_tasks: manage_database.yml

# Test the comment feature
- import_tasks: postgresql_db_comment.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,173 @@
# Test code for the postgresql_db comment module feature
# Copyright: (c) 2019, Andrew Klychkov (@Andersson007) <[email protected]>
# GNU General Public License v3.0+ (see COPYING or https://www.gnu.org/licenses/gpl-3.0.txt)

- name: Set parameters we use with most of tasks
ansible.builtin.set_fact:
task_parameters: &task_parameters
become_user: "{{ pg_user }}"
become: true
register: result

- name: Create DB with comment
<<: *task_parameters
postgresql_db:
state: present
name: comment_db
login_user: "{{ pg_user }}"
comment: Test DB comment 1

- name: Assert the executed commands
assert:
that:
- result is changed
- result.db == "comment_db"
- result.executed_commands == ['CREATE DATABASE "comment_db"', "COMMENT ON DATABASE \"comment_db\" IS 'Test DB comment 1'"]

- name: Get the DB comment
<<: *task_parameters
postgresql_query:
login_user: "{{ pg_user }}"
query: "SELECT pg_catalog.shobj_description(d.oid, 'pg_database') AS comment FROM pg_catalog.pg_database d WHERE datname = 'comment_db'"

- name: Check the comments match
assert:
that:
- result.query_result[0]['comment'] == "Test DB comment 1"


- name: Create DB with another comment in check mode
<<: *task_parameters
postgresql_db:
state: present
name: comment_db
login_user: "{{ pg_user }}"
comment: Another comment
check_mode: true

- name: Assert the result
assert:
that:
- result is changed

- name: Check the comment
<<: *task_parameters
postgresql_query:
login_user: "{{ pg_user }}"
query: "SELECT pg_catalog.shobj_description(d.oid, 'pg_database') AS comment FROM pg_catalog.pg_database d WHERE datname = 'comment_db'"

- name: Check the comment hasn't changed
assert:
that:
- result.query_result[0]['comment'] == "Test DB comment 1"


- name: Create DB with another comment in real mode
<<: *task_parameters
postgresql_db:
state: present
name: comment_db
login_user: "{{ pg_user }}"
comment: Another comment

- name: Assert the result
assert:
that:
- result is changed
- result.executed_commands == ["COMMENT ON DATABASE \"comment_db\" IS 'Another comment'"]

- name: Check the comment
<<: *task_parameters
postgresql_query:
login_user: "{{ pg_user }}"
query: "SELECT pg_catalog.shobj_description(d.oid, 'pg_database') AS comment FROM pg_catalog.pg_database d WHERE datname = 'comment_db'"

- name: Check the comments match
assert:
that:
- result.query_result[0]['comment'] == "Another comment"


- name: Create DB with the same comment in real mode
<<: *task_parameters
postgresql_db:
state: present
name: comment_db
login_user: "{{ pg_user }}"
comment: Another comment

- name: Assert the result
assert:
that:
- result is not changed
- result.executed_commands == []

- name: Check the comment
<<: *task_parameters
postgresql_query:
login_user: "{{ pg_user }}"
query: "SELECT pg_catalog.shobj_description(d.oid, 'pg_database') AS comment FROM pg_catalog.pg_database d WHERE datname = 'comment_db'"

- name: Check the comments match
assert:
that:
- result.query_result[0]['comment'] == "Another comment"


- name: Not specifying the comment will not erase it
<<: *task_parameters
postgresql_db:
state: present
name: comment_db
login_user: "{{ pg_user }}"

- name: Assert the result
assert:
that:
- result is not changed
- result.executed_commands == []

- name: Check the comment
<<: *task_parameters
postgresql_query:
login_user: "{{ pg_user }}"
query: "SELECT pg_catalog.shobj_description(d.oid, 'pg_database') AS comment FROM pg_catalog.pg_database d WHERE datname = 'comment_db'"

- name: Check the comments match
assert:
that:
- result.query_result[0]['comment'] == "Another comment"


- name: Reset the comment
<<: *task_parameters
postgresql_db:
state: present
name: comment_db
login_user: "{{ pg_user }}"
comment: ''

- name: Assert the result
assert:
that:
- result is changed
- result.executed_commands == ["COMMENT ON DATABASE \"comment_db\" IS ''"]

- name: Check the comment
<<: *task_parameters
postgresql_query:
login_user: "{{ pg_user }}"
query: "SELECT pg_catalog.shobj_description(d.oid, 'pg_database') AS comment FROM pg_catalog.pg_database d WHERE datname = 'comment_db'"

- name: Check the comments match
assert:
that:
- result.query_result[0]['comment'] == None


- name: Clean up
<<: *task_parameters
postgresql_db:
state: absent
name: comment_db
login_user: "{{ pg_user }}"

0 comments on commit 9dcc77f

Please sign in to comment.