DBmail shut down and how to audit.

  • We had an issue and was noticed until client inform. [br]
    Can someone help on how to audit who stopped it and how to configure alert when DBmail is stop.

  • anzz - Wednesday, January 18, 2017 1:38 PM

    We had an issue and was noticed until client inform. [br]
    Can someone help on how to audit who stopped it and how to configure alert when DBmail is stop.

    You can check the default trace files for ErrorLog event class and you will find the statement:
    <timestamp> spidXX  Configuration option 'Database Mail XPs' changed from 1 to 0. Run the RECONFIGURE statement to install.
    The user name column will have the user.
    It also gets logged to the SQL Server Error Log but won't have the user name in there. But you would look for the same statement that is in the trace.
    In terms of auditing, it would be hard to send an alert when mail doesn't work so what we've usually done is have the alert setup through Windows monitoring tools, pretty much all of them can read the event logs and send alerts. It's logged to the Application Event log by default. The same statement:
    Configuration option 'Database Mail XPs' changed from 1 to 0. Run the RECONFIGURE statement to install.
    with the event ID 15457
    Most of the times we've set this up they needed to do it by event id and source, depends on what it being used. 

    Sue

  • Database mail uses a queue and Service Broker to handle the sending of mail, and it will activate when necessary.  It is normal to see the process that handles this stop when it has nothing to do.  Here's some queries to check:

    USE msdb

    -- see if enabled
    SELECT * FROM sys.configurations
      WHERE name = 'Database Mail XPs'

    -- all messages
    SELECT * FROM dbo.sysmail_allitems
      WHERE send_request_date >= DATEADD(day, DATEDIFF(day, 0, GETDATE()), 0) --'2016-02-15'
      ORDER BY send_request_date DESC

    -- messages not sent in past day
    SELECT * FROM dbo.sysmail_allitems
      WHERE sent_date > GETDATE() - 1
        AND sent_status <> 'sent'
      ORDER BY send_request_date DESC

    -- error log
    SELECT i.mailitem_id, i.subject, i.send_request_date, l.log_date, i.body, i.file_attachments, l.description
      FROM dbo.sysmail_faileditems as i
        INNER JOIN dbo.sysmail_event_log AS l ON i.mailitem_id = l.mailitem_id
      WHERE i.last_mod_date > GETDATE() - 1
      ORDER BY i.send_request_date DESC, l.log_date DESC

    -- unsent
    SELECT * FROM dbo.sysmail_unsentitems

    more detailed troubleshooting database mail:
    https://technet.microsoft.com/en-us/library/ms189959(v=sql.105).aspx

    to learn about database mail:
    https://technet.microsoft.com/en-us/library/ms175887(v=sql.105).aspx

  • Chris already posted most of what I would have said with querying the mail system tables.  The only thing I'll add is how to check to see if the mail system is running.

    EXECUTE msdb.dbo.sysmail_help_status_sp;

    If the configuration Database Mail XPs isn't enabled, you won't be able to execute this procedure because it'll be blocked.

  • Thanks for the reply. 

    how to monitor DBmail, I mean in terms of audit if the DBmail is stopped.

  • anzz - Thursday, January 19, 2017 2:17 PM

    Thanks for the reply. 

    how to monitor DBmail, I mean in terms of audit if the DBmail is stopped.

    you missed the point above. it starts itself automatically when there's something int he queue, and turnns itself off after it is idle for a while.

    what you should audit is failed mail: items that are in the sent mail with a status that is not sent, and dig intot eh specific errors to find out wher ethe issue is.

    this is what i use; if it's been days or weeks since the last error, you are in good shape.
    SELECT top 100
    mail.send_request_date As SentDate,
    sent_status As Reason,
    err.[description],
    mail.*
    FROM [msdb].[dbo].[sysmail_allitems] mail
    inner join [msdb].[dbo].[sysmail_event_log] err
      ON err.mailitem_id = mail.mailitem_id
    WHERE mail.sent_status <> 'sent'
      order by mailitem_id desc

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

Viewing 6 posts - 1 through 5 (of 5 total)

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