Policy-Based Management is a feature that is introduced with SQL Server 2008. It allows us to set the rules we want in our systems, to set our standards and to make our controls automatically. For example, we can create a policy for control purposes so that the names of our stored procedures do not start with a number or database recovery models are not simple.
Before reading this article, I recommend that you read the article “Vlf(Virtual Log File) Count” to understand the answer to the question of what means the VLF Count and what should not be.
To comprehend Policy Based Management (PBM), you need to understand some concepts.
Facet
A feature that can be managed by PBM. For example, there is a facet called Database. And you can use this facet to create a policy that checks the vlf count in the log file in the database.
You can access all facets via SSMS as follows. To access the facet details, you must double-click on it.
Condition
Checks whether the sub-property of the related facets provide the specified condition.
Let’s create a policy to check the vlf count in the database.
Right click Policies tab as follows from the Management> Policy tab and click New Policy.
We give a name to Policy on the screen that appears. We need to create a condition from Check Condition.
We’re clicking on New Condition.
We give a name to the condition from the screen that appears.
From the Facet section, we select the Database facet because we will check the vlf count of the log file in the database.
Click on “…” in the Expression section to paste the following script into the Cell Value section.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 | ExecuteSql('Numeric', '--variables to hold each ''iteration'' declare @query varchar(100) declare @dbname sysname declare @vlfs int --table variable used to ''loop'' over databases declare @databases table (dbname sysname) insert into @databases --only choose online databases select name from sys.databases where state = 0 --table variable to hold results declare @vlfcounts table (dbname sysname, vlfcount int) --table variable to capture DBCC loginfo output --changes in the output of DBCC loginfo from SQL2012 mean we have to determine the version declare @MajorVersion tinyint set @MajorVersion = LEFT(CAST(SERVERPROPERTY(''ProductVersion'') AS nvarchar(max)),CHARINDEX(''.'',CAST(SERVERPROPERTY(''ProductVersion'') AS nvarchar(max)))-1) if @MajorVersion < 11 -- pre-SQL2012 begin declare @dbccloginfo table ( fileid smallint, file_size bigint, start_offset bigint, fseqno int, [status] tinyint, parity tinyint, create_lsn numeric(25,0) ) while exists(select top 1 dbname from @databases) begin set @dbname = (select top 1 dbname from @databases) set @query = ''dbcc loginfo ('' + '''''''' + @dbname + '''''') '' insert into @dbccloginfo exec (@query) set @vlfs = @@rowcount insert @vlfcounts values(@dbname, @vlfs) delete from @databases where dbname = @dbname end --while end else begin declare @dbccloginfo2012 table ( RecoveryUnitId int, fileid smallint, file_size bigint, start_offset bigint, fseqno int, [status] tinyint, parity tinyint, create_lsn numeric(25,0) ) while exists(select top 1 dbname from @databases) begin set @dbname = (select top 1 dbname from @databases) set @query = ''dbcc loginfo ('' + '''''''' + @dbname + '''''') '' insert into @dbccloginfo2012 exec (@query) set @vlfs = @@rowcount insert @vlfcounts values(@dbname, @vlfs) delete from @databases where dbname = @dbname end --while end --output the full list select vlfcount from @vlfcounts order by dbname ') |
And since we want the vlf number to be less than 1000, we set it to “<1000”. The number 1000 is not an appropriate value for every database. Therefore, you should read the article I mentioned at the beginning of the article.
By selecting On Schedule from the Evaluation Mode, we select the interval at which the policy will be checked and then click the Enable check box.
If we choose On Demand, it only checks when we execute policy.
If you have a server-based condition, you can create a server-based condition from the server restriction section.
If you want it to be checked automatically at certain intervals, click New in the Schedule section and determine the frequency that the policy will check the condition. We set it up to work once every day at 12: 00: 000 PM.
We created our policy. We click Evaluate as below to run it manually.
Since we use script instead of Facet property, we received a warning like the following. Policy says it contains scripts and we should only run it from a trusted source.
The policy: ‘VLFCount’ contains scripts. You should only run policies from a trustworthy source.
We press the Evaluate button at the bottom right to run the policy despite the warning.
When I perform this operation in my local, I get a result like the following. As you can see, none of the databases have more than 1000 vlfs. You can find out the current vlf count by clicking View.
With Policy Based Management, you can check many things on SQL Server. And I think a professional database manager should use this feature that SQL Server offers us. You can find more articles on Policy Based Management at the following links.
“How To Check the Compatibility Level of Databases Using Policy Based Management“,
“How To Check Recovery Model of All Databases Using Policy Based Management“,
“How To Check Stored Procedure Names Using Policy Based Management“,
“How To Check SQL Logins That Password Policy Enforced or Password Expiration Enabled Using Policy Based Management”,
“How To Check Disabled Audits Using Policy Based Management”,
“How To Check Auto Shrink Option of Databases Using Policy Based Management”,
“How To Check Whether Availability Groups is Ready To Failover Using Policy Based Management”,
“How To Check Availability Group’s Backup Preference Using Policy Based Management”,
“How To Check Availability Group Automatic Failover Settings Using Policy Based Management”,
“How To Check Whether Readable Secondary is Enabled on Availability Groups Using Policy Based Management”,
“How To Check Whether Data File Sizes is Reached a Specific Size Using Policy Based Management”,
“How To Check Auto Close Option of Databases Using Policy Based Management”,
“How To Check Last Log Backup Time Using Policy Based Management”,
“How To Check Page Verify Option of Databases Using Policy Based Management”