Compartir a través de


Usar variables de sesión para la sincronización de colaboración

Nota

La finalidad de los temas de esta sección de la documentación, Sincronizar otras bases de datos compatibles con ADO.NET, es mostrar cómo se pueden sincronizar otras bases de datos distintas de SQL Server mediante Sync Framework. En esta versión, se utiliza SQL Server en los ejemplos de código, pero el código puede utilizarse en otras bases de datos compatibles con ADO.NET, siempre y cuando se modifiquen los objetos específicos de SQL Server (como SqlConnection) y las consultas SQL que se muestran. Para obtener información acerca de la sincronización de SQL Server, vea Configurar y ejecutar la sincronización de colaboración (SQL Server).

En este tema se muestra cómo usar variables de sesión en Sync Framework. Los ejemplos de este tema se centran en los tipos y propiedades siguientes de Sync Framework:

Para obtener información acerca de cómo ejecutar código de ejemplo, vea "Aplicaciones de ejemplo en los temas de procedimientos" en Sincronizar otras bases de datos compatibles con ADO.NET.

Introducción a las variables de sesión

Sync Framework proporciona un conjunto de variables de sesión que permiten pasar valores a los comandos DbSyncAdapter y DbSyncProvider durante la sincronización. Estas variables se especifican igual que otros parámetros de las consultas o los procedimientos almacenados en los comandos de ADO.NET. Durante una sesión de sincronización, cuando DbSyncProvider invoca a cada objeto de comando de ADO.NET, el proveedor revisa la colección de parámetros de sincronización (SyncParameters) para determinar si puede asignar cada parámetro a un parámetro de comandos ADO.NET según los nombres. Si se da una correspondencia con una variable de sesión integrada o con un parámetro personalizado que haya definido, Sync Framework rellena la variable antes de que el proveedor llame al comando.

Por ejemplo, la instrucción UPDATE siguiente aplica los cambios a la tabla Customer usando las variables de sesión @sync_min_timestamp, @sync_force_write y @sync_row_count.

UPDATE c
SET c.CustomerName = @CustomerName, c.SalesPerson = @SalesPerson, c.CustomerType = @CustomerType      
FROM Sales.Customer c JOIN Sync.Customer_Tracking t ON c.CustomerId = t.CustomerId
WHERE ((t.local_update_peer_timestamp <= @sync_min_timestamp) OR @sync_force_write = 1)
    AND t.CustomerId = @CustomerId  
SET @sync_row_count = @@rowcount

Sync Framework establece los valores de @sync_min_timestamp y @sync_force_write durante la sincronización, mientras que la función @@rowcount de SQL Server establece el valor de @sync_row_count. Puede usar directamente los nombres de las variables, como en la consulta anterior, o bien puede usar las constantes de cadena disponibles en el objeto SyncSession. En la tabla siguiente se muestran todas las variables de sesión disponibles y se explica cómo se utilizan.

Variable de sesión Uso

sync_check_concurrency

Sync Framework la usa para los comandos que actualizan y eliminan metadatos. Sync Framework utiliza este valor para determinar si se puede realizar una modificación en los metadatos si la fila a la que hacen referencia ha cambiado. Si no puede realizarse un cambio en los metadatos, se genera el evento ApplyMetadataFailed.

sync_create_peer_key, sync_create_peer_timestamp, sync_row_is_tombstone, sync_row_timestamp, sync_update_peer_key, sync_update_peer_timestamp, sync_scope_cleanup_timestamp, sync_scope_local_id, sync_shared_scope_name y sync_table_name

Se usan en los comandos que seleccionan y aplican los cambios a las columnas de seguimiento de cambios. Para obtener más información sobre estas columnas, vea "Crear tablas de seguimiento para metadatos por tabla" en Aprovisionar una base de datos servidor para la sincronización de colaboración (no SQL Server).

sync_force_write

Se usa con una ApplyAction de RetryWithForceWrite para forzar la aplicación de un cambio que produjo un error a causa de un conflicto o un error. Para obtener más información, vea Tratar los conflictos de datos y los errores de la sincronización de colaboración (SQL Server).

sync_initialize

Informa sobre si la sesión de sincronización actual es la sesión inicial (un valor de 1) o una sincronización posterior (un valor de 0).

sync_metadata_only

Se usa en Sync Framework para los comandos que se especifican para las propiedades SelectRowCommand y SelectIncrementalChangesCommand. Cuando Sync Framework especifica el valor 1 para esta variable, sólo selecciona los metadatos pero no los cambios de los datos asociados. Se trata de una optimización para los casos en los que Sync Framework no requiere cambios en los datos, por ejemplo al seleccionar filas en conflicto con SelectRowCommand.

sync_min_timestamp y sync_new_timestamp

Se usan para definir el conjunto de cambios que se sincronizan durante una sesión. Durante la sesión de sincronización actual, el comando especificado para la propiedad SelectNewTimestampCommand proporciona un valor timestamp nuevo. Se sincronizan los cambios realizados después del valor mínimo y antes del valor nuevo. El valor nuevo se almacena y se utiliza como valor mínimo de la siguiente sesión de sincronización.

sync_row_count

Devuelve el número de filas afectadas por la última operación en el servidor. En las bases de datos de SQL Server, @@ROWCOUNT proporciona el valor de esta variable. Como se muestra en los ejemplos de código de este tema, los procedimientos almacenados deberían incluir un parámetro de salida que establece el valor de sync_row_count.

Un recuento de filas con el valor 0 como resultado indica que una operación no se realizó correctamente, por lo general debido a un conflicto o un error. Para obtener más información, vea Tratar los conflictos de datos y los errores de la sincronización de colaboración (SQL Server).

sync_scope_cleanup_knowledge, sync_scope_id, sync_scope_knowledge, sync_scope_name y sync_scope_timestamp

Se usan en los comandos que seleccionan y aplican los cambios a la tabla que almacena el conocimiento de sincronización. Para obtener un ejemplo de esta tabla, vea "Crear tablas de seguimiento para metadatos por ámbito" en Aprovisionar una base de datos servidor para la sincronización de colaboración (no SQL Server).

sync_session_id

Devuelve un valor de GUID que identifica la sesión actual de sincronización.

sync_stage_name

Devuelve un valor que corresponde a uno de los valores de la enumeración DbSyncStage.

Ejemplo

Los ejemplos de código siguientes muestran cómo usar variables de sesión cuando se sincroniza la tabla Customer en la base de datos del mismo nivel de ejemplo de Sync Framework.

Partes principales de la API

Esta sección proporciona ejemplos de código que destacan algunas de las partes principales de la API que incluyen variables de sesión. Algunos de los comandos que se muestran llaman a procedimientos almacenados que están incluidos en la base de datos del mismo nivel de ejemplo. Para obtener más información, vea "Crear procedimientos almacenados para seleccionar y actualizar datos y metadatos" de Aprovisionar una base de datos servidor para la sincronización de colaboración (no SQL Server).

En el ejemplo de código siguiente se especifica una consulta para la propiedad SelectNewTimestampCommand. Esta propiedad establece el valor de la variable sync_new_timestamp. Este valor lo utilizan los comandos de sincronización que seleccionan cambios de la base de datos servidor.

SqlCommand selectNewTimestampCommand = new SqlCommand();
string newTimestampVariable = "@" + DbSyncSession.SyncNewTimestamp;
selectNewTimestampCommand.CommandText = "SELECT " + newTimestampVariable + " = min_active_rowversion() - 1";
selectNewTimestampCommand.Parameters.Add(newTimestampVariable, SqlDbType.Timestamp);
selectNewTimestampCommand.Parameters[newTimestampVariable].Direction = ParameterDirection.Output;

sampleProvider.SelectNewTimestampCommand = selectNewTimestampCommand;
Dim newTimestampVariable As String = "@" + DbSyncSession.SyncNewTimestamp

Dim selectNewTimestampCommand As New SqlCommand()

With selectNewTimestampCommand
    .CommandText = "SELECT " + newTimestampVariable + " = min_active_rowversion() - 1"
    .Parameters.Add(newTimestampVariable, SqlDbType.Timestamp)
    .Parameters(newTimestampVariable).Direction = ParameterDirection.Output
End With

sampleProvider.SelectNewTimestampCommand = selectNewTimestampCommand

La función MIN_ACTIVE_ROWVERSION devuelve el valor activo menor de timestamp (conocido también como rowversion) en la base de datos actual. El valor timestamp está activo cuando se usa en una transacción que aún no se ha confirmado. Si no hay valores activos en la base de datos, MIN_ACTIVE_ROWVERSION devuelve el mismo valor como @@DBTS + 1. MIN_ACTIVE_ROWVERSION resulta útil para determinados escenarios, como la sincronización de datos, que usan valores timestamp para agrupar conjuntos de cambios. Si una aplicación usa @@DBTS en sus comandos de delimitador en lugar de MIN_ACTIVE_ROWVERSION, es posible que se pierdan cambios que están activos cuando se produce la sincronización.

En el ejemplo de código siguiente se especifica un procedimiento almacenado para la propiedad SelectIncrementalChangesCommand. Este procedimiento selecciona las inserciones, actualizaciones y eliminaciones de un elemento del mismo nivel que se van a aplicar a un segundo elemento durante una sesión de sincronización. La variable sync_min_timestamp especifica el valor de timestamp mínimo que se incluye en el conjunto de cambios que se va a sincronizar. El valor de esta variable se compara con los valores de la columna sync_row_timestamp de la tabla de seguimiento para determinar qué filas seleccionar. La variable sync_initialize se utiliza para especificar si una sesión de sincronización es la primera entre dos elementos del mismo nivel. Si es la primera sesión entre dos elementos del mismo nivel, el procedimiento almacenado sp_Customer_SelectChanges puede incluir lógica que solo se ejecute durante esta primera sesión.

SqlCommand chgsCustomerCmd = new SqlCommand();
chgsCustomerCmd.CommandType = CommandType.StoredProcedure;
chgsCustomerCmd.CommandText = "Sync.sp_Customer_SelectChanges";
chgsCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncMetadataOnly, SqlDbType.Int);
chgsCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncMinTimestamp, SqlDbType.BigInt);
chgsCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int);
chgsCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncInitialize, SqlDbType.Int);

adapterCustomer.SelectIncrementalChangesCommand = chgsCustomerCmd;
Dim chgsCustomerCmd As New SqlCommand()

With chgsCustomerCmd
    .CommandType = CommandType.StoredProcedure
    .CommandText = "Sync.sp_Customer_SelectChanges"
    .Parameters.Add("@" + DbSyncSession.SyncMetadataOnly, SqlDbType.Int)
    .Parameters.Add("@" + DbSyncSession.SyncMinTimestamp, SqlDbType.BigInt)
    .Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int)
    .Parameters.Add("@" + DbSyncSession.SyncInitialize, SqlDbType.Int)
End With

adapterCustomer.SelectIncrementalChangesCommand = chgsCustomerCmd

El ejemplo de código siguiente especifica un comando que aplica las actualizaciones en un elemento del mismo nivel seleccionado desde otro. La variable sync_row_count permite a Sync Framework determinar si una actualización se realizó correctamente o no. Si se produce un error en una actualización, la variable sync_force_write puede establecerse en 1. Esto habilita una lógica diferente en el procedimiento de almacenado sp_Customer_ApplyUpdate. Para obtener más información, vea Tratar los conflictos de datos y los errores de la sincronización de colaboración (SQL Server). Antes de que una actualización se aplique en un elemento del mismo nivel, la variable sync_min_timestamp se utiliza para comprobar si una fila del elemento del mismo nivel se ha actualizado desde la sesión de sincronización anterior.

SqlCommand updCustomerCmd = new SqlCommand();
updCustomerCmd.CommandType = CommandType.StoredProcedure;
updCustomerCmd.CommandText = "Sync.sp_Customer_ApplyUpdate";
updCustomerCmd.Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier);
updCustomerCmd.Parameters.Add("@CustomerName", SqlDbType.NVarChar);
updCustomerCmd.Parameters.Add("@SalesPerson", SqlDbType.NVarChar);
updCustomerCmd.Parameters.Add("@CustomerType", SqlDbType.NVarChar);
updCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncMinTimestamp, SqlDbType.BigInt);
updCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output;
updCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncForceWrite, SqlDbType.Int);

adapterCustomer.UpdateCommand = updCustomerCmd;
Dim updCustomerCmd As New SqlCommand()

With updCustomerCmd
    .CommandType = CommandType.StoredProcedure
    .CommandText = "Sync.sp_Customer_ApplyUpdate"
    .Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier)
    .Parameters.Add("@CustomerName", SqlDbType.NVarChar)
    .Parameters.Add("@SalesPerson", SqlDbType.NVarChar)
    .Parameters.Add("@CustomerType", SqlDbType.NVarChar)
    .Parameters.Add("@" + DbSyncSession.SyncMinTimestamp, SqlDbType.BigInt)
    .Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output
    .Parameters.Add("@" + DbSyncSession.SyncForceWrite, SqlDbType.Int)
End With

adapterCustomer.UpdateCommand = updCustomerCmd

Los ejemplos de código siguientes especifican los comandos que aplican las actualizaciones a las tablas Customer_Tracking y ScopeInfo. La mayoría de las variables de sesión corresponde a las columnas de las tablas de seguimiento. La variable sync_check_concurrency se utiliza en los comandos para determinar si se pueden realizar cambios en los metadatos cuando las filas a las que hacen referencia han cambiado.

SqlCommand updMetadataCustomerCmd = new SqlCommand();
updMetadataCustomerCmd.CommandType = CommandType.StoredProcedure;
updMetadataCustomerCmd.CommandText = "Sync.sp_Customer_UpdateMetadata";
updMetadataCustomerCmd.Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier);
updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int);
updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowTimestamp, SqlDbType.BigInt);
updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncCreatePeerKey, SqlDbType.Int);
updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncCreatePeerTimestamp, SqlDbType.BigInt);
updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncUpdatePeerKey, SqlDbType.Int);
updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncUpdatePeerTimestamp, SqlDbType.BigInt);
updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowIsTombstone, SqlDbType.Int);
updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int);
updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output;

adapterCustomer.UpdateMetadataCommand = updMetadataCustomerCmd;
Dim updMetadataCustomerCmd As New SqlCommand()

With updMetadataCustomerCmd
    .CommandType = CommandType.StoredProcedure
    .CommandText = "Sync.sp_Customer_UpdateMetadata"
    .Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier)
    .Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int)
    .Parameters.Add("@" + DbSyncSession.SyncRowTimestamp, SqlDbType.BigInt)
    .Parameters.Add("@" + DbSyncSession.SyncCreatePeerKey, SqlDbType.Int)
    .Parameters.Add("@" + DbSyncSession.SyncCreatePeerTimestamp, SqlDbType.BigInt)
    .Parameters.Add("@" + DbSyncSession.SyncUpdatePeerKey, SqlDbType.Int)
    .Parameters.Add("@" + DbSyncSession.SyncUpdatePeerTimestamp, SqlDbType.BigInt)
    .Parameters.Add("@" + DbSyncSession.SyncRowIsTombstone, SqlDbType.Int)
    .Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int)
    .Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output
End With

adapterCustomer.UpdateMetadataCommand = updMetadataCustomerCmd
SqlCommand updReplicaInfoCmd = new SqlCommand();
updReplicaInfoCmd.CommandType = CommandType.Text;
updReplicaInfoCmd.CommandText = "UPDATE  Sync.ScopeInfo SET " +
                                "scope_sync_knowledge = @" + DbSyncSession.SyncScopeKnowledge + ", " +
                                "scope_id = @" + DbSyncSession.SyncScopeId + ", " +
                                "scope_tombstone_cleanup_knowledge = @" + DbSyncSession.SyncScopeCleanupKnowledge + " " +
                                "WHERE scope_name = @" + DbSyncSession.SyncScopeName + " AND " +
                                " ( @" + DbSyncSession.SyncCheckConcurrency + " = 0 OR scope_timestamp = @" + DbSyncSession.SyncScopeTimestamp + "); " +
                                "set @" + DbSyncSession.SyncRowCount + " = @@rowcount";
updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncScopeKnowledge, SqlDbType.VarBinary, 10000);
updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncScopeCleanupKnowledge, SqlDbType.VarBinary, 10000);
updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncScopeName, SqlDbType.NVarChar, 100);
updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int);
updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncScopeId, SqlDbType.UniqueIdentifier);
updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncScopeTimestamp, SqlDbType.BigInt);
updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output;

sampleProvider.UpdateScopeInfoCommand = updReplicaInfoCmd;
Dim updReplicaInfoCmd As New SqlCommand()

With updReplicaInfoCmd
    .CommandType = CommandType.Text
    .CommandText = "UPDATE  Sync.ScopeInfo SET " _
                 & "scope_sync_knowledge = @" + DbSyncSession.SyncScopeKnowledge + ", " _
                 & "scope_id = @" + DbSyncSession.SyncScopeId + ", " _
                 & "scope_tombstone_cleanup_knowledge = @" + DbSyncSession.SyncScopeCleanupKnowledge + " " _
                 & "WHERE scope_name = @" + DbSyncSession.SyncScopeName + " AND " _
                 & " ( @" + DbSyncSession.SyncCheckConcurrency + " = 0 OR scope_timestamp = @" + DbSyncSession.SyncScopeTimestamp + "); " _
                 & "set @" + DbSyncSession.SyncRowCount + " = @@rowcount"
    .Parameters.Add("@" + DbSyncSession.SyncScopeKnowledge, SqlDbType.VarBinary, 10000)
    .Parameters.Add("@" + DbSyncSession.SyncScopeCleanupKnowledge, SqlDbType.VarBinary, 10000)
    .Parameters.Add("@" + DbSyncSession.SyncScopeName, SqlDbType.NVarChar, 100)
    .Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int)
    .Parameters.Add("@" + DbSyncSession.SyncScopeId, SqlDbType.UniqueIdentifier)
    .Parameters.Add("@" + DbSyncSession.SyncScopeTimestamp, SqlDbType.BigInt)
    .Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output
End With

sampleProvider.UpdateScopeInfoCommand = updReplicaInfoCmd

Ejemplo de código completo

En el ejemplo de código completo siguiente se incluyen los ejemplos de código descritos anteriormente en este tema y código adicional para realizar la sincronización. Para el ejemplo, se requiere que la clase Utility esté disponible en Clase de utilidad para los temas de procedimientos del proveedor de bases de datos.

using System;
using System.IO;
using System.Text;
using System.Data;
using System.Data.SqlClient;
using Microsoft.Synchronization;
using Microsoft.Synchronization.Data;

namespace Microsoft.Samples.Synchronization
{
    class Program
    {
        static void Main(string[] args)
        {

            //The SampleStats class handles information from the SyncStatistics
            //object that the Synchronize method returns.
            SampleStats sampleStats = new SampleStats();

            try
            {
                //Initial synchronization. Instantiate the SyncOrchestrator
                //and call Synchronize. Note that data is not synchronized during the
                //session between peer 1 and peer 3, because all rows have already
                //been delivered to peer 3 during its synchronization session with peer 2.
                SyncOrchestrator sampleSyncAgent;
                SyncOperationStatistics syncStatistics;

                sampleSyncAgent = new SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync2);
                syncStatistics = sampleSyncAgent.Synchronize();
                sampleStats.DisplayStats(syncStatistics, "initial");

                sampleSyncAgent = new SampleSyncAgent(Utility.ConnStr_DbSync2, Utility.ConnStr_DbSync3);
                syncStatistics = sampleSyncAgent.Synchronize();
                sampleStats.DisplayStats(syncStatistics, "initial");

                sampleSyncAgent = new SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync3);
                syncStatistics = sampleSyncAgent.Synchronize();
                sampleStats.DisplayStats(syncStatistics, "initial");
            }


            catch (DbOutdatedSyncException ex)
            {
                Console.WriteLine("Outdated Knowledge: " + ex.OutdatedPeerSyncKnowledge.ToString() +
                                  " Clean up knowledge: " + ex.MissingCleanupKnowledge.ToString());
            }
            catch (Exception ex)
            {
                Console.WriteLine(ex.Message);
            }

            //Make changes in each peer database.
            Utility.MakeDataChangesOnNode(Utility.ConnStr_DbSync1, "Customer");
            Utility.MakeDataChangesOnNode(Utility.ConnStr_DbSync2, "Customer");
            Utility.MakeDataChangesOnNode(Utility.ConnStr_DbSync3, "Customer");

            try
            {
                //Subsequent synchronization. Changes are now synchronized between all
                //peers.
                SyncOrchestrator sampleSyncAgent;
                SyncOperationStatistics syncStatistics;

                sampleSyncAgent = new SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync2);
                syncStatistics = sampleSyncAgent.Synchronize();
                sampleStats.DisplayStats(syncStatistics, "subsequent");

                sampleSyncAgent = new SampleSyncAgent(Utility.ConnStr_DbSync2, Utility.ConnStr_DbSync3);
                syncStatistics = sampleSyncAgent.Synchronize();
                sampleStats.DisplayStats(syncStatistics, "subsequent");

                sampleSyncAgent = new SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync3);
                syncStatistics = sampleSyncAgent.Synchronize();
                sampleStats.DisplayStats(syncStatistics, "subsequent");

                //Sessions in which no new changes have been made.
                //In this case, the call to SelectTableMaxTimestampsCommand indicates 
                //that no data changes are available to synchronize, so
                //SelectIncrementalChangesCommand is not called.
                sampleSyncAgent = new SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync2);
                syncStatistics = sampleSyncAgent.Synchronize();
                sampleStats.DisplayStats(syncStatistics, "subsequent");

                sampleSyncAgent = new SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync2);
                syncStatistics = sampleSyncAgent.Synchronize();
                sampleStats.DisplayStats(syncStatistics, "subsequent");
            }


            catch (DbOutdatedSyncException ex)
            {
                Console.WriteLine("Outdated Knowledge: " + ex.OutdatedPeerSyncKnowledge.ToString() +
                                  " Clean up knowledge: " + ex.MissingCleanupKnowledge.ToString());
            }
            catch (Exception ex)
            {
                Console.WriteLine(ex.Message);
            }

            //Return peer data back to its original state.
            Utility.CleanUpNode(Utility.ConnStr_DbSync1);
            Utility.CleanUpNode(Utility.ConnStr_DbSync2);
            Utility.CleanUpNode(Utility.ConnStr_DbSync3);

            //Exit.
            Console.Write("\nPress Enter to close the window.");
            Console.ReadLine();
        }

        //Create a class that is derived from 
        //Microsoft.Synchronization.SyncOrchestrator.
        public class SampleSyncAgent : SyncOrchestrator
        {
            public SampleSyncAgent(string localProviderConnString, string remoteProviderConnString)
            {

                //Instantiate the sample provider that allows us to create a provider
                //for both of the peers that are being synchronized.
                SampleSyncProvider sampleSyncProvider = new SampleSyncProvider();

                //Instantiate a DbSyncProvider for the local peer and the remote peer.
                //For example, if this code is running at peer1 and is
                //synchronizing with peer2, peer1 would be the local provider
                //and peer2 the remote provider.
                DbSyncProvider localProvider = new DbSyncProvider();
                DbSyncProvider remoteProvider = new DbSyncProvider();

                //Create a provider by using the SetupSyncProvider on the sample class.             
                sampleSyncProvider.SetupSyncProvider(localProviderConnString, localProvider);
                localProvider.SyncProviderPosition = SyncProviderPosition.Local;
                
                sampleSyncProvider.SetupSyncProvider(remoteProviderConnString, remoteProvider);
                remoteProvider.SyncProviderPosition = SyncProviderPosition.Remote;

                //Specify the local and remote providers that should be synchronized,
                //and the direction and order of changes. In this case, changes are first
                //uploaded from remote to local and then downloaded in the other direction.
                this.LocalProvider = localProvider;
                this.RemoteProvider = remoteProvider;
                this.Direction = SyncDirectionOrder.UploadAndDownload;
            }
        }


        public class SampleSyncProvider
        {
            public DbSyncProvider SetupSyncProvider(string peerConnString, DbSyncProvider sampleProvider)
            {

                SqlConnection peerConnection = new SqlConnection(peerConnString);
                sampleProvider.Connection = peerConnection;
                sampleProvider.ScopeName = "Sales";

                //Create a DbSyncAdapter object for the Customer table and associate it 
                //with the DbSyncProvider. Following the DataAdapter style in ADO.NET, 
                //DbSyncAdapter is the equivalent for synchronization. The commands that 
                //are specified for the DbSyncAdapter object call stored procedures
                //that are created in each peer database.
                DbSyncAdapter adapterCustomer = new DbSyncAdapter("Customer");


                //Specify the primary key, which Sync Framework uses
                //to identify each row during synchronization.
                adapterCustomer.RowIdColumns.Add("CustomerId");


                //Specify the command to select incremental changes.
                //In this command and other commands, session variables are
                //used to pass information at runtime. DbSyncSession.SyncMetadataOnly 
                //and SyncMinTimestamp are two of the string constants that
                //the DbSyncSession class exposes. You could also include 
                //@sync_metadata_only and @sync_min_timestamp directly in your 
                //queries:
                //*  sync_metadata_only is used by Sync Framework as an optimization
                //   in some queries.
                //* The value of the sync_min_timestamp session variable is compared to
                //   values in the sync_row_timestamp column in the tracking table to 
                //   determine which rows to select.
                SqlCommand chgsCustomerCmd = new SqlCommand();
                chgsCustomerCmd.CommandType = CommandType.StoredProcedure;
                chgsCustomerCmd.CommandText = "Sync.sp_Customer_SelectChanges";
                chgsCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncMetadataOnly, SqlDbType.Int);
                chgsCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncMinTimestamp, SqlDbType.BigInt);
                chgsCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int);
                chgsCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncInitialize, SqlDbType.Int);

                adapterCustomer.SelectIncrementalChangesCommand = chgsCustomerCmd;

                //Specify the command to insert rows.
                //The sync_row_count session variable is used in this command 
                //and other commands to return a count of the rows affected by an operation. 
                //A count of 0 indicates that an operation failed.
                SqlCommand insCustomerCmd = new SqlCommand();
                insCustomerCmd.CommandType = CommandType.StoredProcedure;
                insCustomerCmd.CommandText = "Sync.sp_Customer_ApplyInsert";
                insCustomerCmd.Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier);
                insCustomerCmd.Parameters.Add("@CustomerName", SqlDbType.NVarChar);
                insCustomerCmd.Parameters.Add("@SalesPerson", SqlDbType.NVarChar);
                insCustomerCmd.Parameters.Add("@CustomerType", SqlDbType.NVarChar);
                insCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output;

                adapterCustomer.InsertCommand = insCustomerCmd;


                //Specify the command to update rows.
                //The value of the sync_min_timestamp session variable is compared to
                //values in the sync_row_timestamp column in the tracking table to 
                //determine which rows to update.
                SqlCommand updCustomerCmd = new SqlCommand();
                updCustomerCmd.CommandType = CommandType.StoredProcedure;
                updCustomerCmd.CommandText = "Sync.sp_Customer_ApplyUpdate";
                updCustomerCmd.Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier);
                updCustomerCmd.Parameters.Add("@CustomerName", SqlDbType.NVarChar);
                updCustomerCmd.Parameters.Add("@SalesPerson", SqlDbType.NVarChar);
                updCustomerCmd.Parameters.Add("@CustomerType", SqlDbType.NVarChar);
                updCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncMinTimestamp, SqlDbType.BigInt);
                updCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output;
                updCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncForceWrite, SqlDbType.Int);
                
                adapterCustomer.UpdateCommand = updCustomerCmd;


                //Specify the command to delete rows.
                //The value of the sync_min_timestamp session variable is compared to
                //values in the sync_row_timestamp column in the tracking table to 
                //determine which rows to delete.
                SqlCommand delCustomerCmd = new SqlCommand();
                delCustomerCmd.CommandType = CommandType.StoredProcedure;
                delCustomerCmd.CommandText = "Sync.sp_Customer_ApplyDelete";
                delCustomerCmd.Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier);
                delCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncMinTimestamp, SqlDbType.BigInt);
                delCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output;
                delCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncForceWrite, SqlDbType.Int);
                
                adapterCustomer.DeleteCommand = delCustomerCmd;

                //Specify the command to select any conflicting rows.
                SqlCommand selRowCustomerCmd = new SqlCommand();
                selRowCustomerCmd.CommandType = CommandType.StoredProcedure;
                selRowCustomerCmd.CommandText = "Sync.sp_Customer_SelectRow";
                selRowCustomerCmd.Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier);
                selRowCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int);

                adapterCustomer.SelectRowCommand = selRowCustomerCmd;


                //Specify the command to insert metadata rows.
                //The session variables in this command relate to columns in
                //the tracking table.
                SqlCommand insMetadataCustomerCmd = new SqlCommand();
                insMetadataCustomerCmd.CommandType = CommandType.StoredProcedure;
                insMetadataCustomerCmd.CommandText = "Sync.sp_Customer_InsertMetadata";
                insMetadataCustomerCmd.Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier);          
                insMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int);
                insMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowTimestamp, SqlDbType.BigInt);
                insMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncCreatePeerKey, SqlDbType.Int);
                insMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncCreatePeerTimestamp, SqlDbType.BigInt);
                insMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncUpdatePeerKey, SqlDbType.Int);
                insMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncUpdatePeerTimestamp, SqlDbType.BigInt);
                insMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowIsTombstone, SqlDbType.Int);
                insMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int);
                insMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output;

                adapterCustomer.InsertMetadataCommand = insMetadataCustomerCmd;


                //Specify the command to update metadata rows.
                SqlCommand updMetadataCustomerCmd = new SqlCommand();
                updMetadataCustomerCmd.CommandType = CommandType.StoredProcedure;
                updMetadataCustomerCmd.CommandText = "Sync.sp_Customer_UpdateMetadata";
                updMetadataCustomerCmd.Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier);
                updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int);
                updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowTimestamp, SqlDbType.BigInt);
                updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncCreatePeerKey, SqlDbType.Int);
                updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncCreatePeerTimestamp, SqlDbType.BigInt);
                updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncUpdatePeerKey, SqlDbType.Int);
                updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncUpdatePeerTimestamp, SqlDbType.BigInt);
                updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowIsTombstone, SqlDbType.Int);
                updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int);
                updMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output;

                adapterCustomer.UpdateMetadataCommand = updMetadataCustomerCmd;

                //Specify the command to delete metadata rows.
                SqlCommand delMetadataCustomerCmd = new SqlCommand();
                delMetadataCustomerCmd.CommandType = CommandType.StoredProcedure;
                delMetadataCustomerCmd.CommandText = "Sync.sp_Customer_DeleteMetadata";
                delMetadataCustomerCmd.Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier);
                delMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int);
                delMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowTimestamp, SqlDbType.BigInt);
                delMetadataCustomerCmd.Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output;

                adapterCustomer.DeleteMetadataCommand = delMetadataCustomerCmd;


                //Add the adapter to the provider.
                sampleProvider.SyncAdapters.Add(adapterCustomer);


                // Configure commands that relate to the provider itself rather 
                // than the DbSyncAdapter object for each table:
                // * SelectNewTimestampCommand: Returns the new high watermark for 
                //   the current synchronization session.
                // * SelectScopeInfoCommand: Returns sync knowledge, cleanup knowledge, 
                //   and a scope version (timestamp).
                // * UpdateScopeInfoCommand: Sets new values for sync knowledge and cleanup knowledge.            
                // * SelectTableMaxTimestampsCommand (optional): Returns the maximum timestamp from each base table 
                //   or tracking table, to determine whether for each table the destination already 
                //   has all of the changes from the source. If a destination table has all the changes,
                //   SelectIncrementalChangesCommand is not called for that table.
                // There are additional commands related to metadata cleanup that are not 
                // included in this application.


                //Select a new timestamp.
                //During each synchronization, the new value and
                //the last value from the previous synchronization
                //are used: the set of changes between these upper and
                //lower bounds is synchronized.
                SqlCommand selectNewTimestampCommand = new SqlCommand();
                string newTimestampVariable = "@" + DbSyncSession.SyncNewTimestamp;
                selectNewTimestampCommand.CommandText = "SELECT " + newTimestampVariable + " = min_active_rowversion() - 1";
                selectNewTimestampCommand.Parameters.Add(newTimestampVariable, SqlDbType.Timestamp);
                selectNewTimestampCommand.Parameters[newTimestampVariable].Direction = ParameterDirection.Output;
                
                sampleProvider.SelectNewTimestampCommand = selectNewTimestampCommand;

                //Specify the command to select local replica metadata.
                SqlCommand selReplicaInfoCmd = new SqlCommand();
                selReplicaInfoCmd.CommandType = CommandType.Text;
                selReplicaInfoCmd.CommandText = "SELECT " +
                                                "scope_id, " +
                                                "scope_local_id, " +
                                                "scope_sync_knowledge, " +
                                                "scope_tombstone_cleanup_knowledge, " +
                                                "scope_timestamp " +
                                                "FROM Sync.ScopeInfo " +
                                                "WHERE scope_name = @" + DbSyncSession.SyncScopeName;
                selReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncScopeName, SqlDbType.NVarChar, 100);
                
                sampleProvider.SelectScopeInfoCommand = selReplicaInfoCmd;


                //Specify the command to update local replica metadata. 
                SqlCommand updReplicaInfoCmd = new SqlCommand();
                updReplicaInfoCmd.CommandType = CommandType.Text;
                updReplicaInfoCmd.CommandText = "UPDATE  Sync.ScopeInfo SET " +
                                                "scope_sync_knowledge = @" + DbSyncSession.SyncScopeKnowledge + ", " +
                                                "scope_id = @" + DbSyncSession.SyncScopeId + ", " +
                                                "scope_tombstone_cleanup_knowledge = @" + DbSyncSession.SyncScopeCleanupKnowledge + " " +
                                                "WHERE scope_name = @" + DbSyncSession.SyncScopeName + " AND " +
                                                " ( @" + DbSyncSession.SyncCheckConcurrency + " = 0 OR scope_timestamp = @" + DbSyncSession.SyncScopeTimestamp + "); " +
                                                "set @" + DbSyncSession.SyncRowCount + " = @@rowcount";
                updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncScopeKnowledge, SqlDbType.VarBinary, 10000);
                updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncScopeCleanupKnowledge, SqlDbType.VarBinary, 10000);
                updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncScopeName, SqlDbType.NVarChar, 100);
                updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int);
                updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncScopeId, SqlDbType.UniqueIdentifier);
                updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncScopeTimestamp, SqlDbType.BigInt);
                updReplicaInfoCmd.Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output;
                
                sampleProvider.UpdateScopeInfoCommand = updReplicaInfoCmd;


                //Return the maximum timestamp from the Customer_Tracking table.
                //If more tables are synchronized, the query should UNION
                //all of the results. The table name is not schema-qualified
                //in this case because the name was not schema qualified in the
                //DbSyncAdapter constructor.
                SqlCommand selTableMaxTsCmd = new SqlCommand();
                selTableMaxTsCmd.CommandType = CommandType.Text;
                selTableMaxTsCmd.CommandText = "SELECT 'Customer' AS table_name, " +
                                               "MAX(local_update_peer_timestamp) AS max_timestamp " +
                                               "FROM Sync.Customer_Tracking";
                sampleProvider.SelectTableMaxTimestampsCommand = selTableMaxTsCmd;

                return sampleProvider;
            }
        }

        //Handle the statistics that are returned by the SyncAgent.
        public class SampleStats
        {
            public void DisplayStats(SyncOperationStatistics syncStatistics, string syncType)
            {
                Console.WriteLine(String.Empty);
                if (syncType == "initial")
                {
                    Console.WriteLine("****** Initial Synchronization ******");
                }
                else if (syncType == "subsequent")
                {
                    Console.WriteLine("***** Subsequent Synchronization ****");
                }

                Console.WriteLine("Start Time: " + syncStatistics.SyncStartTime);
                Console.WriteLine("Total Changes Uploaded: " + syncStatistics.UploadChangesTotal);
                Console.WriteLine("Total Changes Downloaded: " + syncStatistics.DownloadChangesTotal);
                Console.WriteLine("Complete Time: " + syncStatistics.SyncEndTime);
                Console.WriteLine(String.Empty);
            }
        }
    }
}
Imports System
Imports System.IO
Imports System.Text
Imports System.Data
Imports System.Data.SqlClient
Imports Microsoft.Synchronization
Imports Microsoft.Synchronization.Data

Class Program

    Shared Sub Main(ByVal args() As String)

        'The SampleStats class handles information from the SyncStatistics
        'object that the Synchronize method returns.
        Dim sampleStats As New SampleStats()

        Try
            'Initial synchronization. Instantiate the SyncOrchestrator
            'and call Synchronize. Note that data is not synchronized during the
            'session between peer 1 and peer 3, because all rows have already
            'been delivered to peer 3 during its synchronization session with peer 2.              
            Dim sampleSyncAgent As SyncOrchestrator
            Dim syncStatistics As SyncOperationStatistics

            sampleSyncAgent = New SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync2)
            syncStatistics = sampleSyncAgent.Synchronize()
            sampleStats.DisplayStats(syncStatistics, "initial")

            sampleSyncAgent = New SampleSyncAgent(Utility.ConnStr_DbSync2, Utility.ConnStr_DbSync3)
            syncStatistics = sampleSyncAgent.Synchronize()
            sampleStats.DisplayStats(syncStatistics, "initial")

            sampleSyncAgent = New SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync3)
            syncStatistics = sampleSyncAgent.Synchronize()
            sampleStats.DisplayStats(syncStatistics, "initial")


        Catch ex As DbOutdatedSyncException
            Console.WriteLine("Outdated Knowledge: " & ex.OutdatedPeerSyncKnowledge.ToString() _
                            & " Clean up knowledge: " + ex.MissingCleanupKnowledge.ToString())
        Catch ex As Exception
            Console.WriteLine(ex.Message)
        End Try

        'Make changes in each peer database.
        Utility.MakeDataChangesOnNode(Utility.ConnStr_DbSync1, "Customer")
        Utility.MakeDataChangesOnNode(Utility.ConnStr_DbSync2, "Customer")
        Utility.MakeDataChangesOnNode(Utility.ConnStr_DbSync3, "Customer")

        Try
            'Subsequent synchronization. Changes are now synchronized between all
            'peers.
            Dim sampleSyncAgent As SyncOrchestrator
            Dim syncStatistics As SyncOperationStatistics

            sampleSyncAgent = New SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync2)
            syncStatistics = sampleSyncAgent.Synchronize()
            sampleStats.DisplayStats(syncStatistics, "subsequent")

            sampleSyncAgent = New SampleSyncAgent(Utility.ConnStr_DbSync2, Utility.ConnStr_DbSync3)
            syncStatistics = sampleSyncAgent.Synchronize()
            sampleStats.DisplayStats(syncStatistics, "subsequent")

            sampleSyncAgent = New SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync3)
            syncStatistics = sampleSyncAgent.Synchronize()
            sampleStats.DisplayStats(syncStatistics, "subsequent")

            'Sessions in which no new changes have been made.
            'In this case, the call to SelectTableMaxTimestampsCommand indicates 
            'that no data changes are available to synchronize, so
            'SelectIncrementalChangesCommand is not called.
            sampleSyncAgent = New SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync2)
            syncStatistics = sampleSyncAgent.Synchronize()
            sampleStats.DisplayStats(syncStatistics, "subsequent")

            sampleSyncAgent = New SampleSyncAgent(Utility.ConnStr_DbSync1, Utility.ConnStr_DbSync2)
            syncStatistics = sampleSyncAgent.Synchronize()
            sampleStats.DisplayStats(syncStatistics, "subsequent")


        Catch ex As DbOutdatedSyncException
            Console.WriteLine("Outdated Knowledge: " & ex.OutdatedPeerSyncKnowledge.ToString() _
                            & " Clean up knowledge: " + ex.MissingCleanupKnowledge.ToString())
        Catch ex As Exception
            Console.WriteLine(ex.Message)
        End Try

        'Return peer data back to its original state.
        Utility.CleanUpNode(Utility.ConnStr_DbSync1)
        Utility.CleanUpNode(Utility.ConnStr_DbSync2)
        Utility.CleanUpNode(Utility.ConnStr_DbSync3)

        'Exit.
        Console.Write(vbLf + "Press Enter to close the window.")
        Console.ReadLine()

    End Sub 'Main

End Class 'Program

'Create a class that is derived from 
'Microsoft.Synchronization.SyncOrchestrator.
Public Class SampleSyncAgent
    Inherits SyncOrchestrator

    Public Sub New(ByVal localProviderConnString As String, ByVal remoteProviderConnString As String)

        'Instantiate the sample provider that allows us to create a provider
        'for both of the peers that are being synchronized.
        Dim sampleSyncProvider As New SampleSyncProvider()

        'Instantiate a DbSyncProvider for the local peer and the remote peer.
        'For example, if this code is running at peer1 and is
        'synchronizing with peer2, peer1 would be the local provider
        'and peer2 the remote provider.  
        Dim localProvider As New DbSyncProvider()
        Dim remoteProvider As New DbSyncProvider()

        'Create a provider by using the SetupSyncProvider on the sample class.
        sampleSyncProvider.SetupSyncProvider(localProviderConnString, localProvider)
        localProvider.SyncProviderPosition = SyncProviderPosition.Local

        sampleSyncProvider.SetupSyncProvider(remoteProviderConnString, remoteProvider)
        remoteProvider.SyncProviderPosition = SyncProviderPosition.Remote

        'Specify the local and remote providers that should be synchronized,
        'and the direction and order of changes. In this case, changes are first
        'uploaded from local to remote and then downloaded in the other direction.
        Me.LocalProvider = localProvider
        Me.RemoteProvider = remoteProvider
        Me.Direction = SyncDirectionOrder.UploadAndDownload

    End Sub 'New
End Class 'SampleSyncAgent

Public Class SampleSyncProvider

    Public Function SetupSyncProvider(ByVal peerConnString As String, ByVal sampleProvider As DbSyncProvider) As DbSyncProvider

        Dim peerConnection As New SqlConnection(peerConnString)
        sampleProvider.Connection = peerConnection
        sampleProvider.ScopeName = "Sales"

        'Create a DbSyncAdapter object for the Customer table and associate it 
        'with the DbSyncProvider. Following the DataAdapter style in ADO.NET, 
        'DbSyncAdapter is the equivalent for synchronization. The commands that 
        'are specified for the DbSyncAdapter object call stored procedures
        'that are created in each peer database.
        Dim adapterCustomer As New DbSyncAdapter("Customer")

        'Specify the primary key, which Sync Framework uses
        'to identify each row during synchronization.
        adapterCustomer.RowIdColumns.Add("CustomerId")

        'Specify the command to select incremental changes.
        'In this command and other commands, session variables are
        'used to pass information at runtime. DbSyncSession.SyncMetadataOnly 
        'and SyncMinTimestamp are two of the string constants that
        'the DbSyncSession class exposes. You could also include 
        '@sync_metadata_only and @sync_min_timestamp directly in your 
        'queries:
        '*  sync_metadata_only is used by Sync Framework as an optimization
        '   in some queries.
        '* The value of the sync_min_timestamp session variable is compared to
        '   values in the sync_row_timestamp column in the tracking table to 
        '   determine which rows to select.
        Dim chgsCustomerCmd As New SqlCommand()

        With chgsCustomerCmd
            .CommandType = CommandType.StoredProcedure
            .CommandText = "Sync.sp_Customer_SelectChanges"
            .Parameters.Add("@" + DbSyncSession.SyncMetadataOnly, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncMinTimestamp, SqlDbType.BigInt)
            .Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncInitialize, SqlDbType.Int)
        End With

        adapterCustomer.SelectIncrementalChangesCommand = chgsCustomerCmd

        'Specify the command to insert rows.
        'The sync_row_count session variable is used in this command 
        'and other commands to return a count of the rows affected by an operation. 
        'A count of 0 indicates that an operation failed.
        Dim insCustomerCmd As New SqlCommand()

        With insCustomerCmd
            .CommandType = CommandType.StoredProcedure
            .CommandText = "Sync.sp_Customer_ApplyInsert"
            .Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier)
            .Parameters.Add("@CustomerName", SqlDbType.NVarChar)
            .Parameters.Add("@SalesPerson", SqlDbType.NVarChar)
            .Parameters.Add("@CustomerType", SqlDbType.NVarChar)
            .Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output
        End With

        adapterCustomer.InsertCommand = insCustomerCmd


        'Specify the command to update rows.
        'The value of the sync_min_timestamp session variable is compared to
        'values in the sync_row_timestamp column in the tracking table to 
        'determine which rows to update.
        Dim updCustomerCmd As New SqlCommand()

        With updCustomerCmd
            .CommandType = CommandType.StoredProcedure
            .CommandText = "Sync.sp_Customer_ApplyUpdate"
            .Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier)
            .Parameters.Add("@CustomerName", SqlDbType.NVarChar)
            .Parameters.Add("@SalesPerson", SqlDbType.NVarChar)
            .Parameters.Add("@CustomerType", SqlDbType.NVarChar)
            .Parameters.Add("@" + DbSyncSession.SyncMinTimestamp, SqlDbType.BigInt)
            .Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output
            .Parameters.Add("@" + DbSyncSession.SyncForceWrite, SqlDbType.Int)
        End With

        adapterCustomer.UpdateCommand = updCustomerCmd


        'Specify the command to delete rows.
        'The value of the sync_min_timestamp session variable is compared to
        'values in the sync_row_timestamp column in the tracking table to 
        'determine which rows to delete.
        Dim delCustomerCmd As New SqlCommand()

        With delCustomerCmd
            .CommandType = CommandType.StoredProcedure
            .CommandText = "Sync.sp_Customer_ApplyDelete"
            .Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier)
            .Parameters.Add("@" + DbSyncSession.SyncMinTimestamp, SqlDbType.BigInt)
            .Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output
            .Parameters.Add("@" + DbSyncSession.SyncForceWrite, SqlDbType.Int)
        End With

        adapterCustomer.DeleteCommand = delCustomerCmd

        'Specify the command to select any conflicting rows.
        Dim selRowCustomerCmd As New SqlCommand()

        With selRowCustomerCmd
            .CommandType = CommandType.StoredProcedure
            .CommandText = "Sync.sp_Customer_SelectRow"
            .Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier)
            .Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int)
        End With

        adapterCustomer.SelectRowCommand = selRowCustomerCmd


        'Specify the command to insert metadata rows.
        'The session variables in this command relate to columns in
        'the tracking table. These are the same columns
        'that were specified as DbSyncAdapter properties at the beginning 
        'of this code example.
        Dim insMetadataCustomerCmd As New SqlCommand()

        With insMetadataCustomerCmd
            .CommandType = CommandType.StoredProcedure
            .CommandText = "Sync.sp_Customer_InsertMetadata"
            .Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier)
            .Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncRowTimestamp, SqlDbType.BigInt)
            .Parameters.Add("@" + DbSyncSession.SyncCreatePeerKey, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncCreatePeerTimestamp, SqlDbType.BigInt)
            .Parameters.Add("@" + DbSyncSession.SyncUpdatePeerKey, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncUpdatePeerTimestamp, SqlDbType.BigInt)
            .Parameters.Add("@" + DbSyncSession.SyncRowIsTombstone, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output
        End With

        adapterCustomer.InsertMetadataCommand = insMetadataCustomerCmd


        'Specify the command to update metadata rows.
        Dim updMetadataCustomerCmd As New SqlCommand()

        With updMetadataCustomerCmd
            .CommandType = CommandType.StoredProcedure
            .CommandText = "Sync.sp_Customer_UpdateMetadata"
            .Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier)
            .Parameters.Add("@" + DbSyncSession.SyncScopeLocalId, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncRowTimestamp, SqlDbType.BigInt)
            .Parameters.Add("@" + DbSyncSession.SyncCreatePeerKey, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncCreatePeerTimestamp, SqlDbType.BigInt)
            .Parameters.Add("@" + DbSyncSession.SyncUpdatePeerKey, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncUpdatePeerTimestamp, SqlDbType.BigInt)
            .Parameters.Add("@" + DbSyncSession.SyncRowIsTombstone, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output
        End With

        adapterCustomer.UpdateMetadataCommand = updMetadataCustomerCmd

        'Specify the command to delete metadata rows.
        Dim delMetadataCustomerCmd As New SqlCommand()

        With delMetadataCustomerCmd
            .CommandType = CommandType.StoredProcedure
            .CommandText = "Sync.sp_Customer_DeleteMetadata"
            .Parameters.Add("@CustomerId", SqlDbType.UniqueIdentifier)
            .Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncRowTimestamp, SqlDbType.BigInt)
            .Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output
        End With

        adapterCustomer.DeleteMetadataCommand = delMetadataCustomerCmd


        sampleProvider.SyncAdapters.Add(adapterCustomer)


        ' Configure commands that relate to the provider itself rather 
        ' than the DbSyncAdapter object for each table:
        ' * SelectNewTimestampCommand: Returns the new high watermark for 
        '   the current synchronization session.
        ' * SelectScopeInfoCommand: Returns sync knowledge, cleanup knowledge, 
        '   and a scope version (timestamp).
        ' * UpdateScopeInfoCommand: Sets new values for sync knowledge and cleanup knowledge.            
        ' * SelectTableMaxTimestampsCommand (optional): Returns the maximum timestamp from each base table 
        '   or tracking table, to determine whether for each table the destination already 
        '   has all of the changes from the source. If a destination table has all the changes,
        '   SelectIncrementalChangesCommand is not called for that table.
        ' There are additional commands related to metadata cleanup that are not 
        ' included in this application.           


        'Select a new timestamp.
        'During each synchronization, the new value and
        'the last value from the previous synchronization
        'are used: the set of changes between these upper and
        'lower bounds is synchronized.
        Dim newTimestampVariable As String = "@" + DbSyncSession.SyncNewTimestamp

        Dim selectNewTimestampCommand As New SqlCommand()

        With selectNewTimestampCommand
            .CommandText = "SELECT " + newTimestampVariable + " = min_active_rowversion() - 1"
            .Parameters.Add(newTimestampVariable, SqlDbType.Timestamp)
            .Parameters(newTimestampVariable).Direction = ParameterDirection.Output
        End With

        sampleProvider.SelectNewTimestampCommand = selectNewTimestampCommand

        'Specify the command to select local replica metadata. 
        Dim selReplicaInfoCmd As New SqlCommand()

        With selReplicaInfoCmd
            .CommandType = CommandType.Text
            .CommandText = "SELECT " _
                         & "scope_id, " _
                         & "scope_local_id, " _
                         & "scope_sync_knowledge, " _
                         & "scope_tombstone_cleanup_knowledge, " _
                         & "scope_timestamp " _
                         & "FROM Sync.ScopeInfo " _
                         & "WHERE scope_name = @" + DbSyncSession.SyncScopeName
            .Parameters.Add("@" + DbSyncSession.SyncScopeName, SqlDbType.NVarChar, 100)
        End With

        sampleProvider.SelectScopeInfoCommand = selReplicaInfoCmd


        'Specify the command to update local replica metadata. 
        Dim updReplicaInfoCmd As New SqlCommand()

        With updReplicaInfoCmd
            .CommandType = CommandType.Text
            .CommandText = "UPDATE  Sync.ScopeInfo SET " _
                         & "scope_sync_knowledge = @" + DbSyncSession.SyncScopeKnowledge + ", " _
                         & "scope_id = @" + DbSyncSession.SyncScopeId + ", " _
                         & "scope_tombstone_cleanup_knowledge = @" + DbSyncSession.SyncScopeCleanupKnowledge + " " _
                         & "WHERE scope_name = @" + DbSyncSession.SyncScopeName + " AND " _
                         & " ( @" + DbSyncSession.SyncCheckConcurrency + " = 0 OR scope_timestamp = @" + DbSyncSession.SyncScopeTimestamp + "); " _
                         & "set @" + DbSyncSession.SyncRowCount + " = @@rowcount"
            .Parameters.Add("@" + DbSyncSession.SyncScopeKnowledge, SqlDbType.VarBinary, 10000)
            .Parameters.Add("@" + DbSyncSession.SyncScopeCleanupKnowledge, SqlDbType.VarBinary, 10000)
            .Parameters.Add("@" + DbSyncSession.SyncScopeName, SqlDbType.NVarChar, 100)
            .Parameters.Add("@" + DbSyncSession.SyncCheckConcurrency, SqlDbType.Int)
            .Parameters.Add("@" + DbSyncSession.SyncScopeId, SqlDbType.UniqueIdentifier)
            .Parameters.Add("@" + DbSyncSession.SyncScopeTimestamp, SqlDbType.BigInt)
            .Parameters.Add("@" + DbSyncSession.SyncRowCount, SqlDbType.Int).Direction = ParameterDirection.Output
        End With

        sampleProvider.UpdateScopeInfoCommand = updReplicaInfoCmd

        'Return the maximum timestamp from the Customer_Tracking table.
        'If more tables are synchronized, the query should UNION
        'all of the results. The table name is not schema-qualified
        'in this case because the name was not schema qualified in the
        'DbSyncAdapter constructor.
        Dim selTableMaxTsCmd As New SqlCommand()
        selTableMaxTsCmd.CommandType = CommandType.Text
        selTableMaxTsCmd.CommandText = "SELECT 'Customer' AS table_name, " _
                                     & "MAX(local_update_peer_timestamp) AS max_timestamp " _
                                     & "FROM Sync.Customer_Tracking"
        sampleProvider.SelectTableMaxTimestampsCommand = selTableMaxTsCmd

        Return sampleProvider

    End Function 'SetupSyncProvider

End Class 'SampleSyncProvider


'Handle the statistics that are returned by the SyncAgent.
Public Class SampleStats

    Public Sub DisplayStats(ByVal syncStatistics As SyncOperationStatistics, ByVal syncType As String)
        Console.WriteLine(String.Empty)
        If syncType = "initial" Then
            Console.WriteLine("****** Initial Synchronization ******")
        ElseIf syncType = "subsequent" Then
            Console.WriteLine("***** Subsequent Synchronization ****")
        End If

        Console.WriteLine("Start Time: " & syncStatistics.SyncStartTime)
        Console.WriteLine("Total Changes Uploaded: " & syncStatistics.UploadChangesTotal)
        Console.WriteLine("Total Changes Downloaded: " & syncStatistics.DownloadChangesTotal)
        Console.WriteLine("Complete Time: " & syncStatistics.SyncEndTime)
        Console.WriteLine(String.Empty)

    End Sub 'DisplayStats
End Class 'SampleStats

Vea también

Conceptos

Sincronizar otras bases de datos compatibles con ADO.NET