diff --git a/README.md b/README.md index de99b2ccc6..d7df7f4a0e 100644 --- a/README.md +++ b/README.md @@ -10,6 +10,7 @@ * [Configure a server](#configure-a-server) * [Create a database](#create-a-database) * [Manage users, roles, and permissions](#manage-users-roles-and-permissions) + * [Manage ownership of DB objects](#manage-ownership-of-db-objects) * [Override defaults](#override-defaults) * [Create an access rule for pg_hba.conf](#create-an-access-rule-for-pg_hbaconf) * [Create user name maps for pg_ident.conf](#create-user-name-maps-for-pg_identconf) @@ -116,6 +117,24 @@ postgresql::server::table_grant { 'my_table of test2': This example grants **all** privileges on the test1 database and on the `my_table` table of the test2 database to the specified user or group. After the values are added into the PuppetDB config file, this database would be ready for use. +### Manage ownership of DB objects + +To change the ownership of all objects within a database using REASSIGN OWNED: + +```puppet +postgresql::server::reassign_owned_by { 'new owner is meerkat': + db => 'test_db', + old_owner => 'marmot', + new_owner => 'meerkat', +} +``` + +This would run the PostgreSQL statement 'REASSIGN OWNED' to update to ownership of all tables, sequences, functions and views currently owned by the role 'marmot' to be owned by the role 'meerkat' instead. + +This applies to objects within the nominated database, 'test_db' only. + +For Postgresql >= 9.3, the ownership of the database is also updated. + ### Override defaults The `postgresql::globals` class allows you to configure the main settings for this module globally, so that other classes and defined resources can use them. By itself, it does nothing. @@ -327,6 +346,7 @@ The postgresql module comes with many options for configuring the server. While * [postgresql::server::grant_role](#postgresqlservergrant_role) * [postgresql::server::pg_hba_rule](#postgresqlserverpg_hba_rule) * [postgresql::server::pg_ident_rule](#postgresqlserverpg_ident_rule) +* [postgresql::server::reassign_owned_by](#postgresqlserverreassign_owned_by) * [postgresql::server::recovery](#postgresqlserverrecovery) * [postgresql::server::role](#postgresqlserverrole) * [postgresql::server::schema](#postgresqlserverschema) @@ -1346,6 +1366,40 @@ Provides the target for the rule and is generally an internal only property. **Use with caution.** +#### postgresql::server::reassign_owned_by + +Runs the PostgreSQL command 'REASSIGN OWNED' on a database, to transfer the ownership of existing objects between database roles + +##### `db` + +Specifies the database to which the 'REASSIGN OWNED' will be applied + +##### `old_role` + +Specifies the role or user who is the current owner of the objects in the specified db + +##### `new_role` + +Specifies the role or user who will be the new owner of these objects + +##### `psql_user` + +Specifies the OS user for running `psql`. + +Default value: The default user for the module, usually 'postgres'. + +##### `port` + +Port to use when connecting. + +Default value: `undef`, which generally defaults to port 5432 depending on your PostgreSQL packaging. + +##### `connect_settings` + +Specifies a hash of environment variables used when connecting to a remote server. + +Default value: Connects to the local Postgres instance. + #### postgresql::server::recovery Allows you to create the content for `recovery.conf`. For more details see the [usage example](#create-recovery-configuration) and the [PostgreSQL documentation](http://www.postgresql.org/docs/current/static/recovery-config.html). diff --git a/manifests/server/reassign_owned_by.pp b/manifests/server/reassign_owned_by.pp new file mode 100644 index 0000000000..812c7e228a --- /dev/null +++ b/manifests/server/reassign_owned_by.pp @@ -0,0 +1,61 @@ +# Define for reassigning the ownership of objects within a database. See README.md for more details. +# This enables us to force the a particular ownership for objects within a database +define postgresql::server::reassign_owned_by ( + String $old_role, + String $new_role, + String $db, + String $psql_user = $postgresql::server::user, + Integer $port = $postgresql::server::port, + Hash $connect_settings = $postgresql::server::default_connect_settings, +) { + + $sql_command = "REASSIGN OWNED BY \"${old_role}\" TO \"${new_role}\"" + + $group = $postgresql::server::group + $psql_path = $postgresql::server::psql_path + + # + # Port, order of precedence: $port parameter, $connect_settings[PGPORT], $postgresql::server::port + # + if $port != undef { + $port_override = $port + } elsif $connect_settings != undef and has_key( $connect_settings, 'PGPORT') { + $port_override = undef + } else { + $port_override = $postgresql::server::port + } + + $onlyif = "SELECT tablename FROM pg_catalog.pg_tables WHERE + schemaname NOT IN ('pg_catalog', 'information_schema') AND + tableowner = '${old_role}' + UNION ALL SELECT proname FROM pg_catalog.pg_proc WHERE + pg_get_userbyid(proowner) = '${old_role}' + UNION ALL SELECT viewname FROM pg_catalog.pg_views WHERE + pg_views.schemaname NOT IN ('pg_catalog', 'information_schema') AND + viewowner = '${old_role}' + UNION ALL SELECT relname FROM pg_catalog.pg_class WHERE + relkind='S' AND pg_get_userbyid(relowner) = '${old_role}'" + + postgresql_psql { "reassign_owned_by:${db}:${sql_command}": + command => $sql_command, + db => $db, + port => $port_override, + connect_settings => $connect_settings, + psql_user => $psql_user, + psql_group => $group, + psql_path => $psql_path, + onlyif => $onlyif, + require => Class['postgresql::server'] + } + + if($old_role != undef and defined(Postgresql::Server::Role[$old_role])) { + Postgresql::Server::Role[$old_role]->Postgresql_psql["reassign_owned_by:${db}:${sql_command}"] + } + if($new_role != undef and defined(Postgresql::Server::Role[$new_role])) { + Postgresql::Server::Role[$new_role]->Postgresql_psql["reassign_owned_by:${db}:${sql_command}"] + } + + if($db != undef and defined(Postgresql::Server::Database[$db])) { + Postgresql::Server::Database[$db]->Postgresql_psql["reassign_owned_by:${db}:${sql_command}"] + } +} diff --git a/spec/acceptance/server/reassign_owned_by_spec.rb b/spec/acceptance/server/reassign_owned_by_spec.rb new file mode 100644 index 0000000000..b885b3837f --- /dev/null +++ b/spec/acceptance/server/reassign_owned_by_spec.rb @@ -0,0 +1,135 @@ +require 'spec_helper_acceptance' + +describe 'postgresql::server::reassign_owned_by:', :unless => UNSUPPORTED_PLATFORMS.include?(fact('osfamily')) do + + let(:db) { 'reassign_test' } + let(:old_owner) { 'psql_reassign_old_owner' } + let(:new_owner) { 'psql_reassign_new_owner' } + let(:password) { 'psql_reassign_pw' } + let(:superuser) { 'postgres' } + + let(:pp_setup) { pp_setup = <<-EOS.unindent + $db = #{db} + $old_owner = #{old_owner} + $new_owner = #{new_owner} + $password = #{password} + + class { 'postgresql::server': } + + postgresql::server::role { $old_owner: + password_hash => postgresql_password($old_owner, $password), + } + + # Since we are not testing pg_hba or any of that, make a local user for ident auth + user { $old_owner: + ensure => present, + } + + # Create a user to reassign ownership to + postgresql::server::role { $new_owner: + db => $db, + require => Postgresql::Server::Database[$db], + } + + # Make a local user for ident auth + user { $new_owner: + ensure => present, + } + + # Grant the new owner membership of the old owner (must have both for REASSIGN OWNED BY to work) + postgresql::server::grant_role { "grant_role to ${new_owner}": + role => $new_owner, + group => $old_owner, + } + + # Grant them connect to the database + postgresql::server::database_grant { "allow connect for ${old_owner}": + privilege => 'CONNECT', + db => $db, + role => $old_owner, + } + EOS + } + + let(:pp_db_old_owner) { <<-EOS.unindent + postgresql::server::database { $db: + owner => $old_owner, + require => Postgresql::Server::Role[$old_owner], + } + EOS + } + + let(:pp_db_no_owner) { <<-EOS.unindent + postgresql::server::database { $db: + } + EOS + } + + context 'reassign_owned_by' do + describe 'REASSIGN OWNED BY tests' do + let(:db) { 'reassign_test' } + let(:old_owner) { 'psql_reassign_old_owner' } + let(:new_owner) { 'psql_reassign_new_owner' } + + let(:pp_setup_objects) { <<-EOS.unindent + postgresql_psql { 'create test table': + command => 'CREATE TABLE test_tbl (col1 integer)', + db => '#{db}', + psql_user => '#{old_owner}', + unless => "SELECT tablename FROM pg_catalog.pg_tables WHERE tablename = 'test_tbl'", + require => Postgresql::Server::Database['#{db}'], + } + postgresql_psql { 'create test sequence': + command => 'CREATE SEQUENCE test_seq', + db => '#{db}', + psql_user => '#{old_owner}', + unless => "SELECT relname FROM pg_catalog.pg_class WHERE relkind='S' AND relname = 'test_seq'", + require => [ Postgresql_psql['create test table'], Postgresql::Server::Database['#{db}'] ], + } + EOS + } + let(:pp_reassign_owned_by) { <<-EOS.unindent + postgresql::server::reassign_owned_by { 'test reassign to new_owner': + db => '#{db}', + old_role => '#{old_owner}', + new_role => '#{new_owner}', + psql_user => '#{new_owner}', + } + EOS + } + + it 'should reassign all objects to new_owner' do + begin + apply_manifest(pp_setup + pp_db_old_owner + pp_setup_objects, :catch_failures => true) + + #postgres version + result = shell('psql --version') + version = result.stdout.match(%r{\s(\d\.\d)})[1] + + if version >= '9.0' + + apply_manifest(pp_setup + pp_db_no_owner + pp_reassign_owned_by, :catch_failures => true) + apply_manifest(pp_setup + pp_db_no_owner + pp_reassign_owned_by, :catch_changes => true) + + ## Check that the ownership was transferred + psql("-d #{db} --tuples-only --no-align --command=\"SELECT tablename,tableowner FROM pg_catalog.pg_tables WHERE schemaname NOT IN ('pg_catalog', 'information_schema')\"", superuser) do |r| + expect(r.stdout).to match(/test_tbl.#{new_owner}/) + expect(r.stderr).to eq('') + end + psql("-d #{db} --tuples-only --no-align --command=\"SELECT relname,pg_get_userbyid(relowner) FROM pg_catalog.pg_class c WHERE relkind='S'\"", superuser) do |r| + expect(r.stdout).to match(/test_seq.#{new_owner}/) + expect(r.stderr).to eq('') + end + if version >= '9.3' + psql("-d #{db} --tuples-only --no-align --command=\"SELECT pg_get_userbyid(datdba) FROM pg_database WHERE datname = current_database()\"", superuser) do |r| + expect(r.stdout).to match(/#{new_owner}/) + expect(r.stderr).to eq('') + end + end + end + end + end # it should reassign all objects + end + end + ##################### +end diff --git a/spec/unit/defines/server/reassign_owned_by_spec.rb b/spec/unit/defines/server/reassign_owned_by_spec.rb new file mode 100644 index 0000000000..72f67c3b49 --- /dev/null +++ b/spec/unit/defines/server/reassign_owned_by_spec.rb @@ -0,0 +1,44 @@ +require 'spec_helper' + +describe 'postgresql::server::reassign_owned_by', :type => :define do + let :facts do + { + :osfamily => 'Debian', + :operatingsystem => 'Debian', + :operatingsystemrelease => '6.0', + :kernel => 'Linux', + :concat_basedir => tmpfilename('reassign_owned_by'), + :id => 'root', + :path => '/usr/local/sbin:/usr/local/bin:/usr/sbin:/usr/bin:/sbin:/bin', + } + end + + let :title do + 'test' + end + + let :params do + { + :db => 'test', + :old_role => 'test_old_role', + :new_role => 'test_new_role', + } + end + + let :pre_condition do + <<-EOS + class {'postgresql::server':} + postgresql::server::role{ ['test_old_role','test_new_role']: } + EOS + end + + it { is_expected.to contain_postgresql__server__reassign_owned_by('test') } + + it { + is_expected.to contain_postgresql_psql('reassign_owned_by:test:REASSIGN OWNED BY "test_old_role" TO "test_new_role"').with({ + 'command' => "REASSIGN OWNED BY \"test_old_role\" TO \"test_new_role\"", + 'onlyif' => /SELECT tablename FROM pg_catalog.pg_tables WHERE\s*schemaname NOT IN \('pg_catalog', 'information_schema'\) AND\s*tableowner = 'test_old_role'.*/m, + }).that_requires('Class[postgresql::server]') + } + +end