Jaa


sp_addpublication_snapshot (Transact-SQL)

Creates the Snapshot Agent for the specified publication. This stored procedure is executed at the Publisher on the publication database.

ms174958.security(en-US,SQL.90).gifSecurity Note:
 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 Encrypting Connections to SQL Server.

Topic link iconTransact-SQL Syntax Conventions

Syntax

sp_addpublication_snapshot [ @publication= ] '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 = ] 'snapshot_agent_name' ]
    [ , [ @publisher_security_mode = ] publisher_security_mode ]
    [ , [ @publisher_login = ] 'publisher_login' ]
    [ , [ @publisher_password = ] 'publisher_password' ] 
    [ , [ @job_login = ] 'job_login' ]
    [ , [ @job_password = ] 'job_password' ]
    [ , [ @publisher = ] 'publisher' ]

Arguments

  • [ @publication=] 'publication'
    Is the name of the publication. publication is sysname, with no default.
  • [ @frequency_type=] frequency_type
    Is 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

  • [ @frequency_interval=] frequency_interval
    Is 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) (Transact-SQL) 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:

    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.

  • [ @frequency_subday=] frequency_subday
    Is 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

  • [ @frequency_subday_interval=] frequency_subday_interval
    Is the interval for frequency_subday. frequency_subday_interval is int, with a default of 5, which means every 5 minutes.
  • [ @frequency_relative_interval=] frequency_relative_interval
    Is the date the Snapshot Agent runs. frequency_relative_interval is int, with a default of 1.
  • [ @frequency_recurrence_factor=] frequency_recurrence_factor
    Is the recurrence factor used by frequency_type. frequency_recurrence_factor is int, with a default of 0.
  • [ @active_start_date=] active_start_date
    Is the date when the Snapshot Agent is first scheduled, formatted as YYYYMMDD. active_start_date is int, with a default of 0.
  • [ @active_end_date=] active_end_date
    Is 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.
  • [ @active_start_time_of_day=] active_start_time_of_day
    Is 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.
  • [ @active_end_time_of_day=] active_end_time_of_day
    Is 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.
  • [ @snapshot_job_name = ] 'snapshot_agent_name'
    Is the name of an existing Snapshot Agent job name if an existing job is being used. snapshot_agent_name is nvarchar(100) with a default value of NULL. This parameter is for internal use and should not be specified when creating a new publication. If snapshot_agent_name is specified, then job_login and job_password must be NULL.
  • [ @publisher_security_mode= ] publisher_security_mode
    Is the security mode used by the agent when connecting to the Publisher. publisher_security_mode is smallint, with a default of 1. 0 specifies SQL Server Authentication, and 1 specifies Windows Authentication. A value of 0 must be specified for non-SQL Server Publishers.
  • [ @publisher_login= ] 'publisher_login'
    Is 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 Windows account specified in job_login will be used when connecting to the Publisher.
  • [ @publisher_password= ] 'publisher_password'
    Is the password used when connecting to the Publisher. publisher_password is sysname, with a default of NULL.

    ms174958.security(en-US,SQL.90).gifSecurity Note:
    Do not store authentication information in script files. Login names and passwords should be supplied at runtime.
  • [ @job_login= ] 'job_login'
    Is the login for the Windows account under which the agent runs. job_login is nvarchar(257), with a default of NULL. This Windows account is always used for agent connections to the Distributor. You must supply this parameter when creating a new Snapshot Agent job.
  • [ @job_password= ] 'job_password'
    Is 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.

    ms174958.security(en-US,SQL.90).gifSecurity Note:
    Do not store authentication information in script files. Login names and passwords should be supplied at runtime.
  • [ @publisher= ] 'publisher'
    Specifies a non-SQL Server Publisher. publisher is sysname, with a default of NULL.

    Note

    publisher should not be used when creating a Snapshot Agent at a SQL Server Publisher.

Return Code Values

0 (success) or 1 (failure)

Remarks

sp_addpublication_snapshot is used in snapshot replication, transactional replication, and merge replication.

Permissions

Only members of the sysadmin fixed server role or db_owner fixed database role can execute sp_addpublication_snapshot.

Example

-- 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

See Also

Reference

sp_addpublication (Transact-SQL)
sp_changepublication_snapshot (Transact-SQL)
sp_startpublication_snapshot (Transact-SQL)
Replication Stored Procedures (Transact-SQL)

Other Resources

How to: Create a Publication (Replication Transact-SQL Programming)
Creating and Applying the Snapshot

Help and Information

Getting SQL Server 2005 Assistance

Change History

Release History

12 December 2006

Updated content:
  • Updated information about @frequency_type and @frequency_interval parameters.