Permissions on sys.transmission_queue

  • Hi All,

    We have several DBs on several servers hosting Service Broker and our developers generally monitor them (which is just as well as I'm not very familiar with SB).

    On some DBs, they're unable to view the contents of sys.transmission_queue - they don't receive an error, just no rows returned.

    I've tried granting them SELECT access on it, VIEW DEFINITION on the DB and data_reader on the DB. They've only been able to see the contents if I've given them db_owner or sysadmin, which I don't want to do. On other DBs, they can see the contents without such elevated permissions (although with multiple AD group membership, it's possible that they do have such permissions - I'm investigating this now).

    What's the minimum permission that I need to grant to allow a user to query sys.transmission_queue?

    Thanks

    Simon

  • According to the definition of sys.transmission_queue you need to be member of the db_owner role.

    Check out the WHERE clause below:

    sp_helptext 'sys.transmission_queue'

    CREATE VIEW sys.transmission_queue AS

    SELECT conversation_handle = S.handle,

    to_service_name = Q.tosvc,

    to_broker_instance = Q.tobrkrinst,

    from_service_name = Q.fromsvc,

    service_contract_name = Q.svccontr,

    enqueue_time = Q.enqtime,

    message_sequence_number = Q.msgseqnum,

    message_type_name = Q.msgtype,

    is_conversation_error = sysconv(bit, Q.status & 2),

    is_end_of_dialog = sysconv(bit, Q.status & 4),

    message_body = Q.msgbody,

    transmission_status = GET_TRANSMISSION_STATUS (S.handle)

    FROM sys.sysxmitqueue Q

    INNER JOIN sys.sysdesend S WITH (NOLOCK) on Q.dlgid = S.diagid AND Q.finitiator = S.initiator

    WHERE is_member('db_owner') = 1

  • Thanks Nils,

    I guess the fact that it returned 0 results rather than failed should have given me a clue. Not the answer I wanted, but thanks for resolving it.

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

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