Category: Replication

Replication–Beware Reuse of View Names When Filtering Articles

I came across a very strange issue with replication this weekend.

As a part of a release a new table was being created with extra columns and a view was created with the old table name that referenced the old column set (so as not to break old legacy applications). This table was replicated. The dev team provided us with scripts to setup replication. During the attempt to perform the snapshot I ran into some problems and so dropped the publication.

All of a sudden users started to complain that they could no longer see the view and couldn’t query the data. I looked, and sure enough the view was not there. Very strange. I told the users that I’d get it created again once replication was done. I redid the publication and the users called me saying not to worry, the view was back.

What the heck?

After digging through I found the cause of the issue. The dev had created the replication scripts and included a filter to eliminate certain columns. This replication then gets wrapped into an article view. In this case the dev had manually named the @view_name in sp_articleview to be the same as the view in the database. This caused SQL to drop the existing view and create it’s own. When the publication was dropped so was the view.

 

Here are the steps to repro this behavior:

Firstly I’m creating a view against the local table SQLMonitor.dbo.SQLBuilds

CREATE VIEW Bananas

AS

    SELECT  Build ,

            [KB Article] ,

            URL ,

            Description ,

            MajorBuild ,

            MinorBuild

    FROM    SQLMonitor.dbo.SQLBuilds 

A quick select shows data:

image

 

Now let’s create a publication for replication with column filters against the SQLBuilds table. We’ll specify the @view_name to be Bananas. I’m also including an @filter_clause to eliminate rows (I’ll explain that in a bit).

-- Enabling the replication database

USE master

EXEC sp_replicationdboption @dbname = N'SQLMonitor', @optname = N'publish',

    @value = N'true'

GO

 

EXEC [SQLMonitor].sys.sp_addlogreader_agent @job_login = NULL,

    @job_password = NULL, @publisher_security_mode = 1

GO

EXEC [SQLMonitor].sys.sp_addqreader_agent @job_login = NULL,

    @job_password = NULL, @frompublisher = 1

GO

-- Adding the transactional publication

USE [SQLMonitor]

EXEC sp_addpublication @publication = N'Bananas Test',

    @description = N'Transactional publication of database ''SQLMonitor'' from Publisher ''local''.',

    @sync_method = N'concurrent', @retention = 0, @allow_push = N'true',

    @allow_pull = N'true', @allow_anonymous = N'false',

    @enabled_for_internet = N'false', @snapshot_in_defaultfolder = N'true',

    @compress_snapshot = N'false', @ftp_port = 21, @ftp_login = N'anonymous',

    @allow_subscription_copy = N'false', @add_to_active_directory = N'false',

    @repl_freq = N'continuous', @status = N'active',

    @independent_agent = N'true', @immediate_sync = N'false',

    @allow_sync_tran = N'false', @autogen_sync_procs = N'false',

    @allow_queued_tran = N'false', @allow_dts = N'false', @replicate_ddl = 1,

    @allow_initialize_from_backup = N'false', @enabled_for_p2p = N'false',

    @enabled_for_het_sub = N'false'

GO

 

 

EXEC sp_addpublication_snapshot @publication = N'Bananas Test',

    @frequency_type = 1, @frequency_interval = 0,

    @frequency_relative_interval = 0, @frequency_recurrence_factor = 0,

    @frequency_subday = 0, @frequency_subday_interval = 0,

    @active_start_time_of_day = 0, @active_end_time_of_day = 235959,

    @active_start_date = 0, @active_end_date = 0, @job_login = NULL,

    @job_password = NULL, @publisher_security_mode = 1

EXEC sp_grant_publication_access @publication = N'Bananas Test',

    @login = N'sa'

GO

EXEC sp_grant_publication_access @publication = N'Bananas Test',

    @login = N'NT AUTHORITYSYSTEM'

GO

EXEC sp_grant_publication_access @publication = N'Bananas Test',

    @login = N'NT SERVICESQLSERVERAGENT'

GO

EXEC sp_grant_publication_access @publication = N'Bananas Test',

    @login = N'NT SERVICEMSSQLSERVER'

GO

EXEC sp_grant_publication_access @publication = N'Bananas Test',

    @login = N'distributor_admin'

GO

 

-- Adding the transactional articles

USE [SQLMonitor]

EXEC sp_addarticle @publication = N'Bananas Test', @article = N'SQLBuilds',

    @source_owner = N'dbo', @source_object = N'SQLBuilds', @type = N'logbased',

    @description = N'', @creation_script = N'', @pre_creation_cmd = N'drop',

    @schema_option = 0x000000000803509F,

    @identityrangemanagementoption = N'none',

    @destination_table = N'SQLBuilds', @destination_owner = N'dbo',

    @status = 24, @vertical_partition = N'true',

    @ins_cmd = N'CALL [sp_MSins_dboSQLBuilds]',

    @del_cmd = N'CALL [sp_MSdel_dboSQLBuilds]',

    @upd_cmd = N'SCALL [sp_MSupd_dboSQLBuilds]'

 

-- Adding the article's partition column(s)

EXEC sp_articlecolumn @publication = N'Bananas Test', @article = N'SQLBuilds',

    @column = N'Build', @operation = N'add', @force_invalidate_snapshot = 1,

    @force_reinit_subscription = 1

EXEC sp_articlecolumn @publication = N'Bananas Test', @article = N'SQLBuilds',

    @column = N'KB Article', @operation = N'add',

    @force_invalidate_snapshot = 1, @force_reinit_subscription = 1

EXEC sp_articlecolumn @publication = N'Bananas Test', @article = N'SQLBuilds',

    @column = N'MajorBuild', @operation = N'add',

    @force_invalidate_snapshot = 1, @force_reinit_subscription = 1

EXEC sp_articlecolumn @publication = N'Bananas Test', @article = N'SQLBuilds',

    @column = N'MinorBuild', @operation = N'add',

    @force_invalidate_snapshot = 1, @force_reinit_subscription = 1

 

-- Adding the article synchronization object

EXEC sp_articleview @publication = N'Bananas Test', @article = N'SQLBuilds',

    @view_name = N'Bananas', @filter_clause = N'[KB Article] >0',

    @force_invalidate_snapshot = 1, @force_reinit_subscription = 1

GO

 

This does it’s job, creates the publication with the article and everything. Now let’s query the view again…

image

 

Several columns are now missing and the view matches what’s specified in the replication script. The old view has been dropped and a new system view has been created:

image

 

 

Now dropping the publication also drops the view

-- Dropping the transactional articles

USE [SQLMonitor]

EXEC sp_dropsubscription @publication = N'Bananas Test',

    @article = N'SQLBuilds', @subscriber = N'all', @destination_db = N'all'

GO

USE [SQLMonitor]

EXEC sp_droparticle @publication = N'Bananas Test', @article = N'SQLBuilds',

    @force_invalidate_snapshot = 1

GO

 

-- Dropping the transactional publication

USE [SQLMonitor]

EXEC sp_droppublication @publication = N'Bananas Test'

GO

 

image

 

This appears to be a bug and not the behavior I would expect.

If I recreate the view and then attempt to create the publication again, this time without the @filter_clause I get an error stating the view already exists:

USE [SQLMonitor]

EXEC sp_addpublication @publication = N'Bananas Test',

    @description = N'Transactional publication of database ''SQLMonitor'' from Publisher ''local''.',

    @sync_method = N'concurrent', @retention = 0, @allow_push = N'true',

    @allow_pull = N'true', @allow_anonymous = N'false',

    @enabled_for_internet = N'false', @snapshot_in_defaultfolder = N'true',

    @compress_snapshot = N'false', @ftp_port = 21, @ftp_login = N'anonymous',

    @allow_subscription_copy = N'false', @add_to_active_directory = N'false',

    @repl_freq = N'continuous', @status = N'active',

    @independent_agent = N'true', @immediate_sync = N'false',

    @allow_sync_tran = N'false', @autogen_sync_procs = N'false',

    @allow_queued_tran = N'false', @allow_dts = N'false', @replicate_ddl = 1,

    @allow_initialize_from_backup = N'false', @enabled_for_p2p = N'false',

    @enabled_for_het_sub = N'false'

GO

 

 

EXEC sp_addpublication_snapshot @publication = N'Bananas Test',

    @frequency_type = 1, @frequency_interval = 0,

    @frequency_relative_interval = 0, @frequency_recurrence_factor = 0,

    @frequency_subday = 0, @frequency_subday_interval = 0,

    @active_start_time_of_day = 0, @active_end_time_of_day = 235959,

    @active_start_date = 0, @active_end_date = 0, @job_login = NULL,

    @job_password = NULL, @publisher_security_mode = 1

EXEC sp_grant_publication_access @publication = N'Bananas Test',

    @login = N'sa'

GO

EXEC sp_grant_publication_access @publication = N'Bananas Test',

    @login = N'NT AUTHORITYSYSTEM'

GO

EXEC sp_grant_publication_access @publication = N'Bananas Test',

    @login = N'NT SERVICESQLSERVERAGENT'

GO

EXEC sp_grant_publication_access @publication = N'Bananas Test',

    @login = N'NT SERVICEMSSQLSERVER'

GO

EXEC sp_grant_publication_access @publication = N'Bananas Test',

    @login = N'distributor_admin'

GO

 

-- Adding the transactional articles

USE [SQLMonitor]

EXEC sp_addarticle @publication = N'Bananas Test', @article = N'SQLBuilds',

    @source_owner = N'dbo', @source_object = N'SQLBuilds', @type = N'logbased',

    @description = N'', @creation_script = N'', @pre_creation_cmd = N'drop',

    @schema_option = 0x000000000803509F,

    @identityrangemanagementoption = N'none',

    @destination_table = N'SQLBuilds', @destination_owner = N'dbo',

    @status = 24, @vertical_partition = N'true',

    @ins_cmd = N'CALL [sp_MSins_dboSQLBuilds]',

    @del_cmd = N'CALL [sp_MSdel_dboSQLBuilds]',

    @upd_cmd = N'SCALL [sp_MSupd_dboSQLBuilds]'

 

-- Adding the article's partition column(s)

EXEC sp_articlecolumn @publication = N'Bananas Test', @article = N'SQLBuilds',

    @column = N'Build', @operation = N'add', @force_invalidate_snapshot = 1,

    @force_reinit_subscription = 1

EXEC sp_articlecolumn @publication = N'Bananas Test', @article = N'SQLBuilds',

    @column = N'KB Article', @operation = N'add',

    @force_invalidate_snapshot = 1, @force_reinit_subscription = 1

EXEC sp_articlecolumn @publication = N'Bananas Test', @article = N'SQLBuilds',

    @column = N'MajorBuild', @operation = N'add',

    @force_invalidate_snapshot = 1, @force_reinit_subscription = 1

EXEC sp_articlecolumn @publication = N'Bananas Test', @article = N'SQLBuilds',

    @column = N'MinorBuild', @operation = N'add',

    @force_invalidate_snapshot = 1, @force_reinit_subscription = 1

 

-- Adding the article synchronization object

EXEC sp_articleview @publication = N'Bananas Test', @article = N'SQLBuilds',

    @view_name = N'Bananas', @filter_clause = N'',

    @force_invalidate_snapshot = 1, @force_reinit_subscription = 1

GO

 

(1 row(s) affected)
(1 row(s) affected)
(1 row(s) affected)
Msg 2714, Level 16, State 3: There is already an object named ‘Bananas’ in the database.
Msg 21745, Level 16, State 1, Procedure sp_MSrepl_articleview, Line 272
Cannot generate a filter view or procedure. Verify that the value specified for the @filter_clause parameter of sp_addarticle can be added to the WHERE clause of a SELECT statement to produce a valid query.
Msg 3931, Level 16, State 1, Procedure sp_MSrepl_articleview, Line 401
The current transaction cannot be committed and cannot be rolled back to a savepoint. Roll back the entire transaction.

 

Something to be aware of if you are going to be playing with replication.

I’ve opened a Connect bug with Microsoft to try and get this fixed. Please go vote on it. And be careful with your replication.

Mass Updating Job Step Retry Attempts

Sometimes I find that the SQL Server team make curious choices as regards default operations. When setting up replication by default the log reader and distribution agent job steps will retry 2,147,483,647 times before failing. Doing the math on the retry interval of 1 minute that means that the job wouldn’t actually hit a failed status for over 4000 years. While you can setup alerts around replication a lot of folks don’t do that and you could easily be in a situation where replication has been down for so long that you have to reinitialize the subscription and perform a snapshot to get things running again.

Having a great many distribution jobs running on my server I wanted to perform a mass update. It could have gone through and updated each job step but that would have taken me a couple of days. I needed a better way. Digging through the SQL Server Agent stored procedures I found that sp_update_jobstep would do the work for me. I just needed to pass in the relevant parameters and then restart the jobs so that the change took effect.

As such I ended up writing the following script. Just adjust the @retries variable to the value that you want to work with (in this instance it would be an hours worth of retries before the job failed). This script is limited to the Distribution job step but could be easily modified to manage the log reader also.

Running this script took two minutes and it updated 60 distribution agent jobs. I’m getting ready to kick it off on the rest of my servers.

SET NOCOUNT ON

      

DECLARE @retries INT = 60 --Set to the value that you want for retry attempts

 

DECLARE @JobIdUpd UNIQUEIDENTIFIER ,

    @JobStepUpd INT,

    @JobStatus INT,

    @JobName SYSNAME,

    @Message NVARCHAR(256)

 

 

--Create a temp table which will hold the results from xp_sqlagent_enum_jobs

--Note xp_sqlagent_enum_jobs is an undocumented stored procedure, it may not be there soon

CREATE TABLE #enumjobs

    (

      job_id UNIQUEIDENTIFIER NOT NULL ,

      last_run_date INT NOT NULL ,

      last_run_time INT NOT NULL ,

      next_run_date INT NOT NULL ,

      next_run_time INT NOT NULL ,

      next_run_schedule_id INT NOT NULL ,

      requested_to_run INT NOT NULL ,

      request_source INT NOT NULL ,

      request_source_id SYSNAME NULL ,

      running INT NOT NULL , 

      current_step INT NOT NULL ,

      current_retry_attempt INT NOT NULL ,

      job_state INT NOT NULL

    ) 

 

 

   

DECLARE UpdateJobsCrsr CURSOR

FOR

SELECT  sjs.job_id ,

        sjs.step_id ,

        sj.name

FROM    msdb.dbo.sysjobsteps sjs

        INNER JOIN msdb.dbo.sysjobs sj ON sjs.job_id = sj.job_id

WHERE   subsystem = 'Distribution'

        AND retry_attempts > 60

 

OPEN UpdateJobsCrsr ;

 

FETCH NEXT FROM UpdateJobsCrsr

INTO @JobIdUpd, @JobStepUpd,@JobName

WHILE ( @@FETCH_STATUS <> -1 ) 

    BEGIN

   

--Update the job step so that the number of retry attempts is set to the @retries variable                

EXEC msdb.dbo.sp_update_jobstep @job_id = @jobidUpd, @step_id = @jobstepUpd, @retry_attempts = @retries  

SELECT @Message = N'Job ' + @JobName + ' updated.'

RAISERROR (@Message, 0, 1) WITH nowait 

 

--We have to restart the job in order for this change to take effect

--Check to see if the job is running, if so stop and restart it, otherwise leave it alone

--Note, you'll need to be a sysadmin for this to work (or change up some stuff)

    TRUNCATE TABLE #enumjobs;

    INSERT INTO #enumjobs

                EXEC master.dbo.xp_sqlagent_enum_jobs 1, 'sa', @JobIdUpd;

                

SELECT @JobStatus = job_state FROM #enumjobs

 

IF @JobStatus <> 4 --This is the job idle state

    BEGIN

--Stop the job

        EXEC msdb.dbo.sp_stop_job @job_id = @JobIdUpd

--Wait a couple of seconds for the job to stop

        WAITFOR DELAY '00:00:03'        

--Start the job up again

        EXEC msdb.dbo.sp_start_job @job_id = @JobIdUpd    

    END

ELSE 

    BEGIN

        SELECT @Message = N'Job ' + @JobName + ' was not running, please start manually if required.'              

        RAISERROR (@Message, 0, 1) WITH NOWAIT

    END

                

        FETCH NEXT FROM UpdateJobsCrsr

            INTO @JobIdUpd, @JobStepUpd, @JobName

    END

 

 

CLOSE UpdateJobsCrsr ;

GO

DEALLOCATE UpdateJobsCrsr ;

GO

 

--Cleanup

DROP TABLE #enumjobs   

Reinitializing Replication For A Single Subscriber

Interesting thing happened today, but never mind that. We had a server go down recently in our staging environment, wasn’t any big deal, we had to have vendor support come out and replace the motherboard. It was stage, not a big deal. The thing was, the server was down for a couple of days. Actually it was down for a total of 4 days.

 

The server in question is a SQL 2008 subscriber to several published tables on the staging OLTP SQL 2008 Instance (using push subscriptions). Sadly, not thinking of this ahead of time, we neglected to adjust the maximum distribution retention period for transactional replication (which sits at 72 hours). Suffice to say, the server came back online, we restarted the distribution agents we got the dreaded “subscription marked as inactive” error requiring us to have to reinitialize all of the subscriptions to that server.

 

“There goes my afternoon” thought I. Not being a fan of the replication monitor in 2008 I dreaded having to work with it to go through and reinitialize each and every publication for that subscriber, especially given that there are around 80 different articles. There must be a better way I thought…and lo, there is!

 

Books online talks about sp_reinitsubscription and passing parameters for the publication, article, subscriber, destination database, for schema change, publisher, ignore distributor failover and invalidate snapshot.

 

What BOL is not clear about it that you can pass in just a subscriber, that’s it, nothing else.

 

exec sp_reinitsubscription @subscriber = ‘<sql instance>’;

 

Running this reinitialized all of the publications within the current database for that one subscriber. Very quick, very easy. From there I just had to kickstart the snapshot agents and we were back in business (sp_start_job in this case ftw).

T-SQL Tuesday #10 – Applying Indexes To Replicated Tables

It’s T-SQL Tuesday time again! This month Michael J. Swart (blog|twitter) is hosting and has given us the topic of indexes.

I’ve previously written about how you can find indexes that are not being used and get their sizes. Not being allowed to reuse that meant that I had to come up with something else.

 In my previous post on calculating replication schema options I documented a way of being able to change article options in transactional replication so that you could apply all the non-clustered indexes on your subscribing table that exist on the publishing one. But what if you are using replication to offload reporting and you need to create indexes that don’t exist on the publishing table?

You could always manually apply these indexes any time that you perform a snapshot but this requires manual work and can easily be forgotten.

Fortunately there is another option, you can have replication automatically apply a post-snapshot SQL script which will create those indexes for you. Here’s how…

 

Create a basic publication (snapshot or transactional) and add a table article. Perform the snapshot and compare indexes between the tables (in this example I am using the person.address table from AdventureWorks2008).

After the snapshot here’s how the indexes stand

 

For this example we’re going to create a new index on Admindb.person.address. To do this first we need to generate the index creation script

 

USE AdminDB

GO

IF NOT EXISTS (SELECT * FROM sys.indexes WHERE object_id = OBJECT_ID(N‘[person].[address]’) AND name = N’NCIX_Zip’)
CREATE NONCLUSTERED INDEX [NCIX_Zip] ON [person].[address]
(
    [PostalCode] ASC
)
WITH (ONLINE = ON, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON) ON [PRIMARY]
GO

 

Save this script to C:ReplicationScriptsCreateReportingIndex.sql

Now we change the existing publication so that whenever a snapshot is taken it will apply this script when applied to the subscriber. This change can be done in a couple of ways.

The quick and easy way is to use sp_changepublication and just pass in the publication name, property change and location of the script.

 

USE AdventureWorks2008
GO

EXEC sp_changepublication    
@publication = ‘Post Snapshot Test’ 
, @property = N’post_snapshot_script’  ,
@value = ‘C:ReplicationScriptsCreateReportingIndex.sql’
  , @force_invalidate_snapshot = 1 –must invalidate existing snapshots for this to take effect
GO

 

This can also be done using the GUI (right click on the publication and select Properties)

 

 

When you next perform a snapshot then the script will be applied. We can check that this actually worked first by looking at replication monitor where it will tell you that the script was applied.

 

And then you can check the table itself and confirm that the index exists

 

There are a couple of final things to note.

Usually you will specify a unc path for the SQL script so that you just have to maintain a single copy. You just need to ensure that the subscriber is able to access the post-snapshot script location.

Post-snapshots are not limited to creating indexes, in fact you can do pretty much anything just so long as the Distribution Agent has the access;

  • Send yourself an email to let you know that the snapshot has been applied on the subscriber
  • Apply table permissions
  • Create views

If you use replication and find yourself manually reapplying indexes it’s worth evaluating whether using post-snapshot scripts might save you some work.

Calculating Replication Schema Options

I recently evaluated using page compression on some of my production data (see my post on estimating data compression). I’m using transactional replication to send this data out to a few other servers for reporting pusposes and I wanted to adjust replication so that the data compression settings on the tables would also be replicated.

Making life a little easier on this was an application change that was going to require me dropping and recreating replication so I figured it would be a simple case to change the replication options when recreating the publications.

Using the GUI I scripted out all of the existing publications and then dropped them.

Now I wanted to adjust the script so that the schema options I wanted replicated were applied. Here’s the sp_addarticle for one of these tables (SQL 2008)

 — Adding the transactional articles

 use [TestDB]

exec sp_addarticle
    @publication = N’TestDB_TestTable’
    , @article = N’TestTable’
    , @source_owner = N’dbo’
    , @source_object = N’TestTable’
    , @type = N’logbased’
    , @description = N”
    , @creation_script = N”
    , @pre_creation_cmd = N’drop’
    , @schema_option = 0x000000000803509F
    , @identityrangemanagementoption = N’none’
    , @destination_table = N’TestTable’
    , @destination_owner = N’dbo’
    , @status = 24
    , @vertical_partition = N’false’
    , @ins_cmd = N’CALL [dbo].[sp_MSins_dboTestTable]’
    , @del_cmd = N’CALL [dbo].[sp_MSdel_dboTestTable]’
    , @upd_cmd = N’SCALL [dbo].[sp_MSupd_dboTestTable]’
GO

 

Now this doesn’t tell you a lot about what schema options are in place. The binary value @schema_option has all the information you need however it’s not exactly user friendly. Books Online has the information available to be able to figure this out, it just takes a little calculation. Somewhat of a pain I’ve created a script to tell me what options are enabled.

All you need to do is pass in the @schema_option value and it will tell you what options are enabled (in this case  0x000000000803509F)

 

/* PROVIDES THE REPLICATION OPTIONS ENABLED FOR A GIVEN @SCHEMA_OPTION IN SYSARTICLES */

declare @schema_option varbinary(8) = 0x000000000803509F  –< PUT YOUR SCHEMA_OPTION HERE

set nocount on
declare @OptionTable table ( HexValue varbinary(8), IntValue as cast(HexValue as bigint), OptionDescription varchar(255))
insert into @OptionTable (HexValue, OptionDescription)
select 0x01 ,‘Generates object creation script’
union all  select 0x02 ,‘Generates procs that propogate changes for the article’
union all  select 0x04 ,‘Identity columns are scripted using the IDENTITY property’
union all  select 0x08 ,‘Replicate timestamp columns (if not set timestamps are replicated as binary)’
union all  select 0x10 ,‘Generates corresponding clustered index’
union all  select 0x20 ,‘Converts UDT to base data types’
union all  select 0x40 ,‘Create corresponding nonclustered indexes’
union all  select 0x80 ,‘Replicate pk constraints’
union all  select 0x100 ,‘Replicates user triggers’
union all  select 0x200 ,‘Replicates foreign key constraints’
union all  select 0x400 ,‘Replicates check constraints’
union all  select 0x800  ,‘Replicates defaults’
union all  select 0x1000 ,‘Replicates column-level collation’
union all  select 0x2000 ,‘Replicates extended properties’
union all  select 0x4000 ,‘Replicates UNIQUE constraints’
union all  select 0x8000 ,‘Not valid’
union all  select 0x10000 ,‘Replicates CHECK constraints as NOT FOR REPLICATION so are not enforced during sync’
union all  select 0x20000 ,‘Replicates FOREIGN KEY constraints as NOT FOR REPLICATION so are not enforced during sync’
union all  select 0x40000 ,‘Replicates filegroups’
union all  select 0x80000 ,‘Replicates partition scheme for partitioned table’
union all  select 0x100000 ,‘Replicates partition scheme for partitioned index’
union all  select 0x200000 ,‘Replicates table statistics’
union all  select 0x400000 ,‘Default bindings’
union all  select 0x800000 ,‘Rule bindings’
union all  select 0x1000000 ,‘Full text index’
union all  select 0x2000000 ,‘XML schema collections bound to xml columns not replicated’
union all  select 0x4000000 ,‘Replicates indexes on xml columns’
union all  select 0x8000000 ,‘Creates schemas not present on subscriber’
union all  select 0x10000000 ,‘Converts xml columns to ntext’
union all  select 0x20000000 ,‘Converts (max) data types to text/image’
union all  select 0x40000000 ,‘Replicates permissions’
union all  select 0x80000000 ,‘Drop dependencies to objects not part of publication’
union all  select 0x100000000 ,‘Replicate FILESTREAM attribute (2008 only)’
union all  select 0x200000000 ,‘Converts date & time data types to earlier versions’
union all  select 0x400000000 ,‘Replicates compression option for data & indexes’
union all  select 0x800000000  ,‘Store FILESTREAM data on its own filegroup at subscriber’
union all  select 0x1000000000 ,‘Converts CLR UDTs larger than 8000 bytes to varbinary(max)’
union all  select 0x2000000000 ,‘Converts hierarchyid to varbinary(max)’
union all  select 0x4000000000 ,‘Replicates filtered indexes’
union all  select 0x8000000000 ,‘Converts geography, geometry to varbinary(max)’
union all  select 0x10000000000 ,‘Replicates geography, geometry indexes’
union all  select 0x20000000000 ,‘Replicates SPARSE attribute ‘
                  
select HexValue,OptionDescription as ‘Schema Options Enabled’
From @OptionTable where (cast(@schema_option as bigint) & cast(HexValue as bigint)) <> 0

 

This is really great and useful. In fact you can use this script to check out the schema options for any article, just plug in the schem_option value from sysarticles to get the data.

Now to take it a step further I wanted to know what the new value would need to be for @schema_option in order to replicate the data compression settings. For this I wrote another query. This time it’s just a case of uncommenting the lines for the schema options that I want and running the select.

select cast(

  cast(0x01 AS BIGINT) –DEFAULT Generates object creation script
| cast(0x02 AS BIGINT) –DEFAULT Generates procs that propogate changes for the article
| cast(0x04 AS BIGINT) –Identity columns are scripted using the IDENTITY property
| cast(0x08 AS BIGINT) –DEFAULT Replicate timestamp columns (if not set timestamps are replicated as binary)
| cast(0x10 AS BIGINT) –DEFAULT Generates corresponding clustered index
–| cast(0x20 AS BIGINT) –Converts UDT to base data types
–| cast(0x40 AS BIGINT) –Create corresponding nonclustered indexes
| cast(0x80 AS BIGINT) –DEFAULT Replicate pk constraints
–| cast(0x100 AS BIGINT) –Replicates user triggers
–| cast(0x200 AS BIGINT) –Replicates foreign key constraints
–| cast(0x400 AS BIGINT) –Replicates check constraints
–| cast(0x800 AS BIGINT)  –Replicates defaults
| cast(0x1000 AS BIGINT) –DEFAULT Replicates column-level collation
–| cast(0x2000 AS BIGINT) –Replicates extended properties
| cast(0x4000 AS BIGINT) –DEFAULT Replicates UNIQUE constraints
–| cast(0x8000 AS BIGINT) –Not valid
| cast(0x10000 AS BIGINT) –DEFAULT Replicates CHECK constraints as NOT FOR REPLICATION so are not enforced during sync
| cast(0x20000 AS BIGINT) –DEFAULT Replicates FOREIGN KEY constraints as NOT FOR REPLICATION so are not enforced during sync
–| cast(0x40000 AS BIGINT) –Replicates filegroups (filegroups must already exist on subscriber)
–| cast(0x80000 AS BIGINT) –Replicates partition scheme for partitioned table
–| cast(0x100000 AS BIGINT) –Replicates partition scheme for partitioned index
–| cast(0x200000 AS BIGINT) –Replicates table statistics
–| cast(0x400000 AS BIGINT) –Default bindings
–| cast(0x800000 AS BIGINT) –Rule bindings
–| cast(0x1000000 AS BIGINT) –Full text index
–| cast(0x2000000 AS BIGINT) –XML schema collections bound to xml columns not replicated
–| cast(0x4000000 AS BIGINT) –Replicates indexes on xml columns
| cast(0x8000000 AS BIGINT) –DEFAULT Creates schemas not present on subscriber
–| cast(0x10000000 AS BIGINT) –Converts xml columns to ntext
–| cast(0x20000000 AS BIGINT) –Converts (max) data types to text/image
–| cast(0x40000000 AS BIGINT) –Replicates permissions
–| cast(0x80000000 AS BIGINT) –Drop dependencies to objects not part of publication
–| cast(0x100000000 AS BIGINT) –Replicate FILESTREAM attribute (2008 only)
–| cast(0x200000000 AS BIGINT) –Converts date & time data types to earlier versions
| cast(0x400000000 AS BIGINT) –Replicates compression option for data & indexes
–| cast(0x800000000 AS BIGINT)  –Store FILESTREAM data on its own filegroup at subscriber
–| cast(0x1000000000 AS BIGINT) –Converts CLR UDTs larger than 8000 bytes to varbinary(max)
–| cast(0x2000000000 AS BIGINT) –Converts hierarchyid to varbinary(max)
–| cast(0x4000000000 AS BIGINT) –Replicates filtered indexes
–| cast(0x8000000000 AS BIGINT) –Converts geography, geometry to varbinary(max)
–| cast(0x10000000000 AS BIGINT) –Replicates geography, geometry indexes
–| cast(0x20000000000 AS BIGINT) –Replicates SPARSE attribute
AS BINARY(8)) as Schema_Option

 

Plugging in that new value and executing the sp_addarticle script created the new article with all the old settings and now included replicating compression options.

Download the script Replication Schema Options.sql give them a try yourself and let me know if they help.