• I have modified the script to avoid sp_configure and cursors.

    ;

    WITH cteConfigValues AS

    (

    SELECT

    ConfigurationName = [name]

    ,[Description]

    ,CurrentValue =

    CASE [value_in_use]

    WHEN 0 THEN 0

    ELSE 1

    END

    ,[value_in_use]

    FROM

    [master].sys.configurations

    WHERE

    [name] IN

    (

    'affinity64 mask'

    ,'affinity I/O mask'

    ,'affinity64 I/O mask'

    ,'lightweight pooling'

    ,'priority boost'

    ,'max worker threads'

    ,'show advanced options'

    )

    )

    ,cteWarnings AS

    (

    SELECT

    ConfigurationName = 'maxworkerthreads'

    ,CurrentValue = 1

    ,Warning =

    'Max Work Threads setting my cause blocking and thread pool issues/errors.

    When all worker threads are active with long running queries, SQL Server may appear unresponsive until

    a worker thread completes and becomes available. Though not a defect, this can sometimes be undesirable.

    If a process appears to be unresponsive and no new queries can be processed, then connect to SQL Server

    using the dedicated administrator connection (DAC), and kill the process.

    ** Only use if requested by Microsoft Support **

    The default value for this option in sp_configure is 0.'

    UNION

    SELECT

    ConfigurationName = 'priorityboost'

    ,CurrentValue = 1

    ,Warning =

    '"Boost SQL Server priority" setting will drain OS and network functions and causes issues/errors.

    Raising the priority too high may drain resources from essential operating system and network functions,

    resulting in problems shutting down SQL Server or using other operating system tasks on the server.

    ** Only use if requested by Microsoft Support **

    The default value for this option in sp_configure is 0.'

    UNION

    SELECT

    ConfigurationName = 'lightweightpooling'

    ,CurrentValue = 1

    ,Warning =

    '"Use Windows fibers (lightweight pooling)". By setting lightweight pooling to 1 causes SQL Server to switch

    to fiber mode scheduling. Common language runtime (CLR) execution is not supported under lightweight pooling.

    Disable one of two options: "clr enabled" or "lightweight pooling". Features that rely upon CLR and that do

    not work properly in fiber mode include the hierarchy data type, replication, and Policy-Based Management.

    CLR, replication and extended stored procedures will fail and/or not work.

    ** Only use if requested by Microsoft Support **

    The default value for this option in sp_configure is 0.'

    UNION

    SELECT

    ConfigurationName = 'affinitymask'

    ,CurrentValue = 1

    ,Warning =

    'I/O and processor affinity changes will cause strange issues/errors and is not necessary on and 64 bit server.

    Do not configure CPU affinity in the Windows operating system and also configure the affinity mask in SQL Server.

    These settings are attempting to achieve the same result, and if the configurations are inconsistent, you may have

    unpredictable results. SQL Server CPU affinity is best configured using the sp_configure option in SQL Server.

    Using the GUI, under server properties select the "Automatically set processor affinity mask for all processors" and

    select the "Automatically set I/O affinity mask for all processors". This will correct the issues.

    ** Only use if requested by Microsoft Support **

    The default value for this option in sp_configure is 0.'

    )

    SELECT

    A.ConfigurationName

    ,A.[Description]

    ,CurrentValue = A.[value_in_use]

    ,Warning = CAST(ISNULL(B.Warning,'No warning necessary. The value for this configuration option is the default.') AS xml)

    FROM

    cteConfigValues A

    INNER JOIN

    cteWarnings B

    ON REPLACE(REPLACE(REPLACE(A.ConfigurationName,' ',''),'I/O',''),'64','') = B.ConfigurationName

    AND A.CurrentValue = B.CurrentValue

    ;