Usages of CONTEXT_INFO

  • This procedure wouldn't work for me in SQL 2005. Casting the Context_Info as varchar did not work. I had to cast the string as binary(128).

     

    I had to rewrite the trigger as following:

    IF

    (Select CONTEXT_INFO()) <> Cast('uspModifyEmployees' as binary(128))

    Also, in SQL 2005, Context_Info can be Null which it is for an ad hoc query. A Null Context_Info would not be caught by the trigger since Null is neither equal nor not equal to anything. So, I further had to modify it to account for null:

    IF

    (Select IsNull(CONTEXT_INFO(), Cast('' as binary(128)))) <> Cast('uspModifyEmployees' as binary(128))

    Of course, this doesn't really stop me from doing ad hoc queries, as I can still do this:

    Set

    Context_Info 0x7573704D6F64696679456D706C6F79656573

    Delete

    From Employees

    Where

    EmpID = 1

    SET

    CONTEXT_INFO 0x0


    My blog: SQL Soldier[/url]
    SQL Server Best Practices:
    SQL Server Best Practices
    Twitter: @SQLSoldier
    My book: Pro SQL Server 2008 Mirroring[/url]
    Microsoft Certified Master: SQL Server, Data Platform MVP
    Database Engineer at BlueMountain Capital Management[/url]

  • Interesting, but please all do not forget that this is what PERMISSIONS are for in SQL Server. I find it's best to use a thing according to its intended purpose first, and only tweak/hack it when absolutely necessary. This trick is not as secure, it's harder to understand, it would potentially make life miserable for someone working on the system who is unfamiliar with it, etc. etc.

    If you want a table to be read only, then:

    1. Set permissions for the user(s) or role(s) as Select for the table

    2. Set permissions to grant execute on the stored proc.

    This works perfectly.

  • I should also add that I can disable or drop the trigger as well.


    My blog: SQL Soldier[/url]
    SQL Server Best Practices:
    SQL Server Best Practices
    Twitter: @SQLSoldier
    My book: Pro SQL Server 2008 Mirroring[/url]
    Microsoft Certified Master: SQL Server, Data Platform MVP
    Database Engineer at BlueMountain Capital Management[/url]

  • I agree totally, in fact I go so far to say that this article is going to confuse a lot of people new to SQL Server. What the author is proposing really should be done through permissions. Simply no permissions should be granted to the table directly and execute access granted to the stored procedure itself. I'm not sure if the article was intended as an academic exercise but it seems fairly impractical approach to me.

  • Informative article... i was not aware of the CONTEXT_INFO.

    I feel that use of CONTEXT_INFO in the scripts will be creating dependencies with the developers i.e., it will be mandatory to use this in each script. Setting up the permissions will be the correct and secure option.

  • >> This may destroy the ability to use connection pooling.  Then each user will have there

    >> own connections, increasing resources on the both the db server and web (or app) server. 

    >>  Scalability and performance of your site will likely decrease. Or, if connection pooling still

    >> works when using context_info, then you will run the risk of having the Context_info reset

    >> on the connection, or being used by the wrong user.  In an ASP app, there is no guarantee

    >> that you will get the same connection each time.  And, other users will share the same

    >> connection.

    Serving the Multilingual data with concept of ContextInfo technique does not destroy the ability of Connection Poolling. The extra overhead which comes is that every command has to precede with a Set ContextInfo call based on the User's context.

    The connection Reset will not hamper the logic as the next call to the DB will precede again with a SetContextInfo call and hence different Users can share the same connection.

     

  • Of course, I don't think the author's intention was to claim that Context_Info was the solution to all of our security concerns. I think he merely chose that as an example of how to use it.

    I wonder if you can change Context_Info repeatedly within a stored. Perhaps you could use it to output debugging info or something like that. Don't you hate when you have debugging statements in a procedure, but they don't get output until the procedure completes or fails? Maybe this can be used to output some debugging info as it runs. I don't know, just a thought.


    My blog: SQL Soldier[/url]
    SQL Server Best Practices:
    SQL Server Best Practices
    Twitter: @SQLSoldier
    My book: Pro SQL Server 2008 Mirroring[/url]
    Microsoft Certified Master: SQL Server, Data Platform MVP
    Database Engineer at BlueMountain Capital Management[/url]

  • Robert Davis (12/22/2006)


    Of course, I don't think the author's intention was to claim that Context_Info was the solution to all of our security concerns. I think he merely chose that as an example of how to use it.

    I wonder if you can change Context_Info repeatedly within a stored. Perhaps you could use it to output debugging info or something like that. Don't you hate when you have debugging statements in a procedure, but they don't get output until the procedure completes or fails? Maybe this can be used to output some debugging info as it runs. I don't know, just a thought.

    If you use "raiserror('your debug statement', 10, 1) with nowait", you get the error messages in SSMS/QA immediately, at that step in the process. You can use a varchar/nvarchar variable for the debug statement, so you can even put a timestamp in it, or other data (variable values, for example). The key is the "nowait" hint. Severity 10 is used for informational messages and won't interrupt the flow of the script/proc.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • I have several layers of nested procedures and when it reached trigger time, @@spid returned the top executing sproc rather than the update sproc, so it failed out. The only way I could make it work was to add a context_info check in the trigger against every procedure that might be at the top of the hierarchy.

    Of course, this allows direct upserts in any procedure along the hierarchy, but at least it protects the table from business analysts with sysadmin rights who use "open table" all the time.

    Having standards (like good security) is nice if you can enforce them, but my shop exists somewhere in the wild west!

    Here's my latest implementation within the trigger:

    if exists (

    select *

    from sys.dm_exec_sessions as SYS

    where not exists (

    select *

    from dbo.v_lookup_context_info as sub

    where sub.context_info_as_varchar

    = cast( SYS.context_info as varchar )

    this_is_a_close_paren_that_turned_into_an_emoticon

    and session_id = @@spid

    )

    begin

    raiserror('You can not write to XXXX outside of XXXX',16,1)

    return

    end

  • This is a very interesting technique. I am using CONTEXT_INFO to set the current "ClientContext" that is executing any Procedures from an Application. This allows me to track who is retrieving data as well as doing simple things like converting all DateTime values to the client's current TimeZoneOffset. My ClientContext parameter of my Procs is sent in via Xml, converted to a simplier String (VarChar) representation to make it shorter, then set on the CONTEXT_INFO.

    No, CONTEXT_INFO has no affect on Connection Pooling. This happens AFTER a connection is made and is not part of the ConnectionString anyway. For those of you who've never watched a connection-pooled App through Profiler, you would see that basically the Pool instantiates a number of Connections on you behalf, so, "each user having their own connection" has ALWAYS been the way pooling works. Until MARS came along, you couldn't even execute multiple Readers on the same connection at the same time.

    Also, you should probably not be querying sys.dm_exec_sessions, sys.dm_exec_requests, or sys.sysprocesses directly becuase you probably won't have the correct permissions to do that in Production code. Instead, query you Context this way "SELECT CONTEXT_INFO()".

  • Also, you should probably not be querying sys.dm_exec_sessions, sys.dm_exec_requests, or sys.sysprocesses directly becuase you probably won't have the correct permissions.

    Maybe that's why I never got it to work properly, but at the time it seemed to be trouble with nested stored procedures where the wrong value persisted during execution of child procedures. It might be easier to roll your own by creating a permissions table and using triggers and OBJECT_NAME( @@PROCID ) to validate that the data manipulation is happening according to your rules.

  • An oldie, but such a goodie.

    This is exactly what I've been looking for, thank you.

Viewing 12 posts - 16 through 26 (of 26 total)

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