diff --git a/functions/Export-DbaDbRole.ps1 b/functions/Export-DbaDbRole.ps1 new file mode 100644 index 0000000000..42d0deccfa --- /dev/null +++ b/functions/Export-DbaDbRole.ps1 @@ -0,0 +1,395 @@ +function Export-DbaDbRole { + <# + .SYNOPSIS + Exports database roles to a T-SQL file. Export includes Role creation, object permissions and Schema ownership. + + .DESCRIPTION + Exports databsase roles to a T-SQL file. Export includes Role creation, object permissions and Schema ownership. + + This command is based off of John Eisbrener's post "Fully Script out a MSSQL Database Role" + Reference: https://dbaeyes.wordpress.com/2013/04/19/fully-script-out-a-mssql-database-role/ + + .PARAMETER SqlInstance + The target SQL Server instance or instances. SQL Server 2005 and above supported. + Any databases in CompatibilityLevel 80 or lower will be skipped + + .PARAMETER SqlCredential + Login to the target instance using alternative credentials. Windows and SQL Authentication supported. Accepts credential objects (Get-Credential) + + .PARAMETER InputObject + Enables piping from Get-DbaDatabase and Get-DbaLogin. + + .PARAMETER ScriptingOptionsObject + An SMO Scripting Object that can be used to customize the output - see New-DbaScriptingOption + + .PARAMETER Database + The database(s) to process. Options for this list are auto-populated from the server. If unspecified, all databases will be processed. + + .PARAMETER Role + The Role(s) to process. If unspecified, all Roles will be processed. + + .PARAMETER ExcludeRole + The Role(s) to exclude. + + .PARAMETER ExcludeFixedRole + Excludes all members of fixed roles. + + .PARAMETER IncludeRoleMember + Include scripting of role members in script + + .PARAMETER Path + Specifies the directory where the file or files will be exported. + Will default to Path.DbatoolsExport Configuration entry + + .PARAMETER FilePath + Specifies the full file path of the output file. If left blank then filename based on Instance name, Database name and date is created. + If more than one database or instance is input then this parameter should normally be blank. + + .PARAMETER Passthru + Output script to console only + + .PARAMETER BatchSeparator + Batch separator for scripting output. Uses the value from configuration Formatting.BatchSeparator by default. This is normally "GO" + + .PARAMETER NoClobber + If this switch is enabled, a file already existing at the path specified by Path will not be overwritten. This takes precedence over Append switch + + .PARAMETER Append + If this switch is enabled, content will be appended to a file already existing at the path specified by FilePath. If the file does not exist, it will be created. + + .PARAMETER NoPrefix + Do not include a Prefix + + .PARAMETER Encoding + Specifies the file encoding. The default is UTF8. + + Valid values are: + -- ASCII: Uses the encoding for the ASCII (7-bit) character set. + -- BigEndianUnicode: Encodes in UTF-16 format using the big-endian byte order. + -- Byte: Encodes a set of characters into a sequence of bytes. + -- String: Uses the encoding type for a string. + -- Unicode: Encodes in UTF-16 format using the little-endian byte order. + -- UTF7: Encodes in UTF-7 format. + -- UTF8: Encodes in UTF-8 format. + -- Unknown: The encoding type is unknown or invalid. The data can be treated as binary. + + + .PARAMETER EnableException + By default, when something goes wrong we try to catch it, interpret it and give you a friendly warning message. + This avoids overwhelming you with "sea of red" exceptions, but is inconvenient because it basically disables advanced scripting. + Using this switch turns this "nice by default" feature off and enables you to catch exceptions with your own try/catch. + + .NOTES + Tags: Export, Role + Author: Patrick Flynn (@sqllensman) + + Website: https://dbatools.io + Copyright: (c) 2018 by dbatools, licensed under MIT + License: MIT https://opensource.org/licenses/MIT + + .LINK + https://dbatools.io/Export-DbaDbRole + + .EXAMPLE + PS C:\> Export-DbaDbRole -SqlInstance sql2005 -Path C:\temp + + Exports the Database Roles for all for SQL Server "sql2005" and writes them to the file "C:\temp\sql2005-logins.sql" + + .EXAMPLE + PS C:\> Export-DbaDbRole -SqlInstance sqlserver2014a -ExcludeLogin realcajun -SqlCredential $scred -Path C:\temp\logins.sql -Append + + Authenticates to sqlserver2014a using SQL Authentication. Exports all logins except for realcajun to C:\temp\logins.sql, and appends to the file if it exists. If not, the file will be created. + + .EXAMPLE + PS C:\> Export-DbaDbRole -SqlInstance sqlserver2014a -Login realcajun, netnerds -Path C:\temp\logins.sql + + Exports ONLY logins netnerds and realcajun FROM sqlserver2014a to the file C:\temp\logins.sql + + .EXAMPLE + PS C:\> Export-DbaDbRole -SqlInstance sqlserver2014a -Login realcajun, netnerds -Database HR, Accounting + + Exports ONLY logins netnerds and realcajun FROM sqlserver2014a with the permissions on databases HR and Accounting + + .EXAMPLE + PS C:\> Get-DbaDatabase -SqlInstance sqlserver2014a -Database HR, Accounting | Export-DbaDbRole + + Exports ONLY logins FROM sqlserver2014a with permissions on databases HR and Accounting + + .EXAMPLE + PS C:\> Export-DbaDbRole -SqlInstance sqlserver2008 -Login realcajun, netnerds -Path C:\temp\login.sql -ExcludeGoBatchSeparator + + Exports ONLY logins netnerds and realcajun FROM sqlserver2008 server, to the C:\temp\login.sql file without the 'GO' batch separator. + + .EXAMPLE + PS C:\> Export-DbaDbRole -SqlInstance sqlserver2008 -Login realcajun -Path C:\temp\users.sql + + Exports login realcajun from sqlserver2008 to the file C:\temp\users.sql + + .EXAMPLE + PS C:\> Get-DbaDatabase -SqlInstance sqlserver2008 -Login realcajun | Export-DbaDbRole + + Exports login realcajun from sqlserver2008 + + .EXAMPLE + PS C:\> Get-DbaDbRole -SqlInstance sqlserver2008 -ExcludeFixedRole | Export-DbaDbRole + + Exports all roles from all databases on sqlserver2008, exludes all roles marked as as FixedRole + + #> + [CmdletBinding()] + param ( + [parameter()] + [DbaInstanceParameter[]]$SqlInstance, + [PSCredential]$SqlCredential, + [Parameter(ValueFromPipeline)] + [object[]]$InputObject, + [Microsoft.SqlServer.Management.Smo.ScriptingOptions]$ScriptingOptionsObject, + [object[]]$Database, + [object[]]$Role, + [object[]]$ExcludeRole, + [switch]$ExcludeFixedRole, + [switch]$IncludeRoleMember, + [string]$Path = (Get-DbatoolsConfigValue -FullName 'Path.DbatoolsExport'), + [Alias("OutFile", "FileName")] + [string]$FilePath, + [switch]$Passthru, + [string]$BatchSeparator = (Get-DbatoolsConfigValue -FullName 'Formatting.BatchSeparator'), + [switch]$NoClobber, + [switch]$Append, + [switch]$NoPrefix, + [ValidateSet('ASCII', 'BigEndianUnicode', 'Byte', 'String', 'Unicode', 'UTF7', 'UTF8', 'Unknown')] + [string]$Encoding = 'UTF8', + [switch]$EnableException + ) + begin { + $null = Test-ExportDirectory -Path $Path + $outsql = @() + $outputFileArray = @() + $roleCollection = New-Object System.Collections.ArrayList + $executingUser = [Security.Principal.WindowsIdentity]::GetCurrent().Name + $commandName = $MyInvocation.MyCommand.Name + + $roleSQL = "SELECT + N'<#RoleName#>' as RoleName, + CASE dp.state + WHEN 'D' THEN 'DENY' + WHEN 'G' THEN 'GRANT' + WHEN 'R' THEN 'REVOKE' + WHEN 'W' THEN 'GRANT' + END as GrantState, + dp.permission_name as Permission, + CASE dp.class + WHEN 0 THEN '' + WHEN 1 THEN --table or column subset on the table + CASE WHEN dp.major_id < 0 THEN COALESCE('[sys].[' + OBJECT_NAME(dp.major_id) + ']', '') + ELSE '[' + (SELECT SCHEMA_NAME(schema_id) + '].[' + name FROM sys.objects WHERE object_id = dp.major_id) + ']' + END + -- optionally concatenate column names + CASE WHEN MAX(dp.minor_id) > 0 THEN ' ([' + + REPLACE((SELECT name + '], [' FROM sys.columns + WHERE object_id = dp.major_id + AND column_id IN (SELECT minor_id FROM sys.database_permissions WHERE major_id = dp.major_id AND USER_NAME(grantee_principal_id) = N'<#RoleName#>') + FOR XML PATH('')) + '])', ', []', '') + ELSE '' + END + WHEN 3 THEN 'SCHEMA::[' + SCHEMA_NAME(dp.major_id) + ']' + WHEN 4 THEN '' + (SELECT RIGHT(type_desc, 4) + '::[' + name FROM sys.database_principals WHERE principal_id = dp.major_id) + ']' + WHEN 5 THEN 'ASSEMBLY::[' + (SELECT name FROM sys.assemblies WHERE assembly_id = dp.major_id) + ']' + WHEN 6 THEN 'TYPE::[' + (SELECT name FROM sys.types WHERE user_type_id = dp.major_id) + ']' + WHEN 10 THEN 'XML SCHEMA COLLECTION::[' + (SELECT SCHEMA_NAME(schema_id) + '.' + name FROM sys.xml_schema_collections WHERE xml_collection_id = dp.major_id) + ']' + WHEN 15 THEN 'MESSAGE TYPE::[' + (SELECT name FROM sys.service_message_types WHERE message_type_id = dp.major_id) + ']' + WHEN 16 THEN 'CONTRACT::[' + (SELECT name FROM sys.service_contracts WHERE service_contract_id = dp.major_id) + ']' + WHEN 17 THEN 'SERVICE::[' + (SELECT name FROM sys.services WHERE service_id = dp.major_id) + ']' + WHEN 18 THEN 'REMOTE SERVICE BINDING::[' + (SELECT name FROM sys.remote_service_bindings WHERE remote_service_binding_id = dp.major_id) + ']' + WHEN 19 THEN 'ROUTE::[' + (SELECT name FROM sys.routes WHERE route_id = dp.major_id) + ']' + WHEN 23 THEN 'FULLTEXT CATALOG::[' + (SELECT name FROM sys.fulltext_catalogs WHERE fulltext_catalog_id = dp.major_id) + ']' + WHEN 24 THEN 'SYMMETRIC KEY::[' + (SELECT name FROM sys.symmetric_keys WHERE symmetric_key_id = dp.major_id) + ']' + WHEN 25 THEN 'CERTIFICATE::[' + (SELECT name FROM sys.certificates WHERE certificate_id = dp.major_id) + ']' + WHEN 26 THEN 'ASYMMETRIC KEY::[' + (SELECT name FROM sys.asymmetric_keys WHERE asymmetric_key_id = dp.major_id) + ']' + END COLLATE DATABASE_DEFAULT as Type, + CASE dp.state WHEN 'W' THEN ' WITH GRANT OPTION' ELSE '' END as GrantType + FROM sys.database_permissions dp + WHERE USER_NAME(dp.grantee_principal_id) = N'<#RoleName#>' + GROUP BY dp.state, dp.major_id, dp.permission_name, dp.class + UNION ALL + SELECT + N'<#RoleName#>' as RoleName, + 'ALTER' as GrantState, + 'AUTHORIZATION' as permission_name, + 'SCHEMA::['+s.[name]+']' as Type, + '' as GrantType + from sys.schemas s + join sys.sysusers u on s.principal_id = u.[uid] + where u.[name] = N'<#RoleName#>'" + + $userSQL = "SELECT roles.name as RoleName, users.name as Member + FROM sys.database_principals users + INNER JOIN sys.database_role_members link + ON link.member_principal_id = users.principal_id + INNER JOIN sys.database_principals roles + ON roles.principal_id = link.role_principal_id + WHERE roles.name = N'<#RoleName#>'" + + if (Test-Bound -Not -ParameterName ScriptingOptionsObject) { + $ScriptingOptionsObject = New-DbaScriptingOption + $ScriptingOptionsObject.AllowSystemObjects = $false + $ScriptingOptionsObject.IncludeDatabaseRoleMemberships = $true + $ScriptingOptionsObject.ContinueScriptingOnError = $false + $ScriptingOptionsObject.IncludeDatabaseContext = $true + $ScriptingOptionsObject.IncludeIfNotExists = $false + } + + if ($ScriptingOptionsObject.NoCommandTerminator) { + $commandTerminator = '' + } else { + $commandTerminator = ';' + } + $outsql = @() + } + process { + if (Test-FunctionInterrupt) { + return + } + + if (-not $InputObject -and -not $SqlInstance) { + Stop-Function -Message "You must pipe in a role, database, or server or specify a SqlInstance" + return + } + + if ($SqlInstance) { + $InputObject = $SqlInstance + } + + foreach ($input in $InputObject) { + $inputType = $input.GetType().FullName + switch ($inputType) { + 'Sqlcollaborative.Dbatools.Parameter.DbaInstanceParameter' { + Write-Message -Level Verbose -Message "Processing DbaInstanceParameter through InputObject" + $databaseRoles = Get-DbaDBRole -SqlInstance $input -SqlCredential $sqlcredential -Database $Database -ExcludeDatabase $ExcludeDatabase -Role $Role -ExcludeRole $ExcludeRole -ExcludeFixedRole:$ExcludeFixedRole + } + 'Microsoft.SqlServer.Management.Smo.Server' { + Write-Message -Level Verbose -Message "Processing Server through InputObject" + $databaseRoles = Get-DbaDBRole -SqlInstance $input -SqlCredential $sqlcredential -Database $Database -ExcludeDatabase $ExcludeDatabase -Role $Role -ExcludeRole $ExcludeRole -ExcludeFixedRole:$ExcludeFixedRole + } + 'Microsoft.SqlServer.Management.Smo.Database' { + Write-Message -Level Verbose -Message "Processing Database through InputObject" + $databaseRoles = $input | Get-DbaDBRole -ExcludeDatabase $ExcludeDatabase -Role $Role -ExcludeRole $ExcludeRole -ExcludeFixedRole:$ExcludeFixedRole + } + 'Microsoft.SqlServer.Management.Smo.DatabaseRole' { + Write-Message -Level Verbose -Message "Processing DatabaseRole through InputObject" + $databaseRoles = $input + } + default { + Stop-Function -Message "InputObject is not a server, database, or login." + return + } + } + foreach ($dbRole in $databaseRoles) { + try { + $server = $dbRole.Parent.Parent + $db = $dbRole.Parent + if ($server.VersionMajor -lt 9) { + Stop-Function -Message "SQL Server version 9 or higher required - $server not supported." -Continue + } + $dbCompatibilityLevel = [int]($db.CompatibilityLevel.ToString().Replace('Version', '')) + if ($dbCompatibilityLevel -lt 90) { + Stop-Function -Message "$db has a compatibility level lower than Version90 and will be skipped." -Target $db -Continue + } + + $outsql += $dbRole.Script($ScriptingOptionsObject) + + $query = $roleSQL.Replace('<#RoleName#>', "$($dbRole.Name)") + $rolePermissions = $($dbRole.Parent).Query($query) + + foreach ($rolePermission in $rolePermissions) { + $script = $rolePermission.GrantState + " " + $rolePermission.Permission + if ($rolePermission.Type) { + $script += " ON " + $rolePermission.Type + } + if ($rolePermission.RoleName) { + $script += " TO [" + $rolePermission.RoleName + "]" + } + if ($rolePermission.GrantType) { + $script += " WITH GRANT OPTION" + $commandTerminator + } else { + $script += $commandTerminator + } + $outsql += "$script" + } + + if ($IncludeRoleMember) { + $query = $userSQL.Replace('<#RoleName#>', "$($dbRole.Name)") + $roleUsers = $($dbRole.Parent).Query($query) + + foreach ($roleUser in $roleUsers) { + if ($server.VersionMajor -lt 11) { + $script += "EXEC sys.sp_addrolemember @rolename=N'$roleName', @membername=N'$userName'" + } else { + $script = 'ALTER ROLE [' + $roleUser.RoleName + "] ADD MEMBER [" + $roleUser.Member + "]" + $commandTerminator + } + $outsql += "$script" + } + } + $roleObject = [PSCustomObject]@{ + Name = $dbRole.Name + Instance = $dbRole.SqlInstance + Database = $dbRole.Database + Sql = $outsql + } + $roleCollection.Add($roleObject) | Out-Null + $outsql = @() + } catch { + $outsql = @() + Stop-Function -Message "Error occurred processing role $dbRole" -Category ConnectionError -ErrorRecord $_ -Target $server -Continue + } + } + } + } + end { + if (Test-FunctionInterrupt) { return } + + $timeNow = $(Get-Date -Format (Get-DbatoolsConfigValue -FullName 'Formatting.DateTime')) + foreach ($dbRole in $roleCollection) { + $instanceName = $dbRole.Instance + $databaseName = $dbRole.Database + + $outputFileName = $instanceName.Replace('\', '$') + '-' + $databaseName.Replace('\', '$') + + if ($NoPrefix) { + $prefix = $null + } else { + $prefix = "/*`n`tCreated by $executingUser using dbatools $commandName for objects on $instanceName.$databaseName at $timeNow`n`tSee https://dbatools.io/$commandName for more information`n*/" + } + + if ($BatchSeparator) { + $sql = $dbRole.SQL -join "`r`n$BatchSeparator`r`n" + #add the final GO + $sql += "`r`n$BatchSeparator" + } else { + $sql = $dbRole.SQL + } + + if ($Passthru) { + if ($null -ne $prefix) { + $sql = "$prefix`r`n$sql" + } + $sql + } elseif ($Path -Or $FilePath) { + if ($outputFileArray -notcontains $outputFileName) { + Write-Message -Level Verbose -Message "New File $outputFileName " + if ($null -ne $prefix) { + $sql = "$prefix`r`n$sql" + } + $scriptPath = Get-ExportFilePath -Path $PSBoundParameters.Path -FilePath $PSBoundParameters.FilePath -Type sql -ServerName $outputFileName + $sql | Out-File -Encoding $Encoding -LiteralPath $scriptPath -Append:$Append -NoClobber:$NoClobber + $outputFileArray += $outputFileName + Get-ChildItem $scriptPath + } else { + Write-Message -Level Verbose -Message "Adding to $outputFileName " + $sql | Out-File -Encoding $Encoding -LiteralPath $scriptPath -Append + } + } else { + $sql + } + } + } +} \ No newline at end of file diff --git a/functions/Export-DbaServerRole.ps1 b/functions/Export-DbaServerRole.ps1 new file mode 100644 index 0000000000..69a900b15d --- /dev/null +++ b/functions/Export-DbaServerRole.ps1 @@ -0,0 +1,356 @@ +function Export-DbaServerRole { + <# + .SYNOPSIS + Exports server roles to a T-SQL file. Export includes Role creation, object permissions and Schema ownership. + + .DESCRIPTION + Exports Server roles to a T-SQL file. Export includes Role creation, object permissions and Role Members + + Applies mostly to SQL Server 2012 or Higher when user defined Server roles were added but can be used on earlier versions to get role members. + This command is an extension of John Eisbrener's post "Fully Script out a MSSQL Database Role" + Reference: https://dbaeyes.wordpress.com/2013/04/19/fully-script-out-a-mssql-database-role/ + + .PARAMETER SqlInstance + The target SQL Server instance or instances. SQL Server 2000 and above supported. + + .PARAMETER SqlCredential + Login to the target instance using alternative credentials. Windows and SQL Authentication supported. Accepts credential objects (Get-Credential) + + .PARAMETER InputObject + Enables piping from Get-DbaServerRole + + .PARAMETER ScriptingOptionsObject + An SMO Scripting Object that can be used to customize the output - see New-DbaScriptingOption + + .PARAMETER ServerRole + Server-Level role(s) to filter results to that role only. + + .PARAMETER ExcludeServerRole + Server-Level role(s) to exclude from results. + + .PARAMETER ExcludeFixedRole + Filter the fixed server-level roles. As only SQL Server 2012 or higher supports creation of server-level roles will eliminate all output for earlier versions. + + .PARAMETER IncludeRoleMember + Include scripting of role members in script + + .PARAMETER Path + Specifies the directory where the file or files will be exported. + Will default to Path.DbatoolsExport Configuration entry + + .PARAMETER FilePath + Specifies the full file path of the output file. If left blank then filename based on Instance name, Database name and date is created. + If more than one database or instance is input then this parameter should normally be blank. + + .PARAMETER Passthru + Output script to console only + + .PARAMETER BatchSeparator + Batch separator for scripting output. Uses the value from configuration Formatting.BatchSeparator by default. This is normally "GO" + + .PARAMETER NoClobber + If this switch is enabled, a file already existing at the path specified by Path will not be overwritten. This takes precedence over Append switch + + .PARAMETER Append + If this switch is enabled, content will be appended to a file already existing at the path specified by FilePath. If the file does not exist, it will be created. + + .PARAMETER NoPrefix + Do not include a Prefix + + .PARAMETER Encoding + Specifies the file encoding. The default is UTF8. + + Valid values are: + -- ASCII: Uses the encoding for the ASCII (7-bit) character set. + -- BigEndianUnicode: Encodes in UTF-16 format using the big-endian byte order. + -- Byte: Encodes a set of characters into a sequence of bytes. + -- String: Uses the encoding type for a string. + -- Unicode: Encodes in UTF-16 format using the little-endian byte order. + -- UTF7: Encodes in UTF-7 format. + -- UTF8: Encodes in UTF-8 format. + -- Unknown: The encoding type is unknown or invalid. The data can be treated as binary. + + + .PARAMETER EnableException + By default, when something goes wrong we try to catch it, interpret it and give you a friendly warning message. + This avoids overwhelming you with "sea of red" exceptions, but is inconvenient because it basically disables advanced scripting. + Using this switch turns this "nice by default" feature off and enables you to catch exceptions with your own try/catch. + + .NOTES + Tags: Export, Role + Author: Patrick Flynn (@sqllensman) + + Website: https://dbatools.io + Copyright: (c) 2018 by dbatools, licensed under MIT + License: MIT https://opensource.org/licenses/MIT + + .LINK + https://dbatools.io/Export-DbaServerRole + + .EXAMPLE + PS C:\> Export-DbaServerRole -SqlInstance sql2005 + + Exports the Server Roles for SQL Server "sql2005" and writes them to the path defined in the ConfigValue 'Path.DbatoolsExport' using a a default name pattern of ServerName-YYYYMMDDhhmmss-serverrole. Uses BatchSeparator defined by Config 'Formatting.BatchSeparator' + + .EXAMPLE + PS C:\> Export-DbaServerRole -SqlInstance sql2005 -Path C:\temp + + Exports the Server Roles for SQL Server "sql2005" and writes them to the path "C:\temp" using a a default name pattern of ServerName-YYYYMMDDhhmmss-serverrole. Uses BatchSeparator defined by Config 'Formatting.BatchSeparator' + + .EXAMPLE + PS C:\> Export-DbaServerRole -SqlInstance sqlserver2014a -FilePath C:\temp\ServerRoles.sql + + Exports the Server Roles for SQL Server sqlserver2014a to the file C:\temp\ServerRoles.sql. Overwrites file if exists + + .EXAMPLE + PS C:\> Export-DbaServerRole -SqlInstance sqlserver2014a -ServerRole SchemaReader -Passthru + + Exports ONLY ServerRole SchemaReader FROM sqlserver2014a and writes script to console + + .EXAMPLE + PS C:\> Export-DbaServerRole -SqlInstance sqlserver2008 -ExcludeFixedRole -ExcludeServerRole Public -IncludeRoleMember -FilePath C:\temp\ServerRoles.sql -Append -BatchSeparator '' + + Exports server roles from sqlserver2008, exludes all roles marked as as FixedRole and Public role. Includes RoleMembers and writes to file C:\temp\ServerRoles.sql, appending to file if it exits. Does not include a BatchSeparator + + .EXAMPLE + PS C:\> Get-DbaServerRole -SqlInstance sqlserver2012, sqlserver2014 | Export-DbaServerRole + + Exports server roles from sqlserver2012, sqlserver2014 and writes them to the path defined in the ConfigValue 'Path.DbatoolsExport' using a a default name pattern of ServerName-YYYYMMDDhhmmss-serverrole + + .EXAMPLE + PS C:\> Get-DbaServerRole -SqlInstance sqlserver2016 -ExcludeFixedRole -ExcludeServerRole Public | Export-DbaServerRole -IncludeRoleMember + + Exports server roles from sqlserver2016, exludes all roles marked as as FixedRole and Public role. Includes RoleMembers + + #> + [CmdletBinding()] + param ( + [parameter()] + [DbaInstanceParameter[]]$SqlInstance, + [PSCredential]$SqlCredential, + [Parameter(ValueFromPipeline)] + [object[]]$InputObject, + [Microsoft.SqlServer.Management.Smo.ScriptingOptions]$ScriptingOptionsObject, + [string[]]$ServerRole, + [string[]]$ExcludeServerRole, + [switch]$ExcludeFixedRole, + [switch]$IncludeRoleMember, + [string]$Path = (Get-DbatoolsConfigValue -FullName 'Path.DbatoolsExport'), + [Alias("OutFile", "FileName")] + [string]$FilePath, + [switch]$Passthru, + [string]$BatchSeparator = (Get-DbatoolsConfigValue -FullName 'Formatting.BatchSeparator'), + [switch]$NoClobber, + [switch]$Append, + [switch]$NoPrefix, + [ValidateSet('ASCII', 'BigEndianUnicode', 'Byte', 'String', 'Unicode', 'UTF7', 'UTF8', 'Unknown')] + [string]$Encoding = 'UTF8', + [switch]$EnableException + ) + begin { + $null = Test-ExportDirectory -Path $Path + $outsql = @() + $outputFileArray = @() + $roleCollection = New-Object System.Collections.ArrayList + $executingUser = [Security.Principal.WindowsIdentity]::GetCurrent().Name + $commandName = $MyInvocation.MyCommand.Name + + $roleSQL = "SELECT + CASE SPerm.state + WHEN 'D' THEN 'DENY' + WHEN 'G' THEN 'GRANT' + WHEN 'R' THEN 'REVOKE' + WHEN 'W' THEN 'GRANT' + END as GrantState, + sPerm.permission_name as Permission, + Case + WHEN SPerm.class = 100 THEN '' + WHEN SPerm.class = 101 AND sp2.type = 'S' THEN 'ON LOGIN::' + QuoteName(sp2.name) + WHEN SPerm.class = 101 AND sp2.type = 'R' THEN 'ON SERVER ROLE::' + QuoteName(sp2.name) + WHEN SPerm.class = 101 AND sp2.type = 'U' THEN 'ON LOGIN::' + QuoteName(sp2.name) + WHEN SPerm.class = 105 THEN 'ON ENDPOINT::' + QuoteName(ep.name) + WHEN SPerm.class = 108 THEN 'ON AVAILABILITY GROUP::' + QUOTENAME(ag.name) + ELSE '' + END as OnClause, + QuoteName(SP.name) as RoleName, + Case + WHEN SPerm.state = 'W' THEN 'WITH GRANT OPTION AS ' + QUOTENAME(gsp.Name) + ELSE '' + END as GrantOption + FROM sys.server_permissions SPerm + INNER JOIN sys.server_principals SP + ON SP.principal_id = SPerm.grantee_principal_id + INNER JOIN sys.server_principals gsp + ON gsp.principal_id = SPerm.grantor_principal_id + LEFT JOIN sys.endpoints ep + ON ep.endpoint_id = SPerm.major_id + AND SPerm.class = 105 + LEFT JOIN sys.server_principals sp2 + ON sp2.principal_id = SPerm.major_id + AND SPerm.class = 101 + LEFT JOIN + ( + Select + ar.replica_metadata_id, + ag.name + from sys.availability_groups ag + INNER JOIN sys.availability_replicas ar + ON ag.group_id = ar.group_id + ) ag + ON ag.replica_metadata_id = SPerm.major_id + AND SPerm.class = 108 + where sp.type='R' + and sp.name=N'<#RoleName#>'" + + if (Test-Bound -Not -ParameterName ScriptingOptionsObject) { + $ScriptingOptionsObject = New-DbaScriptingOption + $ScriptingOptionsObject.AllowSystemObjects = $false + $ScriptingOptionsObject.ContinueScriptingOnError = $false + $ScriptingOptionsObject.IncludeDatabaseContext = $true + $ScriptingOptionsObject.IncludeIfNotExists = $true + $ScriptingOptionsObject.ScriptOwner = $true + } + + if ($ScriptingOptionsObject.NoCommandTerminator) { + $commandTerminator = '' + } else { + $commandTerminator = ';' + } + $outsql = @() + } + process { + if (Test-FunctionInterrupt) { + return + } + + if (-not $InputObject -and -not $SqlInstance) { + Stop-Function -Message "You must pipe in a ServerRole or server or specify a SqlInstance" + return + } + + if ($SqlInstance) { + $InputObject = $SqlInstance + } + + foreach ($input in $InputObject) { + $inputType = $input.GetType().FullName + switch ($inputType) { + 'Sqlcollaborative.Dbatools.Parameter.DbaInstanceParameter' { + Write-Message -Level Verbose -Message "Processing DbaInstanceParameter through InputObject" + $serverRoles = Get-DbaServerRole -SqlInstance $input -SqlCredential $sqlcredential -ServerRole $ServerRole -ExcludeServerRole $ExcludeServerRole -ExcludeFixedRole:$ExcludeFixedRole + } + 'Microsoft.SqlServer.Management.Smo.Server' { + Write-Message -Level Verbose -Message "Processing Server through InputObject" + $serverRoles = Get-DbaServerRole -SqlInstance $input -SqlCredential $sqlcredential -ServerRole $ServerRole -ExcludeServerRole $ExcludeServerRole -ExcludeFixedRole:$ExcludeFixedRole + } + 'Microsoft.SqlServer.Management.Smo.ServerRole' { + Write-Message -Level Verbose -Message "Processing ServerRole through InputObject" + $serverRoles = $input + } + default { + Stop-Function -Message "InputObject is not a server or serverrole." + return + } + } + + foreach ($role in $serverRoles) { + $server = $role.Parent + + if ($server.ServerType -eq 'SqlAzureDatabase') { + Stop-Function -Message "The SqlAzureDatabase - $server is not supported." -Continue + } + + try { + # Get user defined Server roles + if ($server.VersionMajor -ge 11) { + $outsql += $role.Script($ScriptingOptionsObject) + + $query = $roleSQL.Replace('<#RoleName#>', "$($role.Name)") + $rolePermissions = $server.Query($query) + + foreach ($rolePermission in $rolePermissions) { + $script = $rolePermission.GrantState + " " + $rolePermission.Permission + if ($rolePermission.OnClause) { + $script += " " + $rolePermission.OnClause + } + if ($rolePermission.RoleName) { + $script += " TO " + $rolePermission.RoleName + } + if ($rolePermission.GrantOption) { + $script += " " + $rolePermission.GrantOption + $commandTerminator + } else { + $script += $commandTerminator + } + $outsql += "$script" + } + } + + if ($IncludeRoleMember) { + foreach ($roleUser in $role.Login) { + $script = 'ALTER SERVER ROLE [' + $role.Role + "] ADD MEMBER [" + $roleUser + "]" + $commandTerminator + $outsql += "$script" + } + } + if ($outsql) { + $roleObject = [PSCustomObject]@{ + Name = $role.Name + Instance = $role.SqlInstance + Sql = $outsql + } + } + $roleCollection.Add($roleObject) | Out-Null + $outsql = @() + } catch { + $outsql = @() + Stop-Function -Message "Error occurred processing role $Role" -Category ConnectionError -ErrorRecord $_ -Target $role.SqlInstance -Continue + } + } + } + } + end { + if (Test-FunctionInterrupt) { return } + + $timeNow = $(Get-Date -Format (Get-DbatoolsConfigValue -FullName 'Formatting.DateTime')) + foreach ($role in $roleCollection) { + $instanceName = $role.Instance + + if ($NoPrefix) { + $prefix = $null + } else { + $prefix = "/*`n`tCreated by $executingUser using dbatools $commandName for objects on $instanceName.$databaseName at $timeNow`n`tSee https://dbatools.io/$commandName for more information`n*/" + } + + if ($BatchSeparator) { + $sql = $role.SQL -join "`r`n$BatchSeparator`r`n" + #add the final GO + $sql += "`r`n$BatchSeparator" + } else { + $sql = $role.SQL + } + + if ($Passthru) { + if ($null -ne $prefix) { + $sql = "$prefix`r`n$sql" + } + $sql + } elseif ($Path -Or $FilePath) { + $outputFileName = $instanceName.Replace('\', '$') + if ($outputFileArray -notcontains $outputFileName) { + Write-Message -Level Verbose -Message "New File $outputFileName " + if ($null -ne $prefix) { + $sql = "$prefix`r`n$sql" + } + $scriptPath = Get-ExportFilePath -Path $PSBoundParameters.Path -FilePath $PSBoundParameters.FilePath -Type sql -ServerName $outputFileName + $sql | Out-File -Encoding $Encoding -LiteralPath $scriptPath -Append:$Append -NoClobber:$NoClobber + $outputFileArray += $outputFileName + Get-ChildItem $scriptPath + } else { + Write-Message -Level Verbose -Message "Adding to $outputFileName " + $sql | Out-File -Encoding $Encoding -LiteralPath $scriptPath -Append + } + } else { + $sql + } + } + } +} \ No newline at end of file diff --git a/functions/Get-DbaDbRole.ps1 b/functions/Get-DbaDbRole.ps1 index 8ab860ae70..29cb7988c9 100644 --- a/functions/Get-DbaDbRole.ps1 +++ b/functions/Get-DbaDbRole.ps1 @@ -104,6 +104,9 @@ function Get-DbaDbRole { } foreach ($db in $InputObject) { + if ($db.IsAccessible -eq $false) { + continue + } $server = $db.Parent Write-Message -Level 'Verbose' -Message "Getting Database Roles for $db on $server" diff --git a/functions/Get-DbaServerRole.ps1 b/functions/Get-DbaServerRole.ps1 index 1f87a1ab3b..2e03074f9c 100644 --- a/functions/Get-DbaServerRole.ps1 +++ b/functions/Get-DbaServerRole.ps1 @@ -65,6 +65,9 @@ function Get-DbaServerRole { Stop-Function -Message "Error occurred while establishing connection to $instance" -Category ConnectionError -ErrorRecord $_ -Target $instance -Continue } + if ($server.ServerType -eq 'SqlAzureDatabase') { + Stop-Function -Message "The SqlAzureDatabase - $server is not supported." -Continue + } $serverroles = $server.Roles if ($ServerRole) { diff --git a/tests/Export-DbaDbRole.Tests.ps1 b/tests/Export-DbaDbRole.Tests.ps1 new file mode 100644 index 0000000000..452016eafb --- /dev/null +++ b/tests/Export-DbaDbRole.Tests.ps1 @@ -0,0 +1,88 @@ +$CommandName = $MyInvocation.MyCommand.Name.Replace(".Tests.ps1", "") +Write-Host -Object "Running $PSCommandPath" -ForegroundColor Cyan +. "$PSScriptRoot\constants.ps1" + +Describe "$CommandName Unit Tests" -Tag 'UnitTests' { + Context "Validate parameters" { + [object[]]$params = (Get-Command $CommandName).Parameters.Keys | Where-Object {$_ -notin ('whatif', 'confirm')} + [object[]]$knownParameters = 'SqlInstance', 'SqlCredential', 'InputObject', 'ScriptingOptionsObject', 'Database', 'Role', 'ExcludeRole', 'ExcludeFixedRole', 'IncludeRoleMember', 'Path', 'FilePath', 'Passthru', 'BatchSeparator', 'NoClobber', 'Append', 'NoPrefix', 'Encoding', 'EnableException' + $knownParameters += [System.Management.Automation.PSCmdlet]::CommonParameters + It "Should only contain our specific parameters" { + (@(Compare-Object -ReferenceObject ($knownParameters | Where-Object {$_}) -DifferenceObject $params).Count ) | Should Be 0 + } + } +} + +Describe "$commandname Integration Tests" -Tags "IntegrationTests" { + BeforeAll { + $AltExportPath = "$env:USERPROFILE\Documents" + $outputFile1 = "$AltExportPath\Dbatoolsci_DbRole_CustomFile1.sql" + try { + $random = Get-Random + $dbname1 = "dbatoolsci_exportdbadbrole$random" + $login1 = "dbatoolsci_exportdbadbrole_login1$random" + $user1 = "dbatoolsci_exportdbadbrole_user1$random" + $dbRole = "dbatoolsci_SpExecute$random" + + $server = Connect-DbaInstance -SqlInstance $script:instance2 + $null = $server.Query("CREATE DATABASE [$dbname1]") + $null = $server.Query("CREATE LOGIN [$login1] WITH PASSWORD = 'GoodPass1234!'") + $server.Databases[$dbname1].ExecuteNonQuery("CREATE USER [$user1] FOR LOGIN [$login1]") + + $server.Databases[$dbname1].ExecuteNonQuery("ALTER ROLE [$dbRole] ADD MEMBER [$user1]") + $server.Databases[$dbname1].ExecuteNonQuery("GRANT SELECT ON SCHEMA::dbo to [$dbRole]") + $server.Databases[$dbname1].ExecuteNonQuery("GRANT EXECUTE ON SCHEMA::dbo to [$dbRole]") + $server.Databases[$dbname1].ExecuteNonQuery("GRANT VIEW DEFINITION ON SCHEMA::dbo to [$dbRole]") + } catch {} + } + AfterAll { + try { + Remove-DbaDatabase -SqlInstance $script:instance2 -Database $dbname1 -Confirm:$false + Remove-DbaLogin -SqlInstance $script:instance2 -Login $login1 -Confirm:$false + } catch { } + (Get-ChildItem $outputFile1 -ErrorAction SilentlyContinue) | Remove-Item -ErrorAction SilentlyContinue + } + + Context "Check if output file was created" { + + $null = Export-DbaDbRole -SqlInstance $script:instance2 -Database msdb -FilePath $outputFile1 + It "Exports results to one sql file" { + (Get-ChildItem $outputFile1).Count | Should Be 1 + } + It "Exported file is bigger than 0" { + (Get-ChildItem $outputFile1).Length | Should BeGreaterThan 0 + } + } + + Context "Check piping support" { + + $role = Get-DbaDbRole -SqlInstance $script:instance2 -Database $dbname1 -Role $dbRole + $null = $role | Export-DbaDbRole -FilePath $outputFile1 + It "Exports results to one sql file" { + (Get-ChildItem $outputFile1).Count | Should Be 1 + } + It "Exported file is bigger than 0" { + (Get-ChildItem $outputFile1).Length | Should BeGreaterThan 0 + } + + $script:results = $role | Export-DbaDbRole -Passthru + It "should include the defined BatchSeparator" { + $script:results -match "GO" + } + It "should include the role" { + $script:results -match "CREATE ROLE [$dbRole]" + } + It "should include GRANT EXECUTE ON SCHEMA" { + $script:results -match "GRANT EXECUTE ON SCHEMA::[dbo] TO [$dbRole];" + } + It "should include GRANT SELECT ON SCHEMA" { + $script:results -match "GRANT SELECT ON SCHEMA::[dbo] TO [$dbRole];" + } + It "should include GRANT VIEW DEFINITION ON SCHEMA" { + $script:results -match "GRANT VIEW DEFINITION ON SCHEMA::[dbo] TO [$dbRole];" + } + It "should include ALTER ROLE ADD MEMBER" { + $script:results -match "ALTER ROLE [$dbRole] ADD MEMBER [$user1];" + } + } +} \ No newline at end of file diff --git a/tests/Export-DbaServerRole.Tests.ps1 b/tests/Export-DbaServerRole.Tests.ps1 new file mode 100644 index 0000000000..b6fd57a4b5 --- /dev/null +++ b/tests/Export-DbaServerRole.Tests.ps1 @@ -0,0 +1,88 @@ +$CommandName = $MyInvocation.MyCommand.Name.Replace(".Tests.ps1", "") +Write-Host -Object "Running $PSCommandPath" -ForegroundColor Cyan +. "$PSScriptRoot\constants.ps1" + +Describe "$CommandName Unit Tests" -Tag 'UnitTests' { + Context "Validate parameters" { + [object[]]$params = (Get-Command $CommandName).Parameters.Keys | Where-Object {$_ -notin ('whatif', 'confirm')} + [object[]]$knownParameters = 'SqlInstance', 'SqlCredential', 'InputObject', 'ScriptingOptionsObject', 'ServerRole', 'ExcludeServerRole', 'ExcludeFixedRole', 'IncludeRoleMember', 'Path', 'FilePath', 'Passthru', 'BatchSeparator', 'NoClobber', 'Append', 'NoPrefix', 'Encoding', 'EnableException' + $knownParameters += [System.Management.Automation.PSCmdlet]::CommonParameters + It "Should only contain our specific parameters" { + (@(Compare-Object -ReferenceObject ($knownParameters | Where-Object {$_}) -DifferenceObject $params).Count ) | Should Be 0 + } + } +} + +Describe "$commandname Integration Tests" -Tags "IntegrationTests" { + BeforeAll { + $AltExportPath = "$env:USERPROFILE\Documents" + $outputFile = "$AltExportPath\Dbatoolsci_ServerRole.sql" + try { + $random = Get-Random + $login1 = "dbatoolsci_exportdbaserverrole_login1$random" + $svRole = "dbatoolsci_ScriptPermissions$random" + + $server = Connect-DbaInstance -SqlInstance $script:instance2 + $null = $server.Query("CREATE LOGIN [$login1] WITH PASSWORD = 'GoodPass1234!'") + $null = $server.Query("CREATE SERVER ROLE [$svRole] AUTHORIZATION [$login1]") + $null = $server.Query("ALTER SERVER ROLE [dbcreator] ADD MEMBER [$svRole]") + $null = $server.Query("GRANT CREATE TRACE EVENT NOTIFICATION TO [$svRole]") + $null = $server.Query("DENY SELECT ALL USER SECURABLES TO [$svRole]") + $null = $server.Query("GRANT VIEW ANY DEFINITION TO [$svRole]") + $null = $server.Query("GRANT VIEW ANY DATABASE TO [$svRole]") + } catch {} + } + AfterAll { + try { + Remove-DbaServerRole -SqlInstance $script:instance2 -ServerRole $svRole -Confirm:$false + Remove-DbaLogin -SqlInstance $script:instance2 -Login $login1 -Confirm:$false + + } catch { } + (Get-ChildItem $outputFile -ErrorAction SilentlyContinue) | Remove-Item -ErrorAction SilentlyContinue + } + + Context "Check if output file was created" { + + $null = Export-DbaServerRole -SqlInstance $script:instance2 -FilePath $outputFile + It "Exports results to one sql file" { + (Get-ChildItem $outputFile).Count | Should Be 1 + } + It "Exported file is bigger than 0" { + (Get-ChildItem $outputFile).Length | Should BeGreaterThan 0 + } + } + + Context "Check using piped input created" { + $role = Get-DbaServerRole -SqlInstance $script:instance2 -ServerRole $svRole + $null = $role | Export-DbaServerRole -FilePath $outputFile + It "Exports results to one sql file" { + (Get-ChildItem $outputFile).Count | Should Be 1 + } + It "Exported file is bigger than 0" { + (Get-ChildItem $outputFile).Length | Should BeGreaterThan 0 + } + + $script:results = $role | Export-DbaServerRole -Passthru + It "should include the defined BatchSeparator" { + $script:results -match "GO" + } + It "should include the role" { + $script:results -match "CREATE SERVER ROLE [$svRole]" + } + It "should include ADD MEMBER" { + $script:results -match "ALTER SERVER ROLE [dbcreator] ADD MEMBER [$svRole]" + } + It "should include GRANT CREATE TRACE EVENT" { + $script:results -match "GRANT CREATE TRACE EVENT NOTIFICATION TO [$svRole]" + } + It "should include DENY SELECT ALL USER SECURABLES" { + $script:results -match "DENY SELECT ALL USER SECURABLES TO [$svRole]" + } + It "should include VIEW ANY DEFINITION" { + $script:results -match "GRANT VIEW ANY DEFINITION TO [$svRole];" + } + It "should include GRANT VIEW ANY DATABASE" { + $script:results -match "GRANT VIEW ANY DATABASE TO [$svRole];" + } + } +} \ No newline at end of file