storage

Replication without Snapshot Initialisation

Recently I had a requirement for a customer that was not really “by the book”.
The requirement was to replicate a table, but only replicate anything new coming in, no historical data. The table has close to 7 Billion rows and is several Terabytes big.
Replicating all the historical data would kill the target server which just hasn’t the capacity. The target server will only keep a rolling 30 days of data and discard everything older.
That said, I had to find a way replicating all new transactions without the need of a Snapshot or Backup initialisation. This is not as straight forward as it sounds, but then again also not really too complicated, once you know how.
After some trial-and-error on a test lab installation I got it going. Here is an account of how-to:

Create the schema on the target server

To use replication without snapshot initialisation you will have to need all the data structures set up before you start. Create the target table on the target server. Don’t forget to plan how to handle identity columns. (If you need some data in there, also transfer and – if need be – modify the data to your needs.)

Create publication on source server

What I like to do is to use the wizard to create my Publications but not actually create the publication, just create the scripts. Then check and modify them before actually creating the publication. (And the same for subscriptions)

exec sp_addpublication 
         @publication = N'ReplWoSnapshot'
        ,@description = N'Transactional publication of database ''Source'' from Publisher ''SourceServer''.'
        ,@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
        ,@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'
        ,@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'
        ,@allow_partition_switch = N'true'
        ,@replicate_partition_switch = N'false'

Important here is that Immediate Synchronosation is off. Also switch of Initialisation from Backup.
Note: The last two parameters are needed in this case since it is a partitioned table I am replicating and I want to still be able to switch partitions on the source database without generating errors. But I don’t need the partition switch to be replicated. The target database will have its own split-switch-merge logic.

exec sp_addpublication_snapshot 
         @publication = N'ReplWoSnapshot'
        ,@frequency_type = 1
        ,@frequency_interval = 1
        ,@frequency_relative_interval = 1
        ,@frequency_recurrence_factor = 0
        ,@frequency_subday = 8
        ,@frequency_subday_interval = 1
        ,@active_start_time_of_day = 0
        ,@active_end_time_of_day = 235959
        ,@active_start_date = 0
        ,@active_end_date = 0
        ,@job_login = N'login'
        ,@job_password = 'pwd'
        ,@publisher_security_mode = 1

The snapshot agent is still created as usual even though it won’t be used.

exec sp_addarticle 
          @publication = N'ReplWoSnapshot'
        , @article = N'Source Table'
        , @source_owner = N'dbo'
        , @source_object = N'Source Table'
        , @type = N'logbased'
        , @description = null
        , @creation_script = null
        , @pre_creation_cmd = N'drop'
        , @schema_option = 0x00000000081B509F
        , @identityrangemanagementoption = N'manual'
        , @destination_table = N'Source Table'
        , @destination_owner = N'dbo'
        , @vertical_partition = N'false'
        , @ins_cmd = N'CALL sp_MSins_dboSourceTable'
        , @del_cmd = N'CALL sp_MSdel_dboSourceTable'
        , @upd_cmd = N'SCALL sp_MSupd_dboSourceTable'

Also all the articles are added as usual.

Create subscription

Again, I used the wizard to create the subscription, but only let it generate the scripts. In my case I created a Pull subscription, but it should also work with a Push subscription.

First add it on the distributor (= soruce server in this case)

exec sp_addsubscription 
         @publication = N'ReplWoSnapshot'
        ,@subscriber = N'Target Server'
        ,@destination_db = N'Source Dtaabase'
        ,@sync_type = N'replication support only'
        ,@subscription_type = N'pull'
        ,@update_mode = N'read only'

Here lies the most important part of the process: the Synchronisation Type. You need to use Replication Support Only. This ensures that no initialisation is attempted, just anything coming in will be replicated without questions.

Now add the subscription on the target server.

exec sp_addpullsubscription 
		 @publisher = N'Source Server'
		,@publication = N'ReplWoSnapshot'
		,@publisher_db = N'Source DB'
		,@independent_agent = N'True'
		,@subscription_type = N'pull'
		,@description = N''
		,@update_mode = N'read only'
		,@immediate_sync = 0

Again, Immediate Synchronisation must be switched off.

exec sp_addpullsubscription_agent 
		 @publisher = N'source server'
		,@publisher_db = N'Source DB'
		,@publication = N'ReplWoSnapshot'
		,@distributor = N'Source Server'
		,@distributor_security_mode = 1
		,@distributor_login = N''
		,@distributor_password = null
		,@enabled_for_syncmgr = N'False'
		,@frequency_type = 64
		,@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 = 20130111
		,@active_end_date = 99991231
		,@alt_snapshot_folder = N''
		,@working_directory = N''
		,@use_ftp = N'False'
		,@job_login = N'login'
		,@job_password = 'pwd'
		,@publication_type = 0

The subscription agent is then added as usual.

With these few steps the replication is fully configured and running. New transactions from the creation of the Publication on are replicated to the subscriber without any need of initialisation, be it from Snapshot or from Backup.

But there is one more thing you should do!
You need to be aware that a lot of data is actually missing in the target database. So every Update and Delete on a record in the source database that is not available in the target database will cause an error in the replication and acutally stop the replication.
Even when you are sure only Inserts happen on the source server, you should take precautions for transactions being executed for data that is not available on the target system.

Skip Consistency Errors in Replication

In order to avoid these errors (or actually tell the replication to ignore them) you need to use Agent Profiles.
Please find a step-by-step guide here on
How to: Work with Replication Agent Profiles (SQL Server Management Studio)
For this particular distribution we need to use an Agent Profile called Continue On Data Consistency Errors.
To use this profile:

  • Open the Replication Monitor
  • Right-Click on the distribution and choose Agent Profiles
  • Tick the box next to Continue On Data Consistency Errors
  • Click the button Change Existing Agents (if you just click OK, only newly created Agents will use this profile).
  • Caveat 1:

    Please be aware that Replication without Initialisation might not be the best solution for your requirements (or even this requirement described here). In fact Service Broker might provide a more suitable solution or some ETL process or something hand-made.
    Please always look into all kinds of solution and don’t just take the first that offers itself (we do that often enough anyway). It might not be the best one.

    Caveat 2:

    The description given here is no full step-by-step guide. It pre-requisits some knowledge of SQL Server replication. Some obvious steps are omitted, others vaguely described.
    Please always refer to the SQL Server documentation for full description of all parameters and steps.

    Get number of rows per partition

    How can you get the number of rows in each partition of your partitioned tables?
    Here is a simple query to retrieve that data, including the boundary value for each partition:

    SELECT	    
         p.partition_id                             as PartitionID
        ,t.name                                     as [Table]
        ,ps.name                                    as PartitionScheme
        ,pf.name                                    as PartitionFunction
        ,p.partition_number                         as [Partition]
        ,p.rows                                     as [Rows]
        ,prv.value                                  as Boundary
        --,pf.type_desc                               as BoundaryType
        ,case when pf.boundary_value_on_right = 1 
            then 'Right'
            else 'Left'
            end                                     as BoundarySide
    
    FROM	
        sys.tables t
        inner join sys.partitions p 
            on t.object_id = p.object_id 
            and p.index_id = 1
        inner join sys.indexes i on p.object_id = i.object_id and p.index_id = i.index_id
        inner join sys.data_spaces ds on i.data_space_id = ds.data_space_id
        inner join sys.partition_schemes ps on ds.data_space_id = ps.data_space_id
        inner join sys.partition_functions pf on ps.function_id = pf.function_id
        left outer join sys.partition_range_values prv 
            on pf.function_id = prv.function_id
            and p.partition_number = prv.boundary_id
    WHERE	
        is_ms_shipped = 0   
        and exists (select 1 from sys.partitions p2
                    where t.object_id = p2.object_id
                    and partition_number > 1)
    order by 
         t.name 
        ,p.partition_number desc

    This will show you

  • Tables that have at least two partitions. If you also want to see the number of rows for all the other tables, remove the … and exits (…) from the where-clause.
  • Only one entry per partition. If you want to see an entry per partitioned index, remove and p.index_id = 1 from the join-condition.
  • varchar(max), varchar(1), varchar(n), char(100) ,nchar, nvarchar

    I recently had a discussion with developers, DBAs and Data Designers on the usage of the character data types in SQL Server. A topic, I thought, that has been discussed so many times that everything about it has to be common knowledge. I was wrong. Many things seem to be left to assumptions still. So let’s take a closer look at those types.

    All of them store character data. All of them can be given a size (1 to 8000 or max). But what does that actually mean.

    Char

    Char stores one byte for each character resp. one byte for its size predicate. Char(50) fi stores 50 bytes.

    if object_id('dbo.t1') is not null
      drop table dbo.t1;
    
    set ansi_padding on
    
    create table dbo.t1
      (col1 char(50) null
      ,col2 char(50) not null)
    
    insert dbo.t1 values ('1234567890', '1234567890')
    insert dbo.t1 values (null, '1234567890')
    insert dbo.t1 values ('12345678901', '12345678901')
    
    select
       col1
      ,datalength(col1) as datalength
      ,len(col1)      as stringlength
      ,col2
      ,datalength(col2) as datalength
      ,len(col2)      as stringlength
    from
      dbo.t1

    Here is what we get








    No surprises there. Char columns have a fixed data length independent of their content. When the content is less than the fixed length, the rest will be padded with zeros.
    Let’s do the same again but let’s set ansi_padding off:

    if object_id('dbo.t1') is not null
      drop table dbo.t1;
    
    set ansi_padding off
    
    create table dbo.t1
      (col1 char(50) null
      ,col2 char(50) not null)
    
    insert dbo.t1 values ('1234567890', '1234567890')
    insert dbo.t1 values (null, '1234567890')
    insert dbo.t1 values ('12345678901', '12345678901')
    
    select
       col1
      ,datalength(col1) as datalength
      ,len(col1)      as stringlength
      ,col2
      ,datalength(col2) as datalength
      ,len(col2)      as stringlength
    from
      dbo.t1

    And what we get is this:








    On a nullable column the datalength is the same as the content. No padding occurs. On the mandatory column col2 the content is stilled filled with zeros up to 50.
    SET ANSI_PADDING ON/OFF must be set at table creation time to have an effect.

    Varchar

    Now let’s look at varchar columns. Varchar doesn’t preemtively store whatever size it has in it’s predicate, but only stores as much as it needs, up to its size. To do that, varchar needs to additionally store the size of its content, which takes up additional two bytes.
    So varchar(50) always stores 2 bytes + (n Characters * 1 byte) up to 52 bytes.

    if object_id('dbo.t1') is not null
      drop table dbo.t1;
    
    set ansi_padding on
    
    create table dbo.t1
      (col1 varchar(50) null
      ,col2 varchar(50) not null)
    
    insert dbo.t1 values ('1234567890', '1234567890')
    insert dbo.t1 values (null, '1234567890')
    insert dbo.t1 values ('12345678901', '12345678901')
    
    select
       col1
      ,datalength(col1) as datalength
      ,len(col1)      as stringlength
      ,col2
      ,datalength(col2) as datalength
      ,len(col2)      as stringlength
    from
      dbo.t1

    And what we get is this:









    Independent of the ansi_padding setting and the null/not null constraint, the datalength is always the same as the content length.
    Looks like char can be just as variable as varchar with the appropriate settings, doesn’t it? No, it can’t. Don’t mistake datalength for storage length. Char still stores a byte for each character. Char(50) reserves 50 bytes for every row that is created. Varchar only stores the data that is actually there. Plus 2 bytes.
    The ansi_padding setting may have some benefits in application development, but it does not change the storage needs of character columns.

    Varchar(1) vs. Char(100)

    So when to use which data type? Well, the answer seems pretty obvious:

  • 1 to 3 characters => use char
  • 4 to 7 characters => depends. If most of your data fills the 7 characters, use char. Storage wise the maintenance of varchar has a slight overhead, so char could be the wiser decision.
  • More than 7 characters => use varchar. Unless, of course, your data has a fixed length that never varies.
  • You often hear to make the cut at 15, 20 or even 50 characters. Fact is, that even at as little as 7 or 8 characters varchar is the more efficient choice.

    Varchar(255)

    A common practice I have seen many times is to use varchar(255) or even varchar(max) just for everything. Hey, it only stores what is there, so who cares?
    First, varchar(255). What is this artificial 255 threshold? I know, I am also old enough to remember database systems that only allowed 255 characters. And of course, 11111111 is 255, bla bla. But come on, 64bit systems, 32 GB of RAM or more, TBs of data storage, so please get rid of the 255. Or do your users really enter exactly 255 characters?

    Varchar(max)

    Then varchar(max). Varchar(max) is not really a character data type. It is treated as large data field, just like varbinary, text, ntext and image.
    Well, it is a hybrid. If the data fits on the data page it is treated as varchar, if it does not fit, it is treated as a large object. This means, that instead of the data itself a 16 byte pointer is stored that points to a pointer tree containing pointers to the actual data. This means at least one additional read operation up to several, how many it takes to get all the pointers to all the data together.
    Note, this does not dependent on how much data is actually stored in the field, but solely on if the data still fits in the data row on the page.

    We can force SQL Server to treat varchar(max) as In-Row data by switching off the large value types out of row option (default is on, which makes more sense).

    sp_tableoption 'tablename', 'large value types out of row', 'OFF'

    With this set to off, SQL Server will store the data in-row, which basically means that less rows per data page can be stored. Use this option only when the large data is the main read and write target of the table. (For more on this topic see here)
    Oh, and even with this option off the maximum value that is stored in-row is 8000 bytes, so why not use varchar(8000) instead of varchar(max)?

    External applications like SSIS treat varchar(max) as LOB, which means for SSIS that no matter what data is in there, data transfer will always be done by swapping the data to disk and then reading again from disk. Which makes data transfer a hell lot slower.

    And of course you cannot create indexes on varchar(max) columns. But you can still use it in the include-clause of an index. If you like really big indexes.
    If after all of this you still feel the need to create varchar(max) columns, consider limiting the length with a constraint. That doesn’t really help the issues described above, but it could limit the size of your database. Do you really want users to load 2GB of data in every data row? Why should you allow them to if all you wanna store is some small binary files?

    create table dbo.t1
      (col1 varchar(50) null
      ,col2 varchar(50) not null
      ,col3 varchar(max) null)
    
    alter table dbo.t1 add constraint CHK_col3_MaxLength
      CHECK (len(col3) <= 32000)

    This leads to the foremost reason why you just shouldn’t set every varchar() column to 255 or 8000 or max besides all the technical details:

    The key to a well designed, well performing database is to maintain data integrity.
    Don’t store data you don’t need.
    Define every data you store as well as possible.

    This means, limit the size of every column (not only character columns) to the size and data type you actually need. Not, what is easy to implement or you might need in 100 years time. Varchar() is the most flexible data type of them all and devours almost every data you throw into it. The least we can do is limit the amount.

    Nchar, nvarchar

    Nchar and nvarchar are the unicode-equivalents to char and varchar. They need two bytes per character for storage, but can store any unicode character. Apart from that they behave exactly like char and varchar.
    Well, actually it is the other way around. Char and varchar are actually subsets of nchar and nvarchar. So every varchar column can implicitly be converted to nvarchar, but not the other way around!
    Beware of things like this

    where colVarchar = N'Unicode Text'

    This forces SQL Server to explicitly convert colVarchar to nvarchar, and convert, even if it is executed in the background by SQL Server, is a function. This means that the rows of the query have to be evaluated row-by-row (hidden r-bar) and no indexes on colVarchar can be used.

    where colNVarchar = 'Non-Unicode Text'

    This can be converted implicitly and indexes can be used, since varchar is a subset of nvarchar.

    Summary

  • Choose varchar over char also for small values.
  • Use varchar(max) only when you really, actually, without doubt need it.
  • Better still, use nvarchar.
  • %d bloggers like this: