Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayThis browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
Applies to:
SQL Server
Azure SQL Managed Instance
Creates the Snapshot Agent for the specified publication. This stored procedure is executed at the Publisher on the publication database.
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 Configure SQL Server Database Engine for encrypting connections.
Transact-SQL syntax conventions
sp_addpublication_snapshot
[ @publication = ] N'publication'
[ , [ @frequency_type = ] frequency_type ]
[ , [ @frequency_interval = ] frequency_interval ]
[ , [ @frequency_subday = ] frequency_subday ]
[ , [ @frequency_subday_interval = ] frequency_subday_interval ]
[ , [ @frequency_relative_interval = ] frequency_relative_interval ]
[ , [ @frequency_recurrence_factor = ] frequency_recurrence_factor ]
[ , [ @active_start_date = ] active_start_date ]
[ , [ @active_end_date = ] active_end_date ]
[ , [ @active_start_time_of_day = ] active_start_time_of_day ]
[ , [ @active_end_time_of_day = ] active_end_time_of_day ]
[ , [ @snapshot_job_name = ] N'snapshot_job_name' ]
[ , [ @publisher_security_mode = ] publisher_security_mode ]
[ , [ @publisher_login = ] N'publisher_login' ]
[ , [ @publisher_password = ] N'publisher_password' ]
[ , [ @job_login = ] N'job_login' ]
[ , [ @job_password = ] N'job_password' ]
[ , [ @publisher = ] N'publisher' ]
[ , [ @distributor_security_mode = ] distributor_security_mode ]
[ , [ @distributor_login = ] N'distributor_login' ]
[ , [ @distributor_password = ] N'distributor_password' ]
[ ; ]
The name of the publication. @publication is sysname, with no default.
The frequency with which the Snapshot Agent is executed. @frequency_type is int, and can be one of the following values.
Value | Description |
---|---|
1 |
Once |
4 (default) |
Daily |
8 |
Weekly |
16 |
Monthly |
32 |
Monthly, relative to the frequency interval |
64 |
When SQL Server Agent starts |
128 |
Run when the computer is idle |
The value to apply to the frequency set by @frequency_type. @frequency_interval is int, and can be one of the following values.
Value of frequency_type | Effect on frequency_interval |
---|---|
1 |
@frequency_interval is unused. |
4 (default) |
Every @frequency_interval days, with a default of daily. |
8 |
@frequency_interval is one or more of the following (combined with a | (Bitwise OR) logical operator):1 = Sunday |2 = Monday |4 = Tuesday |8 = Wednesday |16 = Thursday |32 = Friday |64 = Saturday |
16 |
On the @frequency_interval day of the month. |
32 |
@frequency_interval is one of the following values:1 = Sunday |2 = Monday |3 = Tuesday |4 = Wednesday |5 = Thursday |6 = Friday |7 = Saturday |8 = Day |9 = Weekday |10 = Weekend day |
64 |
@frequency_interval is unused. |
128 |
@frequency_interval is unused. |
The unit for freq_subday_interval. @frequency_subday is int, and can be one of these values.
Value | Description |
---|---|
1 |
Once |
2 |
Second |
4 (default) |
Minute |
8 |
Hour |
The interval for frequency_subday, in minutes. @frequency_subday_interval is int, with a default of 5
.
The date the Snapshot Agent runs. @frequency_relative_interval is int, with a default of 1
.
The recurrence factor used by frequency_type. @frequency_recurrence_factor is int, with a default of 0
.
The date when the Snapshot Agent is first scheduled, formatted as yyyyMMdd
. @active_start_date is int, with a default of 0
.
The date when the Snapshot Agent stops being scheduled, formatted as yyyyMMdd
. @active_end_date is int, with a default of 99991231
,which means December 31, 9999.
The time of day when the Snapshot Agent is first scheduled, formatted as HHmmss
. @active_start_time_of_day is int, with a default of 0
.
The time of day when the Snapshot Agent stops being scheduled, formatted as HHmmss
. @active_end_time_of_day is int, with a default of 235959
, which means 11:59:59 P.M. as measured on a 24-hour clock.
The name of an existing Snapshot Agent job name if an existing job is being used. @snapshot_job_name is nvarchar(100), with a default of NULL
. This parameter is for internal use and shouldn't be specified when creating a new publication. If @snapshot_agent_name is specified, then @job_login and @job_password must be NULL
.
Note
Microsoft Entra ID was previously known as Azure Active Directory (Azure AD).
The the security mode used by the agent when connecting to the Publisher. @publisher_security_mode is int, with a default of 1
. A value of 0
must be specified for non-SQL Server Publishers. When possible, use Windows authentication.. The following values define the security mode:
0
specifies SQL Server authentication.1
specifies Windows authentication.2
specifies Microsoft Entra password authentication, starting with SQL Server 2022 (16.x) CU 6.3
specifies Microsoft Entra integrated authentication, starting with SQL Server 2022 (16.x) CU 6.4
specifies Microsoft Entra token authentication, starting with SQL Server 2022 (16.x) CU 6.The login used when connecting to the Publisher. @publisher_login is sysname, with a default of NULL
. @publisher_login must be specified when @publisher_security_mode is 0
. If @publisher_login is NULL
and @publisher_security_mode is 1
, then the account specified in @job_login is used when connecting to the Publisher.
The password used when connecting to the Publisher. @publisher_password is sysname, with a default of NULL
.
Important
Don't store authentication information in script files. To help improve security, we recommend that you provide login names and passwords at run time.
The login for the account under which the agent runs. On Azure SQL Managed Instance, use a SQL Server account. @job_login is nvarchar(257), with a default of NULL
. This account is always used for agent connections to the Distributor. You must supply this parameter when creating a new Snapshot Agent job.
For non-SQL Server Publishers, this must be the same login specified in sp_adddistpublisher.
The password for the Windows account under which the agent runs. @job_password is sysname, with no default. You must supply this parameter when creating a new Snapshot Agent job.
Important
Don't store authentication information in script files. To help improve security, we recommend that you provide login names and passwords at run time.
Specifies a non-SQL Server Publisher. @publisher is sysname, with a default of NULL
.
@publisher shouldn't be used when creating a Snapshot Agent at a SQL Server Publisher.
Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.
Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.
Identified for informational purposes only. Not supported. Future compatibility is not guaranteed.
0
(success) or 1
(failure).
sp_addpublication_snapshot
is used in snapshot replication, transactional replication, and merge replication.
-- To avoid storing the login and password in the script file, the values
-- are passed into SQLCMD as scripting variables. 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".
DECLARE @publicationDB AS sysname;
DECLARE @publication AS sysname;
DECLARE @login AS sysname;
DECLARE @password AS sysname;
SET @publicationDB = N'AdventureWorks';
SET @publication = N'AdvWorksProductTran';
-- Windows account used to run the Log Reader and Snapshot Agents.
SET @login = $(Login);
-- This should be passed at runtime.
SET @password = $(Password);
-- Enable transactional or snapshot replication on the publication database.
EXEC sp_replicationdboption
@dbname=@publicationDB,
@optname=N'publish',
@value = N'true';
-- Execute sp_addlogreader_agent to create the agent job.
EXEC sp_addlogreader_agent
@job_login = @login,
@job_password = @password,
-- Explicitly specify the use of Windows Integrated Authentication (default)
-- when connecting to the Publisher.
@publisher_security_mode = 1;
-- Create a new transactional publication with the required properties.
EXEC sp_addpublication
@publication = @publication,
@status = N'active',
@allow_push = N'true',
@allow_pull = N'true',
@independent_agent = N'true';
-- Create a new snapshot job for the publication, using a default schedule.
EXEC sp_addpublication_snapshot
@publication = @publication,
@job_login = @login,
@job_password = @password,
-- Explicitly specify the use of Windows Integrated Authentication (default)
-- when connecting to the Publisher.
@publisher_security_mode = 1;
GO
Only members of the sysadmin fixed server role or db_owner fixed database role can execute sp_addpublication_snapshot
.
Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register today