SQL SERVER – Why Server Authentication is Disabled? What Mode is SQL Server Using Currently?

Sometimes I see weird issues with SQL Servers, and it helps me in understanding how the software works. In this blog, I would share my learning about the cause of Server Authentication mode disabled. If it is disabled, how would you know what mode is used by SQL Server?

SQL SERVER - Why Server Authentication is Disabled? What Mode is SQL Server Using Currently? authentication-800x240

Here is the screenshot of my problem statement. Weird, right?

SQL SERVER - Why Server Authentication is Disabled? What Mode is SQL Server Using Currently? auth-disabled-01

Logically thinking, if a radio button group is greyed out with nothing checked which means the value is not as expected by SQL Server Management Studio (SSMS). I captured profiler and looked at the script which is executed when we click on the “Security” tab under the “Server > Properties” window. Out of the long script, I have made a shorter version which is used to get the value to populate the server authentication. Below is the secret sauce which populates the radio button.

DECLARE @HkeyLocal NVARCHAR(18)
DECLARE @MSSqlServerRegPath NVARCHAR(31)
DECLARE @InstanceRegPath SYSNAME
DECLARE @SmoLoginMode INT;
SELECT @HkeyLocal = N'HKEY_LOCAL_MACHINE'
SELECT @MSSqlServerRegPath = N'SOFTWARE\Microsoft\MSSQLServer'
SELECT @InstanceRegPath = @MSSqlServerRegPath + N'\MSSQLServer'
EXEC master.dbo.xp_instance_regread @HkeyLocal
	,@InstanceRegPath
	,N'LoginMode'
	,@SmoLoginMode OUTPUT;
SELECT @SmoLoginMode

If the output is 1 then its “Windows Authentication mode” and if the output is 2 then its “SQL Server and Windows Authentication mode”. Feel free to run on your environment and verify it.

WORKAROUND/SOLUTION – Authentication

Now there are two possible reasons, which I can think of, to get the radio button greyed out.

  1. If the value returned is something other than one or two OR
  2. There is a failure in executing xp_instance_regread, which could be due to permission or any other reason. The best way would be to run the script and see the output.

Now, the next question would be, how to find the authentication mode used by SQL Server, if the option is greyed out? I would always look at the ERRORLOG file to see line having Authentication mode is.

SQL SERVER - Why Server Authentication is Disabled? What Mode is SQL Server Using Currently? auth-disabled-02

Here are the two possible values which I have seen.

  • Authentication mode is WINDOWS-ONLY.
  • Authentication mode is MIXED.

If you are running into the same situation, run the script and check SmoLoginMode. If the value is other than 1 or 2 then you have an issue with registry value. Fix the value and then come back to SSMS. If there is an error while running the script, please comment and let me know. You can always reach out to me on twitter here.

Reference: Pinal Dave (https://blog.sqlauthority.com)

SQL Error Messages, SQL Scripts, SQL Server, SQL Server Configuration, SQL Server Security
Previous Post
SQL SERVER – LogonUserExEx Fails for User & GetToken – Logging on as the CNO Failed With Error 1326
Next Post
SQL SERVER – Error 9002: The Transaction Log for Database ‘SQLAuthority’ is Full Due to ‘REPLICATION’

Related Posts

3 Comments. Leave new

  • Thank you for your posting.

    Reply
  • And if you just want to know which it is you can use this script.

    SELECT
    CASE SERVERPROPERTY(‘IsIntegratedSecurityOnly’)
    WHEN 1 THEN ‘Windows Authentication’
    WHEN 0 THEN ‘Windows and SQL Server Authentication’
    END AS [Authentication Mode]

    Reply
  • Brijesh Damai
    July 30, 2020 6:08 pm

    Solution for above mentioned problem of authentication option grayed out is as below, please run below script..
    It worked for me

    USE [master]
    GO
    EXEC xp_instance_regwrite N’HKEY_LOCAL_MACHINE’,
    N’Software\Microsoft\MSSQLServer\MSSQLServer’,
    N’LoginMode’, REG_DWORD, 1
    GO

    Reply

Leave a Reply