From 02645b166959a76c7ab85a2f80e1bd9c911e2702 Mon Sep 17 00:00:00 2001 From: Travis Fields Date: Tue, 3 Mar 2015 12:20:09 -0800 Subject: [PATCH] FM-2288 Add Role Members with Purge support --- manifests/role.pp | 16 ++ spec/defines/role_spec.rb | 163 ++++++++++++++---- templates/create/role/members.sql.erb | 30 ++++ templates/query/role/member_exists.sql.erb | 18 ++ templates/snippets/role/member_exists.sql.erb | 5 + .../role/populate_purge_members.sql.erb | 11 ++ 6 files changed, 212 insertions(+), 31 deletions(-) create mode 100644 templates/create/role/members.sql.erb create mode 100644 templates/query/role/member_exists.sql.erb create mode 100644 templates/snippets/role/member_exists.sql.erb create mode 100644 templates/snippets/role/populate_purge_members.sql.erb diff --git a/manifests/role.pp b/manifests/role.pp index 156203db..4ed7967a 100644 --- a/manifests/role.pp +++ b/manifests/role.pp @@ -30,6 +30,11 @@ # [permissions] # A hash of permissions that should be managed for the role. Valid keys are 'GRANT', 'GRANT_WITH_OPTION', 'DENY' or 'REVOKE'. Valid values must be an array of Strings i.e. {'GRANT' => ['CONNECT', 'CREATE ANY DATABASE'] } # +# [members] +# An array of users/logins that should be a member of the role +# +# [members_purge] +# Whether we should purge any members not listed in the members parameter. Default: false ## define sqlserver::role( $ensure = present, @@ -39,6 +44,8 @@ $type = 'SERVER', $database = 'master', $permissions = { }, + $members = [], + $members_purge = false, ){ sqlserver_validate_instance_name($instance) sqlserver_validate_range($role, 1, 128, 'Role names must be between 1 and 128 characters') @@ -97,5 +104,14 @@ permissions => $_upermissions['GRANT_WITH_OPTION'], } } + + validate_array($members) + if size($members) > 0 or $members_purge == true { + sqlserver_tsql{ "role-${role}-members": + command => template('sqlserver/create/role/members.sql.erb'), + onlyif => template('sqlserver/query/role/member_exists.sql.erb'), + instance => $instance, + } + } } } diff --git a/spec/defines/role_spec.rb b/spec/defines/role_spec.rb index 511f8f6f..cba659d6 100644 --- a/spec/defines/role_spec.rb +++ b/spec/defines/role_spec.rb @@ -10,38 +10,38 @@ context 'type =>' do describe 'invalid' do let(:additional_params) { { - :type => 'invalid', + :type => 'invalid', } } let(:raise_error_check) { "Type must be either 'SERVER' or 'DATABASE', provided 'invalid'" } it_behaves_like 'validation error' end describe 'SERVER' do let(:should_contain_command) { [ - 'USE [master];', - 'CREATE SERVER ROLE [myCustomRole];', - /IF NOT EXISTS\(\n\s+SELECT name FROM sys\.server_principals WHERE type_desc = 'SERVER_ROLE' AND name = 'myCustomRole'\n\)/, - "THROW 51000, 'The SERVER ROLE [myCustomRole] does not exist', 10" + 'USE [master];', + 'CREATE SERVER ROLE [myCustomRole];', + /IF NOT EXISTS\(\n\s+SELECT name FROM sys\.server_principals WHERE type_desc = 'SERVER_ROLE' AND name = 'myCustomRole'\n\)/, + "THROW 51000, 'The SERVER ROLE [myCustomRole] does not exist', 10" ] } let(:should_contain_onlyif) { [ - /IF NOT EXISTS\(\n\s+SELECT name FROM sys\.server_principals WHERE type_desc = 'SERVER_ROLE' AND name = 'myCustomRole'\n\)/, - "THROW 51000, 'The SERVER ROLE [myCustomRole] does not exist', 10" + /IF NOT EXISTS\(\n\s+SELECT name FROM sys\.server_principals WHERE type_desc = 'SERVER_ROLE' AND name = 'myCustomRole'\n\)/, + "THROW 51000, 'The SERVER ROLE [myCustomRole] does not exist', 10" ] } it_behaves_like 'sqlserver_tsql command' it_behaves_like 'sqlserver_tsql onlyif' end describe 'DATABASE' do let(:additional_params) { { - 'type' => 'DATABASE', + 'type' => 'DATABASE', } } let(:should_contain_command) { [ - 'USE [master];', - 'CREATE ROLE [myCustomRole];', - /IF NOT EXISTS\(\n\s+SELECT name FROM sys\.database_principals WHERE type_desc = 'DATABASE_ROLE' AND name = 'myCustomRole'\n\)/, - "THROW 51000, 'The DATABASE ROLE [myCustomRole] does not exist', 10" + 'USE [master];', + 'CREATE ROLE [myCustomRole];', + /IF NOT EXISTS\(\n\s+SELECT name FROM sys\.database_principals WHERE type_desc = 'DATABASE_ROLE' AND name = 'myCustomRole'\n\)/, + "THROW 51000, 'The DATABASE ROLE [myCustomRole] does not exist', 10" ] } let(:should_contain_onlyif) { [ - /IF NOT EXISTS\(\n\s+SELECT name FROM sys\.database_principals WHERE type_desc = 'DATABASE_ROLE' AND name = 'myCustomRole'\n\)/, - "THROW 51000, 'The DATABASE ROLE [myCustomRole] does not exist', 10", + /IF NOT EXISTS\(\n\s+SELECT name FROM sys\.database_principals WHERE type_desc = 'DATABASE_ROLE' AND name = 'myCustomRole'\n\)/, + "THROW 51000, 'The DATABASE ROLE [myCustomRole] does not exist', 10", ] } it_behaves_like 'sqlserver_tsql command' @@ -52,7 +52,7 @@ context 'database =>' do let(:additional_params) { { - 'database' => 'myCrazyDb', + 'database' => 'myCrazyDb', } } describe 'with server role type' do let(:raise_error_check) { 'Can not specify a database other than master when managing SERVER ROLES' } @@ -60,11 +60,11 @@ end describe 'with database role type' do let(:additional_params) { { - 'database' => 'myCrazyDb', - 'type' => 'DATABASE', + 'database' => 'myCrazyDb', + 'type' => 'DATABASE', } } let(:should_contain_command) { [ - 'USE [myCrazyDb];', + 'USE [myCrazyDb];', ] } it_behaves_like 'sqlserver_tsql command' end @@ -87,29 +87,29 @@ context 'authorization =>' do describe 'undef' do let(:should_not_contain_command) { [ - /AUTHORIZATION/i, - 'ALTER AUTHORIZATION ON ', + /AUTHORIZATION/i, + 'ALTER AUTHORIZATION ON ', ] } it_behaves_like 'sqlserver_tsql without_command' end describe 'myUser' do let(:additional_params) { { - :authorization => 'myUser', + :authorization => 'myUser', } } let(:should_contain_command) { [ - 'CREATE SERVER ROLE [myCustomRole] AUTHORIZATION [myUser];', - 'ALTER AUTHORIZATION ON SERVER ROLE::[myCustomRole] TO [myUser];' + 'CREATE SERVER ROLE [myCustomRole] AUTHORIZATION [myUser];', + 'ALTER AUTHORIZATION ON SERVER ROLE::[myCustomRole] TO [myUser];' ] } it_behaves_like 'sqlserver_tsql command' end describe 'myUser on Database' do let(:additional_params) { { - :authorization => 'myUser', - :type => 'DATABASE', + :authorization => 'myUser', + :type => 'DATABASE', } } let(:should_contain_command) { [ - 'CREATE ROLE [myCustomRole] AUTHORIZATION [myUser];', - 'ALTER AUTHORIZATION ON ROLE::[myCustomRole] TO [myUser];' + 'CREATE ROLE [myCustomRole] AUTHORIZATION [myUser];', + 'ALTER AUTHORIZATION ON ROLE::[myCustomRole] TO [myUser];' ] } it_behaves_like 'sqlserver_tsql command' end @@ -118,18 +118,119 @@ context 'ensure =>' do describe 'absent' do let(:additional_params) { { - :ensure => 'absent', + :ensure => 'absent', } } let(:should_contain_command) { [ - 'USE [master];', - 'DROP SERVER ROLE [myCustomRole];' + 'USE [master];', + 'DROP SERVER ROLE [myCustomRole];' ] } let(:should_contain_onlyif) { [ - 'IF EXISTS(', + 'IF EXISTS(', ] } it_behaves_like 'sqlserver_tsql command' it_behaves_like 'sqlserver_tsql onlyif' end end + context 'members =>' do + let(:sqlserver_tsql_title) { 'role-myCustomRole-members' } + describe '[test these users]' do + let(:additional_params) { { + :members => %w(test these users), + } } + let(:should_contain_command) { [ + 'ALTER SERVER ROLE [myCustomRole] ADD MEMBER [test];', + 'ALTER SERVER ROLE [myCustomRole] ADD MEMBER [these];', + 'ALTER SERVER ROLE [myCustomRole] ADD MEMBER [users];', + ] } + let(:should_contain_onlyif) { [ + ] } + it_behaves_like 'sqlserver_tsql command' + it_behaves_like 'sqlserver_tsql onlyif' + end + describe 'empty' do + it { + should_not contain_sqlserver_tsql(sqlserver_tsql_title) + } + end + end + context 'members_purge =>' do + let(:sqlserver_tsql_title) { 'role-myCustomRole-members' } + context 'true' do + describe 'type => SERVER and members => []' do + let(:additional_params) { { + :members_purge => true, + } } + let(:should_contain_command) { [ + "WHILE(@row <= @row_count) +BEGIN + SET @sql = 'ALTER SERVER ROLE [myCustomRole] DROP MEMBER [' + (SELECT member FROM @purge_members WHERE ID = @row) + '];' + EXEC(@sql) + SET @row += 1 +END" + ] } + let(:should_contain_onlyif) { [ + "DECLARE @purge_members TABLE ( +ID int IDENTITY(1,1), +member varchar(128) +)", + "INSERT INTO @purge_members (member) ( +SELECT m.name FROM sys.server_role_members rm + JOIN sys.server_principals r ON rm.role_principal_id = r.principal_id + JOIN sys.server_principals m ON rm.member_principal_id = m.principal_id + WHERE r.name = 'myCustomRole'", + "IF 0 != (SELECT COUNT(*) FROM @purge_members) + THROW 51000, 'Unlisted Members in Role, will be purged', 10", + ] } + it_behaves_like 'sqlserver_tsql command' + it_behaves_like 'sqlserver_tsql onlyif' + end + + describe 'type => DATABASE and members => []' do + let(:additional_params) { { + :type => 'DATABASE', + :members_purge => true, + } } + let(:should_contain_command) { [ + "WHILE(@row <= @row_count) +BEGIN + SET @sql = 'ALTER ROLE [myCustomRole] DROP MEMBER [' + (SELECT member FROM @purge_members WHERE ID = @row) + '];' + EXEC(@sql) + SET @row += 1 +END" + ] } + let(:should_contain_onlyif) { [ + "DECLARE @purge_members TABLE ( +ID int IDENTITY(1,1), +member varchar(128) +)", + "INSERT INTO @purge_members (member) ( +SELECT m.name FROM sys.database_role_members rm + JOIN sys.database_principals r ON rm.role_principal_id = r.principal_id + JOIN sys.database_principals m ON rm.member_principal_id = m.principal_id + WHERE r.name = 'myCustomRole'", + "IF 0 != (SELECT COUNT(*) FROM @purge_members) + THROW 51000, 'Unlisted Members in Role, will be purged', 10", + ] } + it_behaves_like 'sqlserver_tsql command' + it_behaves_like 'sqlserver_tsql onlyif' + end + end + describe '[test these users]' do + let(:additional_params) { { + :members_purge => true, + :members => %w(test these users), + } } + let(:should_contain_command) { [ + /WHERE r\.name = 'myCustomRole'\n\s+AND m\.name NOT IN \(/, + "NOT IN ('test','these','users')" + ] } + let(:should_contain_onlyif) { [ + /WHERE r\.name = 'myCustomRole'\n\s+AND m\.name NOT IN \(/, + "NOT IN ('test','these','users')" + ] } + it_behaves_like 'sqlserver_tsql command' + it_behaves_like 'sqlserver_tsql onlyif' + end + end end diff --git a/templates/create/role/members.sql.erb b/templates/create/role/members.sql.erb new file mode 100644 index 00000000..b05e4009 --- /dev/null +++ b/templates/create/role/members.sql.erb @@ -0,0 +1,30 @@ +USE [<%= @database %>]; +DECLARE + @role varchar(128) = '<%= @role %>', + @member varchar(128), + @error_msg varchar(250); + +<%- @members.each do |member| -%> +BEGIN +SET @member = '<%= member %>'; +<%= scope.function_template(['sqlserver/snippets/role/member_exists.sql.erb']) -%> + ALTER <% if @type == 'SERVER' %>SERVER <% end %>ROLE [<%= @role %>] ADD MEMBER [<%= member %>]; + +<%= scope.function_template(['sqlserver/snippets/role/member_exists.sql.erb']) -%> + THROW 51000, 'Failed to add member [<%= member %>] to Role [<%= @role %>]', 10 +END +<% end -%> + +<% if @members_purge %> +<%= scope.function_template(['sqlserver/snippets/role/populate_purge_members.sql.erb']) -%> + +DECLARE @sql varchar(250), @row int = 1, @row_count int; +SET @row_count = (SELECT COUNT(*) FROM @purge_members); + +WHILE(@row <= @row_count) +BEGIN + SET @sql = 'ALTER <% if @type == 'SERVER' %>SERVER <% end %>ROLE [<%= @role %>] DROP MEMBER [' + (SELECT member FROM @purge_members WHERE ID = @row) + '];' + EXEC(@sql) + SET @row += 1 +END +<% end %> diff --git a/templates/query/role/member_exists.sql.erb b/templates/query/role/member_exists.sql.erb new file mode 100644 index 00000000..6072a0da --- /dev/null +++ b/templates/query/role/member_exists.sql.erb @@ -0,0 +1,18 @@ +USE [<%= @database %>]; +DECLARE + @role varchar(128) = '<%= @role %>', + @member varchar(128), + @error_msg varchar(250); + +<% @members.each do |member| %> +SET @member = '<%= member %>'; +SET @error_msg = 'The member [<%= member %>] is <% if @ensure == 'present'%>not <% end %>a member of the role [<%=@role %>]'; +<%= scope.function_template(['sqlserver/snippets/role/member_exists.sql.erb']) -%> + THROW 51000, @error_msg, 10 +<% end %> + +<% if @members_purge %> +<%= scope.function_template(['sqlserver/snippets/role/populate_purge_members.sql.erb']) %> +IF 0 != (SELECT COUNT(*) FROM @purge_members) + THROW 51000, 'Unlisted Members in Role, will be purged', 10 +<% end %> diff --git a/templates/snippets/role/member_exists.sql.erb b/templates/snippets/role/member_exists.sql.erb new file mode 100644 index 00000000..124dad35 --- /dev/null +++ b/templates/snippets/role/member_exists.sql.erb @@ -0,0 +1,5 @@ +IF NOT EXISTS ( + SELECT r.name [Role], m.name [Member] FROM sys.<%= @type.downcase %>_role_members rm + JOIN sys.<%= @type.downcase %>_principals r ON rm.role_principal_id = r.principal_id + JOIN sys.<%= @type.downcase %>_principals m ON rm.member_principal_id = m.principal_id + WHERE r.name = @role AND m.name = @member) diff --git a/templates/snippets/role/populate_purge_members.sql.erb b/templates/snippets/role/populate_purge_members.sql.erb new file mode 100644 index 00000000..f6d18dcc --- /dev/null +++ b/templates/snippets/role/populate_purge_members.sql.erb @@ -0,0 +1,11 @@ +DECLARE @purge_members TABLE ( +ID int IDENTITY(1,1), +member varchar(128) +) +INSERT INTO @purge_members (member) ( +SELECT m.name FROM sys.<%= @type.downcase %>_role_members rm + JOIN sys.<%= @type.downcase %>_principals r ON rm.role_principal_id = r.principal_id + JOIN sys.<%= @type.downcase %>_principals m ON rm.member_principal_id = m.principal_id + WHERE r.name = '<%= @role %>' + <% if !@members.empty? %>AND m.name NOT IN (<%= @members.collect{|m| "'#{m}'"}.join(',') %>)<% end %> + );