How to: Start SQL Server Agent When Agent XPs show Disabled

Problem
The SQL Server Agent was found stopped and the status shows “(Agent XPs disabled)” besides the SQL Server Agent, the funny thing is the service was running according to the services console. Tried to start the service from SQL Server Management Studio, but it didn’t work.

This issue appears when ‘Agent XPs’ advance configuration option is disabled and set to 0 for the SQL Server configuration..

Agent XPs is an advanced configuration option which enables the SQL Server Agent extended stored procedures on the server. When this is not enable SQL Server Agent will not be active in SSMS. Most of the time when you start the SQL Server services it automatically enables ‘Agent XPs’, but sometime it fails to enable or sets the value to 0 and then this issue will appear.

Solution
To fix this issue we should first set the ‘Agent XPs’ to 1 and then run RECONFIGURE to bring it into effect. Execute the following query and try to restart the agent service. The SQL Server agent should be online now.

sp_configure 'show advanced options',1
go
reconfigure with override
go
sp_configure 'Agent XPs',1
go
reconfigure with override
go
sp_configure 'show advanced options',0
go
reconfigure with override
go

This will be the possible output

Configuration option 'show advanced options' changed from 1 to 1. Run the RECONFIGURE statement to install.
Configuration option 'Agent XPs' changed from 0 to 1. Run the RECONFIGURE statement to install.
Configuration option 'show advanced options' changed from 1 to 0. Run the RECONFIGURE statement to install.

References

http://sqlserverzest.com/2012/09/19/agent-xps-server-configuration-option/

How to: Determine SQL Server Agent Start Up Type

This post will teach you how to retrieve the SQL Server Agent start up type from windows registry.

DECLARE @auto_start		INT
DECLARE @key			NVARCHAR(200)

SELECT @key = N'SYSTEM\CurrentControlSet\Services\'

IF (SERVERPROPERTY('INSTANCENAME') IS NOT NULL)
	SELECT @key = @key + N'SQLAgent$' + CONVERT (sysname, SERVERPROPERTY('INSTANCENAME'))
ELSE
	SELECT @key = @key + N'SQLServerAgent'
	
-- Get SQL Server start up type from windows registry
EXECUTE master.dbo.xp_regread N'HKEY_LOCAL_MACHINE',
                              @key,
                              N'Start',
                              @auto_start OUTPUT,
                              N'no_output'

-- Show the SQL Server Agent start up type                     
SELECT (CASE @auto_start
        WHEN 2 THEN 1	-- 2 means auto-start
        WHEN 3 THEN 2	-- 3 means manual
        ELSE 0		-- Safety net
      END) AS [SQLAgent_StartUp_Type]