Skip to main content

Audit SQL Logins

Written by David Postlethwaite
 
There are several ways that you can audit who has logged in to your SQL Server. The easiest way is to turn on logon Auditing under server properties. Here you can audit failed logins, successful logins, or both.
 
AuditLogins
 
This will put the audit records into the Windows event log. The failed logins is pretty useful because there shouldn't be many of them. But the successful logins turns out not to be so helpful because it records every single login which includes the service account. It turns out this logs into the server every few seconds so you end up with so much data in the event log that it's impossible to find anything else, especially the rogue user.
 
The Enterprise version has a built in auditing option which writes to a user defined event log but again this still suffers the same problem in that it audits every login.
What would be better is a way of selectively auditing only those logins we want to see (or not recording those we aren't interested in).
 
One way this can be achieve is by using a login trigger to write the login information to a table. We can easily collect the login information we want:
App_Name() will tell us the calling application
HOST_NAME() will tell us the calling computer
eventdata() can return the login name
 
The trigger can capture the login data and run a query to filter out the logins we don't want to record and then write the data to a table.
 
In this case I chose to filter on the application name rather than a login name. My thinking here was that a user who can use the application might be tempted to try and use Excel or Access to view the raw data. This worked well but I found the table was filling up with records of me using SSMS. I didn't want to audit the DBA team doing their day to day job but I definitely wanted to audit anyone else using SSMS. So I added a second filter to look for a combination of User Name, Application Name and connecting Host Name.
 
1st  create a table to hold the login information
CREATE TABLE [dbo].[Succ_Logins](
      [Succ_ServerName] [varchar](100) NULL,
      [Succ_EventTime] [datetime] NULL,
      [Succ_EventType] [varchar](100) NULL,
      [Succ_LoginName] [varchar](100) NULL,
      [Succ_IPAddress] [varchar](100) NULL,
      [Succ_HostName] [varchar](100) NULL,
      [Succ_AppName] [varchar](100) NULL,
      [Succ_EventData] [xml] NULL
) ON [PRIMARY]
 
2nd  create a table to hold the logins that we don't want to audit
 
CREATE TABLE dbo. LoginsNotToAudit(
      [App_AppName] [varchar](100) NULL,
      [App_HostName] [varchar](100) NULL,
      [App_LoginName] [varchar](100) NULL
) ON [PRIMARY]
ALTER TABLE [dbo].[ LoginsNotToAudit] ADD  CONSTRAINT [DF_LoginsNotToAudit_App_HostName]  DEFAULT ('') FOR [App_HostName]
ALTER TABLE [dbo].[ LoginsNotToAudit] ADD  CONSTRAINT [DF_LoginsNotToAudit_App_LoginName]  DEFAULT ('') FOR [App_LoginName]
 
Add some records . Note you can use a % in the value
 
insert into dbo.LoginsNotToAudit (App_AppName) values ('Microsoft SQL Server')
insert into dbo.LoginsNotToAudit (App_AppName) values ('Report Server%')
insert into dbo.LoginsNotToAudit (App_AppName) values ('SQL Server Data Collector%')
insert into dbo.LoginsNotToAudit (App_AppName) values ('SQLAgent%')
insert into dbo.LoginsNotToAudit (App_AppName) values ('Data Collector%')
insert into dbo.LoginsNotToAudit (App_AppName) values ('DatabaseMail%')
insert into dbo.LoginsNotToAudit (App_AppName) values ('Microsoft SQL Server Management Studio - Transact-SQL IntelliSense')
insert into dbo.LoginsNotToAudit ([App_AppName],App_HostName,App_LoginName) values('.Net SqlClient Data Provider%','Computer1','User1')
 
And here is the trigger
 
CREATE TRIGGER AuditSQLLogins
on all server
with execute as 'sa'
for LOGON
AS BEGIN
BEGIN TRY
  DECLARE @event XML
  SET @event = eventdata()
  IF (select count(App_AppName) from auditDB.dbo.LoginsNotToAudit
  where App_Name() LIKE App_AppName AND APP_HostName='' AND App_LoginName=''
  OR
  App_Name() LIKE App_AppName AND APP_HostName=HOST_NAME()
  AND App_LoginName=CAST(@event.query('/EVENT_INSTANCE/LoginName/text()') AS VARCHAR(100))) = 0
  BEGIN
    BEGIN TRANSACTION
    INSERT INTO auditDB.dbo.Succ_logins (Succ_EventTime,Succ_EventType,Succ_LoginName,Succ_IPAddress,Succ_AppName,Succ_HostName,Succ_ServerName,Succ_EventData)
    VALUES(CAST(CAST(@event.query('/EVENT_INSTANCE/PostTime/text()') AS VARCHAR(64)) AS DATETIME),
       CAST(@event.query('/EVENT_INSTANCE/EventType/text()') AS VARCHAR(100)),
       CAST(@event.query('/EVENT_INSTANCE/LoginName/text()') AS VARCHAR(100)),
       CAST(@event.query('/EVENT_INSTANCE/ClientHost/text()') AS VARCHAR(100)),
       APP_NAME(),
       HOST_NAME(),
       @@SERVERNAME,
       @event)
    COMMIT TRANSACTION
  END
END TRY
BEGIN CATCH
   -- This will not stop the trigger from returning an error
  ROLLBACK TRANSACTION   
END CATCH
END
 
I've run this on several 2008 servers without any noticeable degradation in performance.
But there is a major drawback of using a Login trigger.
 
If the code causes an error then the trigger will fail. If it fails then the users can't login. They will receive an error Logon failed for login 'Domain\username' due to trigger execution.
No amount of try- catch, error trapping or transaction rollbacks will help. Any error will cause the trigger to exit as failed I found this out when a new application started using the server but it wasn't added to the LoginsNotToAudit table, the database ran out of room so the insert failed and so the trigger failed and no one could login I now have a daily job that counts the records in the table to check it's not filling up too quickly
 
If the trigger is failing then the only way to login is to use the Dedicated Administrator Connection or DAC. The Login Trigger doesn't fire when you login using the DAC.
  • Only sysadmins can use DAC
  • There can be only one DAC connection at a time
  • To use DAC with SSMS, prefix the server name with ADMIN:  The important point with SSMS is you can only open a query window with DAC you can't use Object Explorer since this uses more than one connection -you will get an error.
  • You can also use SQLCMD with the "-A" switch  SQLCMD –A –S [SQL Server Name] –U [User Name] –P [Password]  –Q [query]
  • By default you can't connect remotely using the DAC so make sure you can RDP to the SQL Server
To allows remote connections use sp_configure, but there is are security implications of allowing remote DAC connections
 
sp_configure 'remote admin connections', 1
reconfigure with override
 
Once you have your DAC connections you can disable the query using
 
disable trigger AuditSQlLogins ON ALL SERVER
 
 
If you do need to audit logins to SQL this does work very well but does require some administration. Make sure all the DBAs know how to disable the trigger in the event it does fail and keep an eye on the number of records you are collecting. In my experience once you filtered out he DBAs and the application connections there aren't that many records. Which makes looking for the rogue user a bit easier.

Comments

Post a Comment

Popular posts from this blog

SQL Server 2012 and Virtual Service Accounts

This post is written by David Postlethwaite
If you are using SQL Server 2012 you will probably have noticed that the default account for the SQL services has changed from that used in previous versions. With SQL 2005 and 2008 the default account for SQL service and SQL Agent service was “NT Authority\System”. This is one the built in accounts on a Windows machine, managed by the machine and selectable from a dedicated dropdown list

The Network Service account was introduced in Windows 2003 as an alternative to using the LocalSystem account, which has full local system privileges on the local machine, a major security concern.
The Network Service has limited local privileges easing these security concerns but when many services on a machine use the Network Service account it becomes harder to track which service is actually accessing resources and performing actions, because all the services are using the one Network Service account.
Also, this account, by default, has sysadmin per…

Always Encrypted

By David Postlethwaite

Always Encrypted is new features in SQL Server 2016 and it is also available in Azure SQL Database. Here you can encrypt columns in a table with a master key and a certificate so that they will appear as encrypted strings to those who don’t have the required certificate installed on their pc.
Once the certificate is installed on the computer then the unencrypted data can then be seen as normal.

The data passes from database to your application as the encrypted value, only the application with the correct certificate can unencrypt the data so it is secure across the wire. This will go some way to resolving the concern of people worried about putting their sensitive data on a shared server in the cloud such as Microsoft Azure and accessing the data across the Internet.

At the time of writing Always Encrypted is only supported with ADO.NET 4.6, JDBC 6.0 and ODBC 13.1 but expect other driver to become available.

The calling application (including SSMS) must also hav…

New in SQL Server 2017: Graph Databases

David has recorded and published a video of his presentation on SQL Server Graph Database. In his video which you can watch below, David provides an excellent introduction into SQL Server 2017 Graph Databases. In his presentation he looks at Tennis results at tournaments for  his favourite player "The Fed"  Rodger Federer.

David  shows how to set up graph database and work with them in SQL Server 2017.

Graph Database is not new. Other vendors have had graph database capabilities for some time so Microsoft are quite late to the market. In David presentation it appears that Microsoft have done a reasonable job of implementing some of the graph database features but he does point some of the limitations of the Microsoft product too and suggests that it is not ready for production yet but Microsoft seem serious about this feature.

Please watch the video and feel free to leave a comment or feedback - David is delivering a version of this talk on Graph databases in SQL Saturday Ka…