Granting privileges to the Reviewer workspace components in SQL Server
The geodatabase administrator must grant specific privileges to the tables for all users that will be accessing the Reviewer workspace. This can be accomplished by creating database roles and assigning the roles to the individual users.
Copying and pasting the examples may cause syntax errors.
Granting permissions
In SQL Server Management Studio, grant permissions to the Reviewer workspace tables through the schema. The sample script shows how to remove existing members from a role and drop the roles. Then re-create the role and assign permissions to the role through the schema.
USE [revdb]
GO
EXEC sp_droprolemember 'rev_editor', 'giseditor'
GO
EXEC sp_droprole 'rev_editor'
GO
EXEC sp_addrole 'rev_editor', 'rev'
GO
GRANT DELETE ON SCHEMA::[rev] TO [rev_editor]
GRANT EXECUTE ON SCHEMA::[rev] TO [rev_editor]
GRANT INSERT ON SCHEMA::[rev] TO [rev_editor]
GRANT SELECT ON SCHEMA::[rev] TO [rev_editor]
GRANT UPDATE ON SCHEMA::[rev] TO [rev_editor]
GO
EXEC sp_droprolemember 'rev_viewer', 'gisviewer'
GO
EXEC sp_droprole 'rev_viewer'
GO
EXEC sp_addrole 'rev_viewer', 'rev'
GO
GRANT SELECT ON SCHEMA::[rev] TO [rev_viewer]
GO
Verifying roles
This will list the roles.
EXEC sp_helprolemember 'rev_editor'
GO
EXEC sp_helprolemember 'rev_viewer'
GO
Verifying role permissions
This will list the privileges assigned to the role.
select dp.NAME AS principal_name,
dp.type_desc AS principal_type_desc,
o.NAME AS object_name,
p.permission_name,
p.state_desc AS permission_state_desc
from sys.database_permissions p
left OUTER JOIN sys.all_objects o
on p.major_id = o.OBJECT_ID
inner JOIN sys.database_principals dp
on p.grantee_principal_id = dp.principal_id
where dp.NAME in ('rev_editor','rev_viewer')
GO
Grant a user only select, update, insert, and delete privileges to the RevAdminCustomFields and RevAdminDescriptions tables if the user has privileges to modify the database schema and to add customized error descriptions.
Creating an editor user
Users should have their own login names. The example below shows how to create an editor ArcSDE user.
Create the editor login.
USE master
GO
EXEC sp_addlogin N'giseditor', 'gis$editor', @logindb, @loginlang
GO
Create the user for the login in the REVDB.
USE [revdb]
GO
CREATE USER [giseditor] FOR LOGIN [giseditor]
GO
Add the user to the editor role.
USE [revdb]
GO
EXEC sp_addrolemember N'rev_editor', N'giseditor'
GO
Creating a viewer user
Users should have their own login names. The example below shows how to create a viewer ArcSDE user.
Create the viewer login.
USE master
GO
EXEC sp_addlogin N'gisviewer', 'gis$viewer', @logindb, @loginlang
GO
Create the user for the login in the REVDB.
USE [revdb]
GO
CREATE USER [gisviewer] FOR LOGIN [gisviewer]
GO
Add the user to the editor role.
USE [revdb]
GO
EXEC sp_addrolemember N'rev_viewer', N'gisviewer'
GO