Update with column permission

  • Hello,

    I've just stumbled on a strange behavior of SQL Server 2005 when updating a table on which the user has SELECT privileges. Only the column being updated has UPDATE defined for the user. However, any update that uses a join to another table via some other column (unaffacted by update) fails with explanation that the user does not have UPDATE permissions on that column.

    Hm... maybe an example will be easier to understand.

    /*login as sysadmin and prepare environment*/

    CREATE TABLE testpriv(id INT identity, col1 int, col2 int, col3 int)

    GO

    GRANT SELECT ON testpriv TO testuser

    GRANT UPDATE ON testpriv(col1) TO testuser

    GO

    INSERT INTO testpriv (col1, col2, col3)

    SELECT 1, 2, 3

    UNION SELECT 4, 5, 6

    /*switch to testuser - verify SELECT permisssions*/

    select * from testpriv

    id col1 col2 col3

    ----------- ----------- ----------- -----------

    1 1 2 3

    2 4 5 6

    (2 row(s) affected)

    /*still as "testuser" test updating the column col1*/

    UPDATE testpriv SET col1 = 0 WHERE id = 1

    /*(1 row(s) affected) - fine, it works!*/

    /*... and now the surprise, still as testuser*/

    UPDATE t

    SET col1 = 9

    FROM testpriv t

    JOIN numbers n ON n.number = t.id

    WHERE t.id = 1

    /*The UPDATE permission was denied on the column 'id' of the object 'testpriv', database 'VLK_PRAC', schema 'dbo'.*/

    If I join using another column instead of ID, this another column will be reported as needing UPDATE permissions. I did make sure that testuser has SELECT permissions on table Numbers, and also after granting permission to UPDATE testpriv(ID) to testuser the update runs fine.

    Why is that so? Is that intended or a bug? How can I avoid this behavior - except giving permission to update ID, which seems a bit strange to me? I couldn't find anything about it in documentation, but maybe I didn't use the right search terms.

    Thanks!

  • Try granting it references permissions ...

    GRANT REFERENCES ON testpriv(id) TO test

    After that I did not have any issues updating the table as Test user.

    [font="Arial"]---

    Mohit K. Gupta, MCITP: Database Administrator (2005), My Blog, Twitter: @SQLCAN[/url].
    Microsoft FTE - SQL Server PFE

    * Some time its the search that counts, not the finding...
    * I didn't think so, but if I was wrong, I was wrong. I'd rather do something, and make a mistake than be frightened and be doing nothing. :smooooth:[/font]

    How to ask for help .. Read Best Practices here[/url].

  • Thanks for the info, but it didn't help in my case. Maybe a different version?

    On my system SELECT @@VERSION returns:

    Microsoft SQL Server 2005 - 9.00.3073.00 (X64)

    Aug 5 2008 14:31:47

    Copyright (c) 1988-2005 Microsoft Corporation

    Standard Edition (64-bit) on Windows NT 5.2 (Build 3790: Service Pack 2)

  • Hmm oops I ran it on SQL 2008; I'll check it on 2005 and get back to you. Sorry.

    Mohit.

    [font="Arial"]---

    Mohit K. Gupta, MCITP: Database Administrator (2005), My Blog, Twitter: @SQLCAN[/url].
    Microsoft FTE - SQL Server PFE

    * Some time its the search that counts, not the finding...
    * I didn't think so, but if I was wrong, I was wrong. I'd rather do something, and make a mistake than be frightened and be doing nothing. :smooooth:[/font]

    How to ask for help .. Read Best Practices here[/url].

Viewing 4 posts - 1 through 3 (of 3 total)

You must be logged in to reply to this topic. Login to reply