summaryrefslogtreecommitdiff
path: root/database/postgresql/postgresql_privs.py
blob: ae606464dc903a7411303d4c908e8541a475c7b0 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
#!/usr/bin/python
# -*- coding: utf-8 -*-

# This file is part of Ansible
#
# Ansible is free software: you can redistribute it and/or modify
# it under the terms of the GNU General Public License as published by
# the Free Software Foundation, either version 3 of the License, or
# (at your option) any later version.
#
# Ansible is distributed in the hope that it will be useful,
# but WITHOUT ANY WARRANTY; without even the implied warranty of
# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
# GNU General Public License for more details.
#
# You should have received a copy of the GNU General Public License
# along with Ansible.  If not, see <http://www.gnu.org/licenses/>.

ANSIBLE_METADATA = {'status': ['stableinterface'],
                    'supported_by': 'community',
                    'version': '1.0'}

DOCUMENTATION = """
---
module: postgresql_privs
version_added: "1.2"
short_description: Grant or revoke privileges on PostgreSQL database objects.
description:
  - Grant or revoke privileges on PostgreSQL database objects.
  - This module is basically a wrapper around most of the functionality of
    PostgreSQL's GRANT and REVOKE statements with detection of changes
    (GRANT/REVOKE I(privs) ON I(type) I(objs) TO/FROM I(roles))
options:
  database:
    description:
      - Name of database to connect to.
      - 'Alias: I(db)'
    required: yes
  state:
    description:
      - If C(present), the specified privileges are granted, if C(absent) they
        are revoked.
    required: no
    default: present
    choices: [present, absent]
  privs:
    description:
      - Comma separated list of privileges to grant/revoke.
      - 'Alias: I(priv)'
    required: no
  type:
    description:
      - Type of database object to set privileges on.
    required: no
    default: table
    choices: [table, sequence, function, database,
              schema, language, tablespace, group]
  objs:
    description:
      - Comma separated list of database objects to set privileges on.
      - If I(type) is C(table) or C(sequence), the special value
        C(ALL_IN_SCHEMA) can be provided instead to specify all database
        objects of type I(type) in the schema specified via I(schema). (This
        also works with PostgreSQL < 9.0.)
      - If I(type) is C(database), this parameter can be omitted, in which case
        privileges are set for the database specified via I(database).
      - 'If I(type) is I(function), colons (":") in object names will be
        replaced with commas (needed to specify function signatures, see
        examples)'
      - 'Alias: I(obj)'
    required: no
  schema:
    description:
      - Schema that contains the database objects specified via I(objs).
      - May only be provided if I(type) is C(table), C(sequence) or
        C(function). Defaults to  C(public) in these cases.
    required: no
  roles:
    description:
      - Comma separated list of role (user/group) names to set permissions for.
      - The special value C(PUBLIC) can be provided instead to set permissions
        for the implicitly defined PUBLIC group.
      - 'Alias: I(role)'
    required: yes
  grant_option:
    description:
      - Whether C(role) may grant/revoke the specified privileges/group
        memberships to others.
      - Set to C(no) to revoke GRANT OPTION, leave unspecified to
        make no changes.
      - I(grant_option) only has an effect if I(state) is C(present).
      - 'Alias: I(admin_option)'
    required: no
    choices: ['yes', 'no']
  host:
    description:
      - Database host address. If unspecified, connect via Unix socket.
      - 'Alias: I(login_host)'
    default: null
    required: no
  port:
    description:
      - Database port to connect to.
    required: no
    default: 5432
  unix_socket:
    description:
      - Path to a Unix domain socket for local connections.
      - 'Alias: I(login_unix_socket)'
    required: false
    default: null
  login:
    description:
      - The username to authenticate with.
      - 'Alias: I(login_user)'
    default: postgres
  password:
    description:
      - The password to authenticate with.
      - 'Alias: I(login_password))'
    default: null
    required: no
notes:
  - Default authentication assumes that postgresql_privs is run by the
    C(postgres) user on the remote host. (Ansible's C(user) or C(sudo-user)).
  - This module requires Python package I(psycopg2) to be installed on the
    remote host. In the default case of the remote host also being the
    PostgreSQL server, PostgreSQL has to be installed there as well, obviously.
    For Debian/Ubuntu-based systems, install packages I(postgresql) and
    I(python-psycopg2).
  - Parameters that accept comma separated lists (I(privs), I(objs), I(roles))
    have singular alias names (I(priv), I(obj), I(role)).
  - To revoke only C(GRANT OPTION) for a specific object, set I(state) to
    C(present) and I(grant_option) to C(no) (see examples).
  - Note that when revoking privileges from a role R, this role  may still have
    access via privileges granted to any role R is a member of including
    C(PUBLIC).
  - Note that when revoking privileges from a role R, you do so as the user
    specified via I(login). If R has been granted the same privileges by
    another user also, R can still access database objects via these privileges.
  - When revoking privileges, C(RESTRICT) is assumed (see PostgreSQL docs).
requirements: [psycopg2]
author: "Bernhard Weitzhofer (@b6d)"
"""

EXAMPLES = """
# On database "library":
# GRANT SELECT, INSERT, UPDATE ON TABLE public.books, public.authors
# TO librarian, reader WITH GRANT OPTION
- postgresql_privs:
    database: library
    state: present
    privs: SELECT,INSERT,UPDATE
    type: table
    objs: books,authors
    schema: public
    roles: librarian,reader
    grant_option: yes

# Same as above leveraging default values:
- postgresql_privs:
    db: library
    privs: SELECT,INSERT,UPDATE
    objs: books,authors
    roles: librarian,reader
    grant_option: yes

# REVOKE GRANT OPTION FOR INSERT ON TABLE books FROM reader
# Note that role "reader" will be *granted* INSERT privilege itself if this
# isn't already the case (since state: present).
- postgresql_privs:
    db: library
    state: present
    priv: INSERT
    obj: books
    role: reader
    grant_option: no

# REVOKE INSERT, UPDATE ON ALL TABLES IN SCHEMA public FROM reader
# "public" is the default schema. This also works for PostgreSQL 8.x.
- postgresql_privs:
    db: library
    state: absent
    privs: INSERT,UPDATE
    objs: ALL_IN_SCHEMA
    role: reader

# GRANT ALL PRIVILEGES ON SCHEMA public, math TO librarian
- postgresql_privs:
    db: library
    privs: ALL
    type: schema
    objs: public,math
    role: librarian

# GRANT ALL PRIVILEGES ON FUNCTION math.add(int, int) TO librarian, reader
# Note the separation of arguments with colons.
- postgresql_privs:
    db: library
    privs: ALL
    type: function
    obj: add(int:int)
    schema: math
    roles: librarian,reader

# GRANT librarian, reader TO alice, bob WITH ADMIN OPTION
# Note that group role memberships apply cluster-wide and therefore are not
# restricted to database "library" here.
- postgresql_privs:
    db: library
    type: group
    objs: librarian,reader
    roles: alice,bob
    admin_option: yes

# GRANT ALL PRIVILEGES ON DATABASE library TO librarian
# Note that here "db: postgres" specifies the database to connect to, not the
# database to grant privileges on (which is specified via the "objs" param)
- postgresql_privs:
    db: postgres
    privs: ALL
    type: database
    obj: library
    role: librarian

# GRANT ALL PRIVILEGES ON DATABASE library TO librarian
# If objs is omitted for type "database", it defaults to the database
# to which the connection is established
- postgresql_privs:
    db: library
    privs: ALL
    type: database
    role: librarian
"""

try:
    import psycopg2
    import psycopg2.extensions
except ImportError:
    psycopg2 = None


VALID_PRIVS = frozenset(('SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE',
                         'REFERENCES', 'TRIGGER', 'CREATE', 'CONNECT',
                         'TEMPORARY', 'TEMP', 'EXECUTE', 'USAGE', 'ALL', 'USAGE'))
class Error(Exception):
    pass


# We don't have functools.partial in Python < 2.5
def partial(f, *args, **kwargs):
    """Partial function application"""
    def g(*g_args, **g_kwargs):
        new_kwargs = kwargs.copy()
        new_kwargs.update(g_kwargs)
        return f(*(args + g_args), **g_kwargs)
    g.f = f
    g.args = args
    g.kwargs = kwargs
    return g


class Connection(object):
    """Wrapper around a psycopg2 connection with some convenience methods"""

    def __init__(self, params):
        self.database = params.database
        # To use defaults values, keyword arguments must be absent, so
        # check which values are empty and don't include in the **kw
        # dictionary
        params_map = {
            "host":"host",
            "login":"user",
            "password":"password",
            "port":"port",
            "database": "database",
        }
        kw = dict( (params_map[k], getattr(params, k)) for k in params_map
                   if getattr(params, k) != '' )

        # If a unix_socket is specified, incorporate it here.
        is_localhost = "host" not in kw or kw["host"] == "" or kw["host"] == "localhost"
        if is_localhost and params.unix_socket != "":
            kw["host"] = params.unix_socket

        self.connection = psycopg2.connect(**kw)
        self.cursor = self.connection.cursor()


    def commit(self):
        self.connection.commit()


    def rollback(self):
        self.connection.rollback()

    @property
    def encoding(self):
        """Connection encoding in Python-compatible form"""
        return psycopg2.extensions.encodings[self.connection.encoding]


    ### Methods for querying database objects

    # PostgreSQL < 9.0 doesn't support "ALL TABLES IN SCHEMA schema"-like
    # phrases in GRANT or REVOKE statements, therefore alternative methods are
    # provided here.

    def schema_exists(self, schema):
        query = """SELECT count(*)
                   FROM pg_catalog.pg_namespace WHERE nspname = %s"""
        self.cursor.execute(query, (schema,))
        return self.cursor.fetchone()[0] > 0


    def get_all_tables_in_schema(self, schema):
        if not self.schema_exists(schema):
            raise Error('Schema "%s" does not exist.' % schema)
        query = """SELECT relname
                   FROM pg_catalog.pg_class c
                   JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
                   WHERE nspname = %s AND relkind in ('r', 'v')"""
        self.cursor.execute(query, (schema,))
        return [t[0] for t in self.cursor.fetchall()]


    def get_all_sequences_in_schema(self, schema):
        if not self.schema_exists(schema):
            raise Error('Schema "%s" does not exist.' % schema)
        query = """SELECT relname
                   FROM pg_catalog.pg_class c
                   JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
                   WHERE nspname = %s AND relkind = 'S'"""
        self.cursor.execute(query, (schema,))
        return [t[0] for t in self.cursor.fetchall()]



    ### Methods for getting access control lists and group membership info

    # To determine whether anything has changed after granting/revoking
    # privileges, we compare the access control lists of the specified database
    # objects before and afterwards. Python's list/string comparison should
    # suffice for change detection, we should not actually have to parse ACLs.
    # The same should apply to group membership information.

    def get_table_acls(self, schema, tables):
        query = """SELECT relacl
                   FROM pg_catalog.pg_class c
                   JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
                   WHERE nspname = %s AND relkind = 'r' AND relname = ANY (%s)
                   ORDER BY relname"""
        self.cursor.execute(query, (schema, tables))
        return [t[0] for t in self.cursor.fetchall()]


    def get_sequence_acls(self, schema, sequences):
        query = """SELECT relacl
                   FROM pg_catalog.pg_class c
                   JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
                   WHERE nspname = %s AND relkind = 'S' AND relname = ANY (%s)
                   ORDER BY relname"""
        self.cursor.execute(query, (schema, sequences))
        return [t[0] for t in self.cursor.fetchall()]


    def get_function_acls(self, schema, function_signatures):
        funcnames = [f.split('(', 1)[0] for f in function_signatures]
        query = """SELECT proacl
                   FROM pg_catalog.pg_proc p
                   JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace
                   WHERE nspname = %s AND proname = ANY (%s)
                   ORDER BY proname, proargtypes"""
        self.cursor.execute(query, (schema, funcnames))
        return [t[0] for t in self.cursor.fetchall()]


    def get_schema_acls(self, schemas):
        query = """SELECT nspacl FROM pg_catalog.pg_namespace
                   WHERE nspname = ANY (%s) ORDER BY nspname"""
        self.cursor.execute(query, (schemas,))
        return [t[0] for t in self.cursor.fetchall()]


    def get_language_acls(self, languages):
        query = """SELECT lanacl FROM pg_catalog.pg_language
                   WHERE lanname = ANY (%s) ORDER BY lanname"""
        self.cursor.execute(query, (languages,))
        return [t[0] for t in self.cursor.fetchall()]


    def get_tablespace_acls(self, tablespaces):
        query = """SELECT spcacl FROM pg_catalog.pg_tablespace
                   WHERE spcname = ANY (%s) ORDER BY spcname"""
        self.cursor.execute(query, (tablespaces,))
        return [t[0] for t in self.cursor.fetchall()]


    def get_database_acls(self, databases):
        query = """SELECT datacl FROM pg_catalog.pg_database
                   WHERE datname = ANY (%s) ORDER BY datname"""
        self.cursor.execute(query, (databases,))
        return [t[0] for t in self.cursor.fetchall()]


    def get_group_memberships(self, groups):
        query = """SELECT roleid, grantor, member, admin_option
                   FROM pg_catalog.pg_auth_members am
                   JOIN pg_catalog.pg_roles r ON r.oid = am.roleid
                   WHERE r.rolname = ANY(%s)
                   ORDER BY roleid, grantor, member"""
        self.cursor.execute(query, (groups,))
        return self.cursor.fetchall()


    ### Manipulating privileges

    def manipulate_privs(self, obj_type, privs, objs, roles,
                         state, grant_option, schema_qualifier=None):
        """Manipulate database object privileges.

        :param obj_type: Type of database object to grant/revoke
                         privileges for.
        :param privs: Either a list of privileges to grant/revoke
                      or None if type is "group".
        :param objs: List of database objects to grant/revoke
                     privileges for.
        :param roles: Either a list of role names or "PUBLIC"
                      for the implicitly defined "PUBLIC" group
        :param state: "present" to grant privileges, "absent" to revoke.
        :param grant_option: Only for state "present": If True, set
                             grant/admin option. If False, revoke it.
                             If None, don't change grant option.
        :param schema_qualifier: Some object types ("TABLE", "SEQUENCE",
                                 "FUNCTION") must be qualified by schema.
                                 Ignored for other Types.
        """
        # get_status: function to get current status
        if obj_type == 'table':
            get_status = partial(self.get_table_acls, schema_qualifier)
        elif obj_type == 'sequence':
            get_status = partial(self.get_sequence_acls, schema_qualifier)
        elif obj_type == 'function':
            get_status = partial(self.get_function_acls, schema_qualifier)
        elif obj_type == 'schema':
            get_status = self.get_schema_acls
        elif obj_type == 'language':
            get_status = self.get_language_acls
        elif obj_type == 'tablespace':
            get_status = self.get_tablespace_acls
        elif obj_type == 'database':
            get_status = self.get_database_acls
        elif obj_type == 'group':
            get_status = self.get_group_memberships
        else:
            raise Error('Unsupported database object type "%s".' % obj_type)

        # Return False (nothing has changed) if there are no objs to work on.
        if not objs:
            return False

        # obj_ids: quoted db object identifiers (sometimes schema-qualified)
        if obj_type == 'function':
            obj_ids = []
            for obj in objs:
                try:
                    f, args = obj.split('(', 1)
                except:
                    raise Error('Illegal function signature: "%s".' % obj)
                obj_ids.append('"%s"."%s"(%s' % (schema_qualifier, f, args))
        elif obj_type in ['table', 'sequence']:
            obj_ids = ['"%s"."%s"' % (schema_qualifier, o) for o in objs]
        else:
            obj_ids = ['"%s"' % o for o in objs]

        # set_what: SQL-fragment specifying what to set for the target roles:
        # Either group membership or privileges on objects of a certain type
        if obj_type == 'group':
            set_what = ','.join(pg_quote_identifier(i, 'role') for i in obj_ids)
        else:
            # function types are already quoted above
            if obj_type != 'function':
                obj_ids = [pg_quote_identifier(i, 'table') for i in obj_ids]
            # Note: obj_type has been checked against a set of string literals
            # and privs was escaped when it was parsed
            set_what = '%s ON %s %s' % (','.join(privs), obj_type,
                                        ','.join(obj_ids))

        # for_whom: SQL-fragment specifying for whom to set the above
        if roles == 'PUBLIC':
            for_whom = 'PUBLIC'
        else:
            for_whom = ','.join(pg_quote_identifier(r, 'role') for r in roles)

        status_before = get_status(objs)
        if state == 'present':
            if grant_option:
                if obj_type == 'group':
                    query = 'GRANT %s TO %s WITH ADMIN OPTION'
                else:
                    query = 'GRANT %s TO %s WITH GRANT OPTION'
            else:
                query = 'GRANT %s TO %s'
            self.cursor.execute(query % (set_what, for_whom))

            # Only revoke GRANT/ADMIN OPTION if grant_option actually is False.
            if grant_option == False:
                if obj_type == 'group':
                    query = 'REVOKE ADMIN OPTION FOR %s FROM %s'
                else:
                    query = 'REVOKE GRANT OPTION FOR %s FROM %s'
                self.cursor.execute(query % (set_what, for_whom))
        else:
            query = 'REVOKE %s FROM %s'
            self.cursor.execute(query % (set_what, for_whom))
        status_after = get_status(objs)
        return status_before != status_after


def main():
    module = AnsibleModule(
        argument_spec = dict(
            database=dict(required=True, aliases=['db']),
            state=dict(default='present', choices=['present', 'absent']),
            privs=dict(required=False, aliases=['priv']),
            type=dict(default='table',
                      choices=['table',
                               'sequence',
                               'function',
                               'database',
                               'schema',
                               'language',
                               'tablespace',
                               'group']),
            objs=dict(required=False, aliases=['obj']),
            schema=dict(required=False),
            roles=dict(required=True, aliases=['role']),
            grant_option=dict(required=False, type='bool',
                              aliases=['admin_option']),
            host=dict(default='', aliases=['login_host']),
            port=dict(type='int', default=5432),
            unix_socket=dict(default='', aliases=['login_unix_socket']),
            login=dict(default='postgres', aliases=['login_user']),
            password=dict(default='', aliases=['login_password'], no_log=True)
        ),
        supports_check_mode = True
    )

    # Create type object as namespace for module params
    p = type('Params', (), module.params)

    # param "schema": default, allowed depends on param "type"
    if p.type in ['table', 'sequence', 'function']:
        p.schema = p.schema or 'public'
    elif p.schema:
        module.fail_json(msg='Argument "schema" is not allowed '
                             'for type "%s".' % p.type)

    # param "objs": default, required depends on param "type"
    if p.type == 'database':
        p.objs = p.objs or p.database
    elif not p.objs:
        module.fail_json(msg='Argument "objs" is required '
                             'for type "%s".' % p.type)

    # param "privs": allowed, required depends on param "type"
    if p.type == 'group':
        if p.privs:
            module.fail_json(msg='Argument "privs" is not allowed '
                                 'for type "group".')
    elif not p.privs:
        module.fail_json(msg='Argument "privs" is required '
                             'for type "%s".' % p.type)

    # Connect to Database
    if not psycopg2:
        module.fail_json(msg='Python module "psycopg2" must be installed.')
    try:
        conn = Connection(p)
    except psycopg2.Error:
        e = get_exception()
        module.fail_json(msg='Could not connect to database: %s' % e)

    try:
        # privs
        if p.privs:
            privs = frozenset(pr.upper() for pr in p.privs.split(','))
            if not privs.issubset(VALID_PRIVS):
                module.fail_json(msg='Invalid privileges specified: %s' % privs.difference(VALID_PRIVS))
        else:
            privs = None

        # objs:
        if p.type == 'table' and p.objs == 'ALL_IN_SCHEMA':
            objs = conn.get_all_tables_in_schema(p.schema)
        elif p.type == 'sequence' and p.objs == 'ALL_IN_SCHEMA':
            objs = conn.get_all_sequences_in_schema(p.schema)
        else:
            objs = p.objs.split(',')

        # function signatures are encoded using ':' to separate args
        if p.type == 'function':
            objs = [obj.replace(':', ',') for obj in objs]

        # roles
        if p.roles == 'PUBLIC':
            roles = 'PUBLIC'
        else:
            roles = p.roles.split(',')

        changed = conn.manipulate_privs(
            obj_type = p.type,
            privs = privs,
            objs = objs,
            roles = roles,
            state = p.state,
            grant_option = p.grant_option,
            schema_qualifier=p.schema
        )

    except Error:
        e = get_exception()
        conn.rollback()
        module.fail_json(msg=e.message)

    except psycopg2.Error:
        e = get_exception()
        conn.rollback()
        # psycopg2 errors come in connection encoding, reencode
        msg = e.message.decode(conn.encoding).encode(sys.getdefaultencoding(),
                                                     'replace')
        module.fail_json(msg=msg)

    if module.check_mode:
        conn.rollback()
    else:
        conn.commit()
    module.exit_json(changed=changed)


# import module snippets
from ansible.module_utils.basic import *
from ansible.module_utils.database import *
if __name__ == '__main__':
    main()