SQL: Microsoft Dynamics NAV “kill” an idle session

One issue with applications that use a concurrent license model is the dreaded “idle user”. This is the user that had gone to lunch, to a meeting or even home for the and didn’t “logout” of the application. Under the concurrent license model this user does take up a user session, which prevents other users from accessing the application if the maximum number of seats has been reached or lead to the purchase of additional and unnecessary user licenses due to the perception of not enough seats.

Microsoft Dynamics NAV is an example of application that uses a concurrent license model and is also one application that people often ask “How can I disconnect an idle user?” While there isn’t a magic “kill idle” user setting there are a several options available. A few of these options are:

  • If the users are using Remote Desktop you can set an idle timeout to force a disconnect or manually force a disconnect of idle remote users
  • Manually remove idle users from the Microsoft Dynamics NAV session list
  • Kill a user’s SQL Server connection

Let’s jump into the last option that is listed above. In Microsoft SQL server there isn’t an “idle time” value defined for a user, however there is a last_batch value that indicates the last time the users session sent an execution to the SQL server. With that information we can easily create (and schedule) a script that can compare the current date and time to the last_batch value to see how long a user has been “idle” and kill their session if it is over a certain amount of time (script should be adjusted for your implementation):

set nocount on;
set ansi_padding on;
set ansi_nulls on;
set quoted_identifier on;

-- declare variables.
declare @spid as varchar(20)
declare @loginname as varchar(255)
declare @kill as int
declare @cmd as varchar(max)

-- set the variable @kill to 1 to actually perform the “kill or set it to 0 to see a list of users that
-- would be killed
set @kill = 0

declare users insensitive scroll cursor
for    
      select
            spid
            ,loginame
      from
            sys.sysprocesses
      where
            -- NAV Db Name    
            (db_name(dbid) = N'CRONUS')
            and (program_name = N'Microsoft Dynamics NAV Classic client')
            -- number of seconds idle -- remember this does not mean there isn't a long job running
            -- 3600 is 1 hour
            and (datediff(ss, last_batch, getdate()) > 3600)


open users
while (1=1)
      begin
            fetch next from users into @spid, @loginname;
            if @@fetch_status <> 0 break;
            
            set @cmd = 'kill ' + @spid
            if @kill = 1 
              exec (@cmd)
            else
              print @cmd + N' ' + @loginname;
      end

close users;
deallocate users;

go

 

One thing to point out is that a user may be idle because their session is performing a lengthy operation and they have not had any session activity while they are awaiting results for their command. There tends to be some disconnect and excitement when someone is in the middle of some operation and their session is killed.

It should be evident that there is a risk when abnormally terminating a user’s session. There is the risk of data loss or corruption so be certain to understand the environment that you’re in and the implications of terminating a user’s session in a not so elegant way (i.e. properly logging off).

Leave a Comment