Home > Articles > Data > SQL Server

Like this article? We recommend

Creating a Publication

Once you’ve configured a distributor, you’re ready to create publications. To invoke the publication wizard, right-click the local publications folder and choose New Publication from the pop-up menu. As with the Distribution Configuration Wizard, the first screen of this wizard is introductory in nature and can be skipped. The second screen allows you to choose the database in which you want to create a publication; for purposes of this article, I’ll create a publication within the AdventureWorksDW database that can be created as part of SQL Server 2005 installation. After selecting the database, you must choose the publication type. The wizard offers the following options:

  • Snapshot Publication
  • Transactional Publication
  • Transactional Publication with Updatable Subscriptions
  • Merge Publication

The wizard includes a brief description of each type of publication. I’ll use the transactional publication for this example; refer to my earlier articles for more info about other publication types.

A transactional publication can contain one or more articles. An article can be a table, a view (including indexed views), a user-defined function, or a stored procedure. For this example, I’ll replicate the dimAccount table from the AdventureWorksDW database. As shown in Figure 8, I can replicate all columns or a subset of all columns within a given table.

Replication has certain rules as far as which columns can be filtered. Transactional replication prohibits filtering primary-key columns. In addition, if your publication allows updateable subscriptions, you must replicate the msrepl_tran_version column (added by SQL Server when you create such publications). Further, publications that allow updateable subscriptions must replicate any column that doesn’t allow nulls, doesn’t have a predefined default, and isn’t an identity column.

If you check the box Show Only Checked Objects in the List, the wizard limits the list of articles to only those that have been checked. The Article Properties button allows you to set properties for the highlighted article or for all table articles. As Figure 9 shows, you can set a multitude of replication-related properties for each article.

Most properties you can set for table articles are self-explanatory; for example, the Copy Foreign Key Constraints option instructs the replication to include foreign key constraints when creating the table in the subscriber database.

A few properties deserve additional consideration:

  • Destination Object Name, Destination Object Owner. The destination table isn’t required to have the same name or the same owner as the source object.
  • Convert Data Types. This option automatically changes a user-defined data type to the base data type, because the user-defined data type might not exist on the subscriber(s).
  • Convert TIMESTAMP to BINARY. When replicating a column with a TIMESTAMP data type, you can convert it to BINARY. The TIMESTAMP data type tracks the sequence of modifications; every time you change a data row, SQL Server will automatically change the value of the column with the TIMESTAMP data type. This is important because, if you’re not careful, you might end up with different values in the column with the TIMESTAMP data type on the publisher and the subscriber.
  • Convert MAX Data Types to NTEXT and IMAGE. This option translates VARCHAR(MAX) and VARBINARY(MAX) data types, which are new in SQL Server 2005, to respective data types supported in previous versions.
  • Convert XML to NTEXT. Translates the new XML data type to NTEXT.
  • Another option that wasn’t available through wizards in previous versions of SQL Server is automatic identity range management. This option allows the database administrator to set the ranges of valid values for the identity column in the publisher and subscriber databases. For example, we could assign values 1,000,000 and greater to the publisher and 1 to 1,000,000 to the subscriber. When the publisher database reaches the upper limit for the identity range, it will automatically assign a new range so that publisher and subscriber identity values don’t overlap.
  • The final group of options (not shown in Figure 9) determines how to replicate INSERT, UPDATE, and DELETE statements to the subscriber.

Once you’ve set the necessary properties for the article you want to replicate, you can add publication filters (see Figure 10). In previous versions of SQL Server, these filters were referred to as horizontal filters—you create them by supplying a WHERE clause to limit the number of published rows. As shown earlier, now you can filter the publication vertically by specifying which columns to publish.

The next step is to create a snapshot and/or specify the snapshot agent’s schedule, as shown in Figure 11.

The snapshot agent copies the schema and data of the replicated article(s) into the snapshot folder. If you click the Change button on this screen, you’ll get the typical dialog box for creating job schedules; you can run the snapshot agents monthly, weekly, daily, or even multiple times per day.

Next you specify the security settings for the snapshot and log reader agents (see Figure 12). I’ll discuss replication security in greater detail in a later article about transactional replication agents. For now, you just need to know that you can customize security for each agent or use different credentials for each.

The wizard next offers you the option to script the commands for creating the publication. Review the synopsis of the steps the wizard is about to undertake; then specify the publication name and click Finish to create the publication.

Listing 2 shows the script for creating the publication.

Listing 2 Script for creating the example publication.

use [AdventureWorksDW]
exec sp_replicationdboption @dbname = N’AdventureWorksDW’, @optname = N’publish’, @value = N’true’
GO
-- Adding the transactional publication
use [AdventureWorksDW]
exec sp_addpublication @publication = N’DimAccount’,
@description = N’Transactional publication of database ’’AdventureWorksDW’’ from Publisher ’’server\instance’’.’,
@sync_method = N’concurrent’, @retention = 0, @allow_push = N’true’, @allow_pull = N’true’, @allow_anonymous = N’true’,
@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’true’,
@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’DimAccount’, @frequency_type = 4, @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 = null, @job_password = null, @publisher_security_mode = 1


use [AdventureWorksDW]
exec sp_addarticle @publication = N’DimAccount’, @article = N’DimAccount’, @source_owner = N’dbo’,
@source_object = N’DimAccount’, @type = N’logbased’, @description = null, @creation_script = null,
@pre_creation_cmd = N’drop’, @schema_option = 0x000000000803509F, @identityrangemanagementoption = N’manual’,
@destination_table = N’DimAccount’, @destination_owner = N’dbo’, @vertical_partition = N’false’,
@ins_cmd = N’CALL sp_MSins_dboDimAccount’, @del_cmd = N’CALL sp_MSdel_dboDimAccount’,
@upd_cmd = N’SCALL sp_MSupd_dboDimAccount’
GO

You can view the newly created publication’s properties by expanding the local publications folder, right-clicking the publication, and choosing Properties from the pop-up menu. The properties dialog box has several pages, each of which has a specific purpose:

  • General. Shows the publication’s name, description, type, and the database on which the publication is based. You can modify subscription expiration options from this page.
  • Articles. Lets you review the published articles, modify their properties, or add new articles to the publication.
  • Filter Rows. Allows you to create horizontal filters for articles.
  • Snapshot. Enables you to specify the snapshot folder location, snapshot format, or additional scripts to be executed before and after applying the snapshot.
  • FTP Snapshot. Settings that let you allow subscribers to download the snapshot from an FTP share and configure FTP security.
  • Agent Security. Controls security settings for the log reader and snapshot agents.
  • Publication Access List. Specifies SQL Server and Windows logins who have permissions to create and synchronize subscriptions.
  • Subscription Options. Provides a multitude of options for subscribers to the current publication.

The following table describes the subscription options you can set through the Publication Properties dialog box. Note that several of these options are new in SQL Server 2005.

Subscription Option

New in SQL Server 2005

Description

Independent Distribution Agent

No

Specifies whether to use an agent independent of other publications in the same database.

Snapshot Always Available

Yes

Makes snapshot files always be available for initializing subscriptions. This option requires an independent distribution agent.

Allow Anonymous Subscriptions

No

Supports anonymous subscriptions, typically used for replicating over the Internet. This option requires Snapshot Always Available.

Attachable Subscription Database

No

Specifies whether subscriptions can be created by attaching the publication database on the subscriber. This option requires Snapshot Always Available.

Allow Pull Subscriptions

No

Provides support for pull subscriptions.

Allow Initialization from Backup Files

Yes

Enables subscriptions to be created by restoring the publication database backup on the subscriber.

Allow Non-SQL Server Subscribers

No

Permits non-SQL Server subscribers.

Allow Data Transformations

No

Allows for data to be transformed before it’s sent to subscribers. This option is deprecated.

Replicate Schema Changes

Yes

Perhaps the most important change introduced with SQL Server 2005. If this option is set to YES (the default value), replication can deliver to the subscriber(s) any ALTER TABLE statements executed on publishers. In previous releases, some schema changes required removing articles from the publication and were therefore associated with downtime.

Allow Peer-to-Peer Subscriptions

Yes

Determines whether subscribers can participate in peer-to-peer relationship with publishers. Peer-to-peer topology allows multiple nodes to act as publishers and subscribers at the same time. This is similar to bidirectional replication available in previous releases.

Allow Immediate Updating Subscriptions

No

Controls whether data changes on subscriber(s) can be delivered immediately to the publisher.

Allow Queued Updating Subscriptions

No

Specifies whether data changes on subscriber(s) can be queued and delivered to the publisher at a later time. This option is useful if the network line between the publisher and subscriber isn’t always reliable.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020