July 19, 2013 at 9:55 am
Hi Experts,
How can I grant truncate permission to users to only specified tables?
Help Please
July 19, 2013 at 10:27 am
truncate is not granular like that; it's inherent in db_owner and db_ddladmin, i believe.
just make sure noone has those rights.
what difference is there if the user is allowed to delete all rows vs truncate for you?
don't you want to prevent data deletion in general and not just the truncate command?
you could add an object with schema binding, like a view, on any table and that would prevent truncation at all., but not deleting.
Lowell
July 19, 2013 at 10:29 am
BoL clearly explains what can be done:
Permissions
The minimum permission required is ALTER on table_name. TRUNCATE TABLE permissions default to the table owner, members of the sysadmin fixed server role, and the db_owner and db_ddladmin fixed database roles, and are not transferable. However, you can incorporate the TRUNCATE TABLE statement within a module, such as a stored procedure, and grant appropriate permissions to the module using the EXECUTE AS clause.
So, you have two choices:
Grant users ALTER permission OR Create stored procedures (with EXECUTE AS) which will truncate specific tables and give users permission to execute these procs.
Just one more idea: You can create SQL script/proc which will auto generate such stored procedures for the required tables.
July 19, 2013 at 11:38 am
Thanks for your Input..
I got some input from my coleagues. This is what they suggested.
grant control on db0.personsto "SQLCentral\ptom"
It allowed to truncate that specified tables.. Does this has any security concerns ?
July 19, 2013 at 4:21 pm
Eh, yes, there are concerns, since CONTROL gives them full control on the table. ALTER is slightly better, but that may be bad enough. To you want these users add columns to right and left on these tables?
I think a better solution is to bundle the TRUNCATE TABLE statements in a stored procedure which you sign with a certificate and the create a user from that certificate that you grant the required permissions. Finally grant the users in question permission to execute the procedure(s). For more details, see this article on my web site: http://www.sommarskog.se/grantperm.html
[font="Times New Roman"]Erland Sommarskog, SQL Server MVP, www.sommarskog.se[/font]
July 19, 2013 at 6:44 pm
Eugene Elutin (7/19/2013)
BoL clearly explains what can be done:Permissions
The minimum permission required is ALTER on table_name. TRUNCATE TABLE permissions default to the table owner, members of the sysadmin fixed server role, and the db_owner and db_ddladmin fixed database roles, and are not transferable. However, you can incorporate the TRUNCATE TABLE statement within a module, such as a stored procedure, and grant appropriate permissions to the module using the EXECUTE AS clause.
So, you have two choices:
Grant users ALTER permission OR Create stored procedures (with EXECUTE AS) which will truncate specific tables and give users permission to execute these procs.
Just one more idea: You can create SQL script/proc which will auto generate such stored procedures for the required tables.
+1000 to the stored procedure method.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply