Create a Snapshot for a Merge Publication with Parameterized Filters

Applies to: SQL Server

This topic describes how to create a snapshot for a merge publication with parameterized filters in SQL Server by using SQL Server Management Studio, Transact-SQL, or Replication Management Objects (RMO).

When parameterized row filters are used in merge publications, replication initializes each subscription with a two-part snapshot. First, a schema snapshot is created that contains all objects required by replication and the schema of the published objects, but not the data. Then, each subscription is initialized with a snapshot that includes the objects and schema from the schema snapshot and the data that belongs to the subscription's partition. If more than one subscription receives a given partition (in other words, they receive the same schema and data), the snapshot for that partition is created only once; multiple subscriptions are initialized from the same snapshot. For more information about parameterized row filters, see Parameterized Row Filters.

You can create snapshots for publications with parameterized filters in one of three ways:

  • Pre-generate snapshots for each partition. Using this option allows you to control when snapshots are generated.
    You can also choose to have the snapshots refreshed on a schedule. New Subscribers that subscribe to a partition for which a snapshot has been created will receive an up-to-date snapshot.

  • Allow Subscribers to request snapshot generation and application the first time they synchronize. Using this option allows new Subscribers to synchronize without requiring intervention from an administrator (SQL Server Agent must be running at the Publisher to allow the snapshot to be generated).

    Note

    If the filtering for one or more articles in the publication yields non-overlapping partitions that are unique for each subscription, metadata is cleaned up whenever the Merge Agent runs. This means that the partitioned snapshot expires more quickly. When using this option, you should consider allowing Subscribers to initiate snapshot generation and delivery. For more information about filtering options, see Parameterized Row Filters.

  • Manually generate a snapshot for each Subscriber with the Snapshot Agent. The Subscriber must then provide the snapshot location to the Merge Agent, so it can retrieve and apply the correct snapshot.

    Note

    This option is supported for backward compatibility and does not allow FTP snapshot shares.

The most flexible approach is to use a combination of pre-generated and Subscriber-requested snapshot options: snapshots are pre-generated and refreshed on a scheduled basis (usually during off-peak times), but a Subscriber can generate its own snapshot if a subscription that requires a new partition is created.

Consider Adventure Works, which has a mobile work force that delivers inventory to individual stores. Each sales person receives a subscription based on their login, which retrieves the data for the stores they service. The administrator chooses to pre-generate snapshots and refresh them every Sunday. Occasionally a new user is added to the system and needs data for a partition that does not have a snapshot available. The administrator also chooses to allow Subscriber-initiated snapshots to avoid the situation where a Subscriber cannot subscribe to the publication because the snapshot is not yet available. When the new Subscriber connects for the first time, the snapshot is generated for the specified partition and applied at the Subscriber (SQL Server Agent must be running at the Publisher to allow the snapshot to be generated).

To create a snapshot for a publication with parameterized filters, see Create a Snapshot for a Merge Publication with Parameterized Filters.

Security Settings for the Snapshot Agent

The Snapshot Agent creates snapshots for each partition. For pre-generated snapshots and snapshots requested by a Subscriber, the agent runs and makes connections under the credentials that were specified when the snapshot agent job for the publication was created (the job is created by the New Publication Wizard or sp_addpublication_snapshot). To change the credentials, use sp_changedynamicsnapshot_job. For more information, see sp_changedynamicsnapshot_job (Transact-SQL).

Recommendations

  • When generating a snapshot for a merge publication using parameterized filters, you must first generate a standard (schema) snapshot that contains all of the published data and Subscriber metadata for the subscription. For more information, see Create and Apply the Initial Snapshot. After you have created the schema snapshot, you can generate the snapshot that contains the Subscriber-specific partition of the published data.

  • If the filtering for one or more articles in the publication yields non-overlapping partitions that are unique for each subscription, metadata is cleaned up whenever the Merge Agent runs. This means that the partitioned snapshot expires more quickly. When using this option, you should consider allowing Subscribers to initiate snapshot generation and delivery.

Using SQL Server Management Studio

Generate snapshots for partitions on the Data Partitions page of the Publication Properties - <Publication> dialog box. For more information about accessing this dialog box, see View and Modify Publication Properties. You can allow Subscribers to initiate snapshot generation and delivery and/or generate snapshots.

Before generating snapshots for one or more partitions, you must:

  1. Create a merge publication with the New Publication Wizard, and specify one or more parameterized row filters on the Add Filter page of the wizard. For more information, see Define and Modify a Parameterized Row Filter for a Merge Article.

  2. Generate a schema snapshot for the publication. By default, a schema snapshot is generated when you complete the New Publication Wizard; you can also generate a schema snapshot from SQL Server Management Studio.

To generate a schema snapshot

  1. Connect to the Publisher in Management Studio, and then expand the server node.

  2. Expand the Replication folder, and then expand the Publications folder.

  3. Right-click the publication for which you want to create a snapshot, and then click View Snapshot Agent Status.

  4. In the View Snapshot Agent Status - <Publication> dialog box, click Start.

    When the Snapshot Agent finishes generating the snapshot, a message will be displayed, such as "[100%] A snapshot of 17 article(s) was generated."

To allow Subscribers to initiate snapshot generation and delivery

  1. On the Data Partitions page of the Publication Properties - <Publication> dialog box, select Automatically define a partition and generate a snapshot if needed when a new Subscriber tries to synchronize.

  2. Select OK.

To generate and refresh snapshots

  1. On the Data Partitions page of the Publication Properties - <Publication> dialog box, click Add.

  2. Enter a value for the HOST_NAME() and/or SUSER_SNAME() value associated with the partition for which you want to create a snapshot.

  3. Optionally specify a schedule for refreshing snapshots:

    1. Select Schedule the Snapshot Agent for this partition to run at the following time(s)

    2. Accept the default schedule for refreshing snapshots, or click Change to specify a different schedule.

  4. Click OK, which returns you to the Publication Properties - <Publication> dialog box.

  5. Select the partition in the property grid, and then click Generate the selected snapshots now.

  6. Select OK.

Using Transact-SQL

Using stored procedures and the Snapshot Agent, you can perform the following:

  • Allow Subscribers to request snapshot generation and application the first time they synchronize.

  • Pre-generate snapshots for each partition.

  • Manually generate a snapshot for each Subscriber.

    Important

    When possible, prompt users to enter security credentials at runtime. If you must store credentials in a script file, you must secure the file to prevent unauthorized access.

To create a publication that allows Subscribers to initiate snapshot generation and delivery

  1. At the Publisher on the publication database, execute sp_addmergepublication (Transact-SQL). Specify the following parameters:

    • The name of the publication for @publication.

    • A value of true for @allow_subscriber_initiated_snapshot, which enables Subscribers to initiate the snapshot process.

    • (Optional) The number of dynamic snapshot processes that can run concurrently for @max_concurrent_dynamic_snapshots. If the maximum number of processes is running and a Subscriber attempts to generate a snapshot, the process is placed in a queue. By default there is no limit to the number of concurrent processes.

  2. At the Publisher, execute sp_addpublication_snapshot (Transact-SQL). Specify the publication name used in step 1 for @publication and the Microsoft Windows credentials under which the Replication Snapshot Agent runs for @job_login and @password. If the agent will use SQL Server Authentication when connecting to the Publisher, you must also specify a value of 0 for @publisher_security_mode and the Microsoft SQL Server login information for @publisher_login and @publisher_password. This creates a Snapshot Agent job for the publication. For more information about generating an initial snapshot and defining a custom schedule for the Snapshot Agent, see Create and Apply the Initial Snapshot.

    Important

    When configuring a Publisher with a remote Distributor, the values supplied for all parameters, including job_login and job_password, are sent to the Distributor as plain text. You should encrypt the connection between the Publisher and its remote Distributor before executing this stored procedure. For more information, see Enable Encrypted Connections to the Database Engine (SQL Server Configuration Manager).

  3. Execute sp_addmergearticle (Transact-SQL) to add articles to the publication. This stored procedure must be executed once for each article in the publication. When using parameterized filters, you must specify a parameterized row filter for one or more articles using the @subset_filterclause parameter. For more information, see Define and Modify a Parameterized Row Filter for a Merge Article.

  4. If other articles will be filtered based on the parameterized row filter, execute sp_addmergefilter (Transact-SQL) to define the join or logical record relationships between articles. This stored procedure must be executed once for each relationship being defined. For more information, see Define and Modify a Join Filter Between Merge Articles.

  5. When the Merge Agent requests the snapshot to initialize the Subscriber, the snapshot for the requesting subscription's partition is automatically generated.

To create a publication and pre-generate or automatically refresh snapshots

  1. Execute sp_addmergepublication (Transact-SQL) to create the publication. For more information, see Create a Publication.

  2. At the Publisher, execute sp_addpublication_snapshot (Transact-SQL). Specify the publication name used in step 1 for @publication and the Windows credentials under which the Snapshot Agent runs for @job_login and @password. If the agent will use SQL Server Authentication when connecting to the Publisher, you must also specify a value of 0 for @publisher_security_mode and the SQL Server login information for @publisher_login and @publisher_password. This creates a Snapshot Agent job for the publication. For more information about generating an initial snapshot and defining a custom schedule for the Snapshot Agent, see Create and Apply the Initial Snapshot.

    Important

    When configuring a Publisher with a remote Distributor, the values supplied for all parameters, including job_login and job_password, are sent to the Distributor as plain text. You should encrypt the connection between the Publisher and its remote Distributor before executing this stored procedure. For more information, see Enable Encrypted Connections to the Database Engine (SQL Server Configuration Manager).

  3. Execute sp_addmergearticle (Transact-SQL) to add articles to the publication. This stored procedure must be executed once for each article in the publication. When using parameterized filters, you must specify a parameterized row filter for one article using the @subset_filterclause parameter. For more information, see Define and Modify a Parameterized Row Filter for a Merge Article.

  4. If other articles will be filtered based on the parameterized row filter, execute sp_addmergefilter (Transact-SQL) to define the join or logical record relationships between articles. This stored procedure must be executed once for each relationship being defined. For more information, see Define and Modify a Join Filter Between Merge Articles.

  5. At the Publisher on the publication database, execute sp_helpmergepublication (Transact-SQL), specifying the value of @publication from step 1. Note the value of the snapshot_jobid in the result set.

  6. Convert the value of the snapshot_jobid obtained in step 5 to uniqueidentifier.

  7. At the Publisher on the msdb database, execute sp_start_job (Transact-SQL), specifying the converted value obtained in step 6 for @job_id.

  8. At the Publisher on the publication database, execute sp_addmergepartition (Transact-SQL). Specify the name of the publication from step 1 for @publication and the value used to define the partition for @suser_sname if SUSER_SNAME (Transact-SQL) is used in the filter clause or for @host_name if HOST_NAME (Transact-SQL) is used in the filter clause.

  9. At the publisher on the publication database, execute sp_adddynamicsnapshot_job (Transact-SQL). Specify the name of the publication from step 1 for @publication, the value of @suser_sname or @host_name from step 8, and a schedule for the job. This creates the job that generates the parameterized snapshot for the specified partition. For more information, see Specify Synchronization Schedules.

    Note

    This job runs using the same Windows account as the initial snapshot job defined in step 2. To remove the parameterized snapshot job and its related data partition, execute sp_dropdynamicsnapshot_job (Transact-SQL).

  10. At the Publisher on the publication database, execute sp_helpmergepartition (Transact-SQL), specifying the value of @publication from step 1 and the value of @suser_sname or @host_name from step 8. Note the value of the dynamic_snapshot_jobid in the result set.

  11. At the Distributor on the msdb database, execute sp_start_job (Transact-SQL), specifying the value obtained in step 9 for @job_id. This starts the parameterized snapshot job for the partition.

  12. Repeat steps 8-11 to generate a partitioned snapshot for each subscription.

To create a publication and manually create snapshots for each partition

  1. Execute sp_addmergepublication (Transact-SQL) to create the publication. For more information, see Create a Publication.

  2. At the Publisher, execute sp_addpublication_snapshot (Transact-SQL). Specify the publication name used in step 1 for @publication and the Windows credentials under which the Snapshot Agent runs for @job_login and @password. If the agent will use SQL Server Authentication when connecting to the Publisher, you must also specify a value of 0 for @publisher_security_mode and the SQL Server login information for @publisher_login and @publisher_password. This creates a Snapshot Agent job for the publication. For more information about generating an initial snapshot and defining a custom schedule for the Snapshot Agent, see Create and Apply the Initial Snapshot.

    Important

    When configuring a Publisher with a remote Distributor, the values supplied for all parameters, including job_login and job_password, are sent to the Distributor as plain text. You should encrypt the connection between the Publisher and its remote Distributor before executing this stored procedure. For more information, see Enable Encrypted Connections to the Database Engine (SQL Server Configuration Manager).

  3. Execute sp_addmergearticle (Transact-SQL) to add articles to the publication. This stored procedure must be executed once for each article in the publication. When using parameterized filters, you must specify a parameterized row filter for at least one article using the @subset_filterclause parameter. For more information, see Define and Modify a Parameterized Row Filter for a Merge Article.

  4. If other articles will be filtered based on the parameterized row filter, execute sp_addmergefilter (Transact-SQL) to define the join or logical record relationships between articles. This stored procedure must be executed once for each relationship being defined. For more information, see Define and Modify a Join Filter Between Merge Articles.

  5. Start the snapshot job or run the Replication Snapshot Agent from the command prompt to generate the standard snapshot schema and other files. For more information, see Create and Apply the Initial Snapshot.

  6. Run the Replication Snapshot Agent again from the command prompt to generate bulk copy (.bcp) files, specifying the location of the partitioned snapshot for -DynamicSnapshotLocation and one or both of the following properties that defines the partition:

  7. Repeat step 6 to generate a partitioned snapshot for each subscription.

  8. Run the Merge Agent for each subscription to apply the initial partitioned snapshot at the Subscribers, specifying the following properties:

    • -Hostname - the value used to define the partition if the actual value of HOST_NAME is being overridden.

    • -DynamicSnapshotLocation - the location of the dynamic snapshot for this partition.

Note

For more information about programming replication agents, see Replication Agent Executables Concepts.

Examples (Transact-SQL)

This example creates a merge publication with parameterized filters where Subscribers initiate the snapshot generation process. Values for @job_login and @job_password are passed in using scripting variables.

-- To avoid storing the login and password in the script file, the value 
-- is passed into SQLCMD as a scripting variable. For information about 
-- how to use scripting variables on the command line and in SQL Server
-- Management Studio, see the "Executing Replication Scripts" section in
-- the topic "Programming Replication Using System Stored Procedures".

--Add a new merge publication.
DECLARE @publicationdb AS sysname;
DECLARE @publication AS sysname;
DECLARE @table1 AS sysname;
DECLARE @table2 AS sysname;
DECLARE @filter AS sysname;
DECLARE @schema_hr AS sysname;
DECLARE @schema_sales AS sysname;

SET @publicationdb = N'AdventureWorks2022';
SET @publication = N'AdvWorksSalesPersonMerge';
SET @table1 = N'Employee';
SET @table2 = N'SalesPerson';
SET @filter = N'SalesPerson_Employee';
SET @schema_hr = N'HumanResources';
SET @schema_sales = N'Sales';

USE [AdventureWorks2022];

-- Enable AdventureWorks2022 for merge replication.
EXEC sp_replicationdboption
  @dbname = @publicationdb,
  @optname = N'merge publish',
  @value = N'true';  

-- Create new merge publication with Subscriber requested snapshot
-- and using the default agent schedule. 
EXEC sp_addmergepublication 
  @publication = @publication, 
  @description = N'Merge publication of AdventureWorks2022.', 
  @allow_subscriber_initiated_snapshot = N'true',
  @publication_compatibility_level = N'90RTM';

-- Create a new snapshot job for the publication, using the default schedule.
-- Pass credentials at runtime using sqlcmd scripting variables.
EXEC sp_addpublication_snapshot 
  @publication = @publication, 
  @job_login = $(login), 
  @job_password = $(password);

-- Add an article for the Employee table, 
-- which is horizontally partitioned using 
-- a parameterized row filter.
EXEC sp_addmergearticle 
  @publication = @publication, 
  @article = @table1, 
  @source_owner = @schema_hr, 
  @source_object = @table1, 
  @type = N'table', 
  @description = 'contains employee information', 
  @subset_filterclause = N'[LoginID] = HOST_NAME()';

-- Add an article for the SalesPerson table, 
-- which is partitioned based on a join filter.
EXEC sp_addmergearticle 
  @publication = @publication, 
  @article = @table2, 
  @source_owner = @schema_sales, 
  @source_object = @table2, 
  @type = N'table', 
  @description = 'contains salesperson information';

-- Add a join filter between the two articles.
EXEC sp_addmergefilter 
  @publication = @publication, 
  @article = @table1, 
  @filtername = @filter, 
  @join_articlename = @table2, 
  @join_filterclause = N'[Employee].[BusinessEntityID] = [SalesPerson].[SalesPersonID]', 
  @join_unique_key = 1, 
  @filter_type = 1;
GO

-- Start the agent job to generate the full snapshot for the publication.
-- The filtered data snapshot is generated automatically the first time 
-- the subscription is synchronized. 
DECLARE @publication AS sysname;
SET @publication = N'AdvWorksSalesPersonMerge';

EXEC sp_startpublication_snapshot 
  @publication = @publication;
GO

This example creates a publication using a parameterized filter where each Subscriber has its partition defined by executing sp_addmergepartition and the filtered snapshot job created by executing sp_adddynamicsnapshot_job passing the partitioning information. Values for @job_login and @job_password are passed in using scripting variables.

-- To avoid storing the login and password in the script file, the value 
-- is passed into SQLCMD as a scripting variable. For information about 
-- how to use scripting variables on the command line and in SQL Server
-- Management Studio, see the "Executing Replication Scripts" section in
-- the topic "Programming Replication Using System Stored Procedures".

--Add a new merge publication.
DECLARE @publicationdb AS sysname;
DECLARE @publication AS sysname;
DECLARE @table1 AS sysname;
DECLARE @table2 AS sysname;
DECLARE @filter AS sysname;
DECLARE @schema_hr AS sysname;
DECLARE @schema_sales AS sysname;

SET @publicationdb = N'AdventureWorks2022';
SET @publication = N'AdvWorksSalesPersonMerge';
SET @table1 = N'Employee';
SET @table2 = N'SalesPerson';
SET @filter = N'SalesPerson_Employee';
SET @schema_hr = N'HumanResources';
SET @schema_sales = N'Sales';

USE [AdventureWorks2022];

-- Enable AdventureWorks2022 for merge replication.
EXEC sp_replicationdboption
  @dbname = @publicationdb,
  @optname = N'merge publish',
  @value = N'true';  

-- Create new merge publication.  
EXEC sp_addmergepublication 
  @publication = @publication, 
  @description = N'Merge publication of AdventureWorks2022.', 
  @allow_subscriber_initiated_snapshot = N'false';

-- Create a new snapshot job for the publication, using the 
-- default schedule. Pass credentials at runtime using 
-- sqlcmd scripting variables.
EXEC sp_addpublication_snapshot 
  @publication = @publication, 
  @job_login = $(Login), 
  @job_password = $(password);

-- Add an article for the Employee table, 
-- which is horizontally partitioned using 
-- a parameterized row filter.
EXEC sp_addmergearticle 
  @publication = @publication, 
  @article = @table1, 
  @source_owner = @schema_hr, 
  @source_object = @table1, 
  @type = N'table', 
  @description = 'contains employee information', 
  @subset_filterclause = N'[LoginID] = HOST_NAME()';

-- Add an article for the SalesPerson table, 
-- which is partitioned based on a join filter.
EXEC sp_addmergearticle 
  @publication = @publication, 
  @article = @table2, 
  @source_owner = @schema_sales, 
  @source_object = @table2, 
  @type = N'table', 
  @description = 'contains customer information';

-- Add a join filter between the two articles.
EXEC sp_addmergefilter 
  @publication = @publication, 
  @article = @table1, 
  @filtername = @filter, 
  @join_articlename = @table2, 
  @join_filterclause = N'[Employee].[BusinessEntityID] = [SalesPerson].[SalesPersonID]', 
  @join_unique_key = 1, 
  @filter_type = 1;
GO

-- Start the snapshot agent job.
DECLARE @publication AS sysname;
SET @publication = N'AdvWorksSalesPersonMerge';

EXEC sp_startpublication_snapshot 
  @publication = @publication;
GO

PRINT '*** Waiting for the initial snapshot.';
GO

-- Create a temporary table to store the filtered data snapshot 
-- job information.
CREATE TABLE #temp (id int,
    job_name sysname,
    job_id uniqueidentifier,
    dynamic_filter_login sysname NULL,
    dynamic_filter_hostname sysname NULL,
    dynamic_snapshot_location nvarchar(255),
    frequency_type int, 
    frequency_interval int, 
    frequency_subday_type int,
    frequency_subday_interval int, 
    frequency_relative_interval int, 
    frequency_recurrence_factor int, 
    active_start_date int, 
    active_end_date int, 
    active_start_time int, 
    active_end_time int
)

-- Create each snapshot for a partition 
-- The initial snapshot must already be generated.
DECLARE @publication AS sysname;
DECLARE @jobname AS sysname
DECLARE @hostname AS sysname
SET @publication = N'AdvWorksSalesPersonMerge';
SET @hostname = N'adventure-works\Fernando';

WHILE NOT EXISTS(SELECT * FROM sysmergepublications 
    WHERE [name] = @publication 
    AND snapshot_ready = 1)
BEGIN
    WAITFOR DELAY '00:00:05'
END

-- Create a data partition by overriding HOST_NAME().
EXEC sp_addmergepartition 
  @publication = @publication,
  @host_name = @hostname;

-- Create the filtered data snapshot job, and use the returned 
-- information to start the job.
EXEC sp_adddynamicsnapshot_job 
  @publication = @publication,
  @host_name = @hostname;

INSERT INTO #temp (id, job_name, job_id, dynamic_filter_login,
    dynamic_filter_hostname, dynamic_snapshot_location,
    frequency_type,	frequency_interval, frequency_subday_type,
    frequency_subday_interval, frequency_relative_interval, 
    frequency_recurrence_factor, active_start_date,	active_end_date, 
    active_start_time,active_end_time)
EXEC sp_helpdynamicsnapshot_job;

SELECT @jobname = (SELECT DISTINCT job_name FROM #temp WHERE dynamic_filter_hostname = @hostname);

EXEC msdb..sp_start_job @job_name = @jobname;
DROP TABLE #temp;
GO

This example creates a publication using a parameterized filter where each Subscriber must have its data partition and filtered snapshot job created by supplying the partitioning information. A Subscriber supplies partitioning information using command-line parameters when manually running the replication agents. This example assumes that a subscription to the publication has also been created.

-- To avoid storing the login and password in the script file, the value 
-- is passed into SQLCMD as a scripting variable. For information about 
-- how to use scripting variables on the command line and in SQL Server
-- Management Studio, see the "Executing Replication Scripts" section in
-- the topic "Programming Replication Using System Stored Procedures".

--Add a new merge publication.
DECLARE @publicationdb AS sysname;
DECLARE @publication AS sysname;
DECLARE @table1 AS sysname;
DECLARE @table2 AS sysname;
DECLARE @filter AS sysname;
DECLARE @schema_hr AS sysname;
DECLARE @schema_sales AS sysname;

SET @publicationdb = N'AdventureWorks2022';
SET @publication = N'AdvWorksSalesPersonMerge';
SET @table1 = N'Employee';
SET @table2 = N'SalesPerson';
SET @filter = N'SalesPerson_Employee';
SET @schema_hr = N'HumanResources';
SET @schema_sales = N'Sales';

USE [AdventureWorks2022];

-- Enable AdventureWorks2022 for merge replication.
EXEC sp_replicationdboption
  @dbname = @publicationdb,
  @optname = N'merge publish',
  @value = N'true';  

-- Create new merge publication.  
EXEC sp_addmergepublication 
  @publication = @publication, 
  @description = N'Merge publication of AdventureWorks2022.', 
  @allow_subscriber_initiated_snapshot = N'false';

-- Create a new snapshot job for the publication, using the 
-- default schedule. Pass credentials at runtime using 
-- sqlcmd scripting variables.
EXEC sp_addpublication_snapshot 
  @publication = @publication, 
  @job_login = $(Login), 
  @job_password = $(Password);

-- Add an article for the Employee table, 
-- which is horizontally partitioned using 
-- a parameterized row filter.
EXEC sp_addmergearticle 
  @publication = @publication, 
  @article = @table1, 
  @source_owner = @schema_hr, 
  @source_object = @table1, 
  @type = N'table', 
  @description = 'contains employee information', 
  @subset_filterclause = N'[LoginID] = HOST_NAME()';

-- Add an article for the SalesPerson table, 
-- which is partitioned based on a join filter.
EXEC sp_addmergearticle 
  @publication = @publication, 
  @article = @table2, 
  @source_owner = @schema_sales, 
  @source_object = @table2, 
  @type = N'table', 
  @description = 'contains customer information';

-- Add a join filter between the two articles.
EXEC sp_addmergefilter 
  @publication = @publication, 
  @article = @table1, 
  @filtername = @filter, 
  @join_articlename = @table2, 
  @join_filterclause = N'[Employee].[BusinessEntityID] = [SalesPerson].[SalesPersonID]', 
  @join_unique_key = 1, 
  @filter_type = 1;
GO
  
REM Line breaks are added to improve readability.   
REM In a batch file, commands must be made in a single line.  
REM Run the Snapshot agent from the command line to generate the standard snapshot   
REM schema and other files.   
SET DistPub=%computername%  
SET PubDB=AdventureWorks2022   
SET PubName=AdvWorksSalesPersonMerge  
  
"C:\Program Files\Microsoft SQL Server\120\COM\SNAPSHOT.EXE" -Publication %PubName%    
-Publisher %DistPub% -Distributor  %DistPub%  -PublisherDB %PubDB%  -ReplicationType 2    
-OutputVerboseLevel 1  -DistributorSecurityMode 1  
  
PAUSE  
  
  
REM Run the Snapshot agent from the command line, this time to generate   
REM the bulk copy (.bcp) data for each Subscriber partition.    
SET DistPub=%computername%  
SET PubDB=AdventureWorks2022   
SET PubName=AdvWorksSalesPersonMerge  
SET SnapshotDir=\\%DistPub%\repldata\unc\fernando  
  
MD %SnapshotDir%  
  
"C:\Program Files\Microsoft SQL Server\120\COM\SNAPSHOT.EXE" -Publication %PubName%    
-Publisher %DistPub%  -Distributor  %DistPub%  -PublisherDB %PubDB%  -ReplicationType 2    
-OutputVerboseLevel 1  -DistributorSecurityMode 1  -DynamicFilterHostName "adventure-works\Fernando"    
-DynamicSnapshotLocation %SnapshotDir%  
  
PAUSE  
  
  
REM Run the Merge Agent for each subscription to apply the partitioned   
REM snapshot for each Subscriber.    
SET Publisher = %computername%  
SET Subscriber = %computername%  
SET PubDB = AdventureWorks2022   
SET SubDB = AdventureWorks2022Replica   
SET PubName = AdvWorksSalesPersonMerge   
SET SnapshotDir=\\%DistPub%\repldata\unc\fernando  
  
"C:\Program Files\Microsoft SQL Server\120\COM\REPLMERG.EXE" -Publisher  %Publisher%    
-Subscriber  %Subscriber%  -Distributor %Publisher%  -PublisherDB %PubDB%    
-SubscriberDB %SubDB% -Publication %PubName%  -PublisherSecurityMode 1  -OutputVerboseLevel 3    
-Output -SubscriberSecurityMode 1  -SubscriptionType 3 -DistributorSecurityMode 1    
-Hostname "adventure-works\Fernando"  -DynamicSnapshotLocation %SnapshotDir%  
  
PAUSE  
  

Using Replication Management Objects (RMO)

You can use Replication Management Objects (RMO) to generate partitioned snapshots programmatically in the following ways:

  • Allow Subscribers to request snapshot generation and application the first time they synchronize.

  • Pre-generate snapshots for each partition.

  • Manually generate a snapshot for each Subscriber by running the Snapshot Agent.

Note

When filtering for an article yields non-overlapping partitions that are unique for each subscription (by specifying a value of F:Microsoft.SqlServer.Replication.PartitionOptions.NonOverlappingSingleSubscription for P:Microsoft.SqlServer.Replication.MergeArticle.PartitionOption when creating a merge article), metadata is cleaned up whenever the Merge Agent runs. This means that the partitioned snapshot expires more quickly. When you use this option, you should consider allowing Subscribers to request snapshot generation. For more information, see the section Using the Appropriate Filtering Options in the topic Parameterized Row Filters.

Important

When possible, prompt users to enter security credentials at runtime. If you must store credentials, use the cryptographic services provided by the Microsoft Windows .NET Framework.

To create a publication that allows Subscribers to initiate snapshot generation and delivery

  1. Create a connection to the Publisher by using the ServerConnection class.

  2. Create an instance of the ReplicationDatabase class for the publication database, set the ConnectionContext property to the instance of ServerConnection from step 1, and call the LoadProperties method. If LoadProperties returns false, confirm that the database exists.

  3. If EnabledMergePublishing property is false, set it to true and call CommitPropertyChanges.

  4. Create an instance of the MergePublication class, and set the following properties for this object:

  5. Call the Create method to create the publication.

    Important

    When configuring a Publisher with a remote Distributor, the values supplied for all properties, including SnapshotGenerationAgentProcessSecurity, are sent to the Distributor as plain text. You should encrypt the connection between the Publisher and its remote Distributor before calling the Create method. For more information, see Enable Encrypted Connections to the Database Engine (SQL Server Configuration Manager).

  6. Use the MergeArticle property to add articles to the publication. Specify the FilterClause property for at least one article that defines the parameterized filter. (Optional) Create MergeJoinFilter objects that define join filters between articles. For more information, see Define an Article.

  7. If the value of SnapshotAgentExists is false, call CreateSnapshotAgent to create the initial Snapshot Agent job for this publication.

  8. Call the StartSnapshotGenerationAgentJob method of the MergePublication object created in step 4. This starts the agent job that generates the initial snapshot. For more information about generating an initial snapshot and defining a custom schedule for the Snapshot Agent, see Create and Apply the Initial Snapshot.

  9. (Optional) Check for a value of true for the SnapshotAvailable property to determine when the initial snapshot is ready for use.

  10. When the Merge Agent for a Subscriber connects for the first time, a partitioned snapshot is generated automatically.

To create a publication and pregenerate or automatically refresh snapshots

  1. Use an instance of the MergePublication class to define a merge publication. For more information, see Create a Publication.

  2. Use the MergeArticle property to add articles to the publication. Specify the FilterClause property for at least one article that defines the parameterized filter, and create any MergeJoinFilter objects that define join filters between articles. For more information, see Define an Article.

  3. If the value of SnapshotAgentExists is false, call CreateSnapshotAgent to create the snapshot agent job for this publication.

  4. Call the StartSnapshotGenerationAgentJob method of the MergePublication object created in step 1. This method starts the agent job that generates the initial snapshot. For more information on generating an initial snapshot and defining a custom schedule for the Snapshot Agent, see Create and Apply the Initial Snapshot.

  5. Check for a value of true for the SnapshotAvailable property to determine when the initial snapshot is ready for use.

  6. Create an instance of the MergePartition class, and set the parameterized filtering criteria for the Subscriber by using one or both of the following properties:

  7. Create an instance of the MergeDynamicSnapshotJob class, and set the same property as in step 6.

  8. Use the ReplicationAgentSchedule class to define a schedule for generating the filtered snapshot for the Subscriber partition.

  9. Using the instance of MergePublication from step 1, call AddMergePartition. Pass the MergePartition object from step 6.

  10. Using the instance of MergePublication from step 1, call the AddMergeDynamicSnapshotJob method. Pass the MergeDynamicSnapshotJob object from step 7 and the ReplicationAgentSchedule object from step 8.

  11. Call EnumMergeDynamicSnapshotJobs, and locate the MergeDynamicSnapshotJob object for the newly added partitioned snapshot job in the returned array.

  12. Get the Name property for the job.

  13. Create a connection to the Distributor by using the ServerConnection class.

  14. Create an instance of the SQL Server Management Objects (SMO) Server class, passing the ServerConnection object from step 13.

  15. Create an instance of the Job class, passing the JobServer property of the Server object from step 14 and the job name from step 12.

  16. Call the Start method to start the partitioned snapshot job.

  17. Repeat steps 6-16 for each Subscriber.

To create a publication and manually create snapshots for each partition

  1. Use an instance of the MergePublication class to define a merge publication. For more information, see Create a Publication.

  2. Use the MergeArticle property to add articles to the publication Specify the FilterClause property for at least one article that defines the parameterized filter, and create any MergeJoinFilter objects that define join filters between articles. For more information, see Define an Article.

  3. Generate the initial snapshot. For more information, see Create and Apply the Initial Snapshot.

  4. Create an instance of the SnapshotGenerationAgent class, and set the following required properties:

  5. Set a value of Merge for ReplicationType.

  6. Set one or more of the following properties to define the partitioning parameters:

  7. Call the GenerateSnapshot method.

  8. Repeat steps 4-7 for each Subscriber.

Examples (RMO)

This example creates a merge publication that allows Subscribers to requested snapshot generation.

// Set the Publisher, publication database, and publication names.
string publisherName = publisherInstance;
string publicationName = "AdvWorksSalesOrdersMerge";
string publicationDbName = "AdventureWorks2022";

ReplicationDatabase publicationDb;
MergePublication publication;

// Create a connection to the Publisher.
ServerConnection conn = new ServerConnection(publisherName);

try
{
    // Connect to the Publisher.
    conn.Connect();

    // Enable the database for merge publication.				
    publicationDb = new ReplicationDatabase(publicationDbName, conn);
    if (publicationDb.LoadProperties())
    {
        if (!publicationDb.EnabledMergePublishing)
        {
            publicationDb.EnabledMergePublishing = true;
        }
    }
    else
    {
        // Do something here if the database does not exist. 
        throw new ApplicationException(String.Format(
            "The {0} database does not exist on {1}.",
            publicationDb, publisherName));
    }

    // Set the required properties for the merge publication.
    publication = new MergePublication();
    publication.ConnectionContext = conn;
    publication.Name = publicationName;
    publication.DatabaseName = publicationDbName;

    // Enable precomputed partitions.
    publication.PartitionGroupsOption = PartitionGroupsOption.True;

    // Specify the Windows account under which the Snapshot Agent job runs.
    // This account will be used for the local connection to the 
    // Distributor and all agent connections that use Windows Authentication.
    publication.SnapshotGenerationAgentProcessSecurity.Login = winLogin;
    publication.SnapshotGenerationAgentProcessSecurity.Password = winPassword;

    // Explicitly set the security mode for the Publisher connection
    // Windows Authentication (the default).
    publication.SnapshotGenerationAgentPublisherSecurity.WindowsAuthentication = true;

    // Enable Subscribers to request snapshot generation and filtering.
    publication.Attributes |= PublicationAttributes.AllowSubscriberInitiatedSnapshot;
    publication.Attributes |= PublicationAttributes.DynamicFilters;

    // Enable pull and push subscriptions.
    publication.Attributes |= PublicationAttributes.AllowPull;
    publication.Attributes |= PublicationAttributes.AllowPush;

    if (!publication.IsExistingObject)
    {
        // Create the merge publication.
        publication.Create();
        
        // Create a Snapshot Agent job for the publication.
        publication.CreateSnapshotAgent();
    }
    else
    {
        throw new ApplicationException(String.Format(
            "The {0} publication already exists.", publicationName));
    }
}

catch (Exception ex)
{
    // Implement custom application error handling here.
    throw new ApplicationException(String.Format(
        "The publication {0} could not be created.", publicationName), ex);
}
finally
{
    conn.Disconnect();
}
' Set the Publisher, publication database, and publication names.
Dim publisherName As String = publisherInstance
Dim publicationName As String = "AdvWorksSalesOrdersMerge"
Dim publicationDbName As String = "AdventureWorks2022"

Dim publicationDb As ReplicationDatabase
Dim publication As MergePublication

' Create a connection to the Publisher.
Dim conn As ServerConnection = New ServerConnection(publisherName)

Try
    ' Connect to the Publisher.
    conn.Connect()

    ' Enable the database for merge publication.				
    publicationDb = New ReplicationDatabase(publicationDbName, conn)
    If publicationDb.LoadProperties() Then
        If Not publicationDb.EnabledMergePublishing Then
            publicationDb.EnabledMergePublishing = True
        End If
    Else
        ' Do something here if the database does not exist. 
        Throw New ApplicationException(String.Format( _
         "The {0} database does not exist on {1}.", _
         publicationDb, publisherName))
    End If

    ' Set the required properties for the merge publication.
    publication = New MergePublication()
    publication.ConnectionContext = conn
    publication.Name = publicationName
    publication.DatabaseName = publicationDbName

    ' Enable precomputed partitions.
    publication.PartitionGroupsOption = PartitionGroupsOption.True

    ' Specify the Windows account under which the Snapshot Agent job runs.
    ' This account will be used for the local connection to the 
    ' Distributor and all agent connections that use Windows Authentication.
    publication.SnapshotGenerationAgentProcessSecurity.Login = winLogin
    publication.SnapshotGenerationAgentProcessSecurity.Password = winPassword

    ' Explicitly set the security mode for the Publisher connection
    ' Windows Authentication (the default).
    publication.SnapshotGenerationAgentPublisherSecurity.WindowsAuthentication = True

    ' Enable Subscribers to request snapshot generation and filtering.
    publication.Attributes = publication.Attributes Or _
        PublicationAttributes.AllowSubscriberInitiatedSnapshot
    publication.Attributes = publication.Attributes Or _
        PublicationAttributes.DynamicFilters

    ' Enable pull and push subscriptions
    publication.Attributes = publication.Attributes Or _
        PublicationAttributes.AllowPull
    publication.Attributes = publication.Attributes Or _
        PublicationAttributes.AllowPush

    If Not publication.IsExistingObject Then
        ' Create the merge publication.
        publication.Create()

        ' Create a Snapshot Agent job for the publication.
        publication.CreateSnapshotAgent()
    Else
        Throw New ApplicationException(String.Format( _
            "The {0} publication already exists.", publicationName))
    End If
Catch ex As Exception
    ' Implement custom application error handling here.
    Throw New ApplicationException(String.Format( _
        "The publication {0} could not be created.", publicationName), ex)
Finally
    conn.Disconnect()
End Try

This example manually creates the Subscriber partition and the filtered snapshot for a merge publication with parameterized row filters.

// Define the server, database, and publication names
string publisherName = publisherInstance;
string publicationName = "AdvWorksSalesOrdersMerge";
string publicationDbName = "AdventureWorks2022";
string distributorName = publisherInstance;

MergePublication publication;
MergePartition partition;
MergeDynamicSnapshotJob snapshotAgentJob;
ReplicationAgentSchedule schedule;

// Create a connection to the Publisher.
ServerConnection publisherConn = new ServerConnection(publisherName);

// Create a connection to the Distributor to start the Snapshot Agent.
ServerConnection distributorConn = new ServerConnection(distributorName);

try
{
    // Connect to the Publisher.
    publisherConn.Connect();

    // Set the required properties for the publication.
    publication = new MergePublication();
    publication.ConnectionContext = publisherConn;
    publication.Name = publicationName;
    publication.DatabaseName = publicationDbName;


    // If we can't get the properties for this merge publication, 
    // then throw an application exception.
    if (publication.LoadProperties() || publication.SnapshotAvailable)
    {
        // Set a weekly schedule for the filtered data snapshot.
        schedule = new ReplicationAgentSchedule();
        schedule.FrequencyType = ScheduleFrequencyType.Weekly;
        schedule.FrequencyRecurrenceFactor = 1;
        schedule.FrequencyInterval = Convert.ToInt32(0x001);

        // Set the value of Hostname that defines the data partition. 
        partition = new MergePartition();
        partition.DynamicFilterHostName = hostname;
        snapshotAgentJob = new MergeDynamicSnapshotJob();
        snapshotAgentJob.DynamicFilterHostName = hostname;

        // Create the partition for the publication with the defined schedule.
        publication.AddMergePartition(partition);
        publication.AddMergeDynamicSnapshotJob(snapshotAgentJob, schedule);
    }
    else
    {
        throw new ApplicationException(String.Format(
            "Settings could not be retrieved for the publication, " +
            " or the initial snapshot has not been generated. " +
            "Ensure that the publication {0} exists on {1} and " +
            "that the Snapshot Agent has run successfully.",
            publicationName, publisherName));
    }
}
catch (Exception ex)
{
    // Do error handling here.
    throw new ApplicationException(string.Format(
        "The partition for '{0}' in the {1} publication could not be created.",
        hostname, publicationName), ex);
}
finally
{
    publisherConn.Disconnect();
    if (distributorConn.IsOpen) distributorConn.Disconnect();
}
' Define the server, database, and publication names
Dim publisherName As String = publisherInstance
Dim publicationName As String = "AdvWorksSalesOrdersMerge"
Dim publicationDbName As String = "AdventureWorks2022"
Dim distributorName As String = publisherInstance

Dim publication As MergePublication
Dim partition As MergePartition
Dim snapshotAgentJob As MergeDynamicSnapshotJob
Dim schedule As ReplicationAgentSchedule

' Create a connection to the Publisher.
Dim publisherConn As ServerConnection = New ServerConnection(publisherName)

' Create a connection to the Distributor to start the Snapshot Agent.
Dim distributorConn As ServerConnection = New ServerConnection(distributorName)

Try
    ' Connect to the Publisher.
    publisherConn.Connect()

    ' Set the required properties for the publication.
    publication = New MergePublication()
    publication.ConnectionContext = publisherConn
    publication.Name = publicationName
    publication.DatabaseName = publicationDbName


    ' If we can't get the properties for this merge publication, 
    ' then throw an application exception.
    If (publication.LoadProperties() Or publication.SnapshotAvailable) Then
        ' Set a weekly schedule for the filtered data snapshot.
        schedule = New ReplicationAgentSchedule()
        schedule.FrequencyType = ScheduleFrequencyType.Weekly
        schedule.FrequencyRecurrenceFactor = 1
        schedule.FrequencyInterval = Convert.ToInt32("0x001", 16)

        ' Set the value of Hostname that defines the data partition. 
        partition = New MergePartition()
        partition.DynamicFilterHostName = hostname
        snapshotAgentJob = New MergeDynamicSnapshotJob()
        snapshotAgentJob.DynamicFilterHostName = hostname

        ' Create the partition for the publication with the defined schedule.
        publication.AddMergePartition(partition)
        publication.AddMergeDynamicSnapshotJob(snapshotAgentJob, schedule)
    Else
        Throw New ApplicationException(String.Format( _
         "Settings could not be retrieved for the publication, " + _
         " or the initial snapshot has not been generated. " + _
         "Ensure that the publication {0} exists on {1} and " + _
         "that the Snapshot Agent has run successfully.", _
         publicationName, publisherName))
    End If
Catch ex As Exception
    ' Do error handling here.
    Throw New ApplicationException(String.Format( _
     "The partition for '{0}' in the {1} publication could not be created.", _
     hostname, publicationName), ex)
Finally
    publisherConn.Disconnect()
    If distributorConn.IsOpen Then
        distributorConn.Disconnect()
    End If
End Try

This example manually starts the Snapshot Agent to generate the filtered data snapshot for a Subscriber to a merge publication with parameterized row filters.

// Set the Publisher, publication database, and publication names.
string publicationName = "AdvWorksSalesOrdersMerge";
string publicationDbName = "AdventureWorks2022";
string publisherName = publisherInstance;
string distributorName = publisherInstance;

SnapshotGenerationAgent agent;

try
{
    // Set the required properties for Snapshot Agent.
    agent = new SnapshotGenerationAgent();
    agent.Distributor = distributorName;
    agent.DistributorSecurityMode = SecurityMode.Integrated;
    agent.Publisher = publisherName;
    agent.PublisherSecurityMode = SecurityMode.Integrated;
    agent.Publication = publicationName;
    agent.PublisherDatabase = publicationDbName;
    agent.ReplicationType = ReplicationType.Merge;

    // Specify the partition information to generate a 
    // filtered snapshot based on Hostname.
    agent.DynamicFilterHostName = hostname;

    // Start the agent synchronously.
    agent.GenerateSnapshot();
}
catch (Exception ex)
{
    // Implement custom application error handling here.
    throw new ApplicationException(String.Format(
        "A snapshot could not be generated for the {0} publication."
        , publicationName), ex);
}
' Set the Publisher, publication database, and publication names.
Dim publicationName As String = "AdvWorksSalesOrdersMerge"
Dim publicationDbName As String = "AdventureWorks2022"
Dim publisherName As String = publisherInstance
Dim distributorName As String = publisherInstance

Dim agent As SnapshotGenerationAgent

Try
    ' Set the required properties for Snapshot Agent.
    agent = New SnapshotGenerationAgent()
    agent.Distributor = distributorName
    agent.DistributorSecurityMode = SecurityMode.Integrated
    agent.Publisher = publisherName
    agent.PublisherSecurityMode = SecurityMode.Integrated
    agent.Publication = publicationName
    agent.PublisherDatabase = publicationDbName
    agent.ReplicationType = ReplicationType.Merge

    ' Specify the partition information to generate a 
    ' filtered snapshot based on Hostname.
    agent.DynamicFilterHostName = hostname

    ' Start the agent synchronously.
    agent.GenerateSnapshot()
Catch ex As Exception
    ' Implement custom application error handling here.
    Throw New ApplicationException(String.Format( _
     "A snapshot could not be generated for the {0} publication." _
     , publicationName), ex)
End Try

See Also

Parameterized Row Filters
Replication System Stored Procedures Concepts
Replication Security Best Practices