Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Truncate permission only on specified tables Expand / Collapse
Author
Message
Posted Friday, July 19, 2013 9:55 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: 2 days ago @ 10:12 AM
Points: 235, Visits: 974
Hi Experts,

How can I grant truncate permission to users to only specified tables?

Help Please
Post #1475571
Posted Friday, July 19, 2013 10:26 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 10:38 AM
Points: 12,880, Visits: 31,798
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1475586
Posted Friday, July 19, 2013 10:29 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Friday, July 4, 2014 3:55 AM
Points: 2,836, Visits: 5,062
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.


_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!"
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Post #1475590
Posted Friday, July 19, 2013 11:38 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: 2 days ago @ 10:12 AM
Points: 235, Visits: 974
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 ?
Post #1475613
Posted Friday, July 19, 2013 4:21 PM


Right there with Babe

Right there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with Babe

Group: General Forum Members
Last Login: Yesterday @ 2:28 PM
Points: 786, Visits: 691
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


Erland Sommarskog, SQL Server MVP, www.sommarskog.se
Post #1475708
Posted Friday, July 19, 2013 6:44 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 11:02 AM
Points: 36,727, Visits: 31,179
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
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1475719
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse