Tuesday, May 21, 2013

SQL Server Compact Code Snippet of the Week #15 : flush data to disk immediately

Under normal operation, SQL Server Compact keeps all pending disk writes in memory, and flushes them to disk at least every 10 seconds. The connection string property to control this is called “Flush Interval”, and valid values are between 1 and 1000 seconds. But you may want to flush to disk immediately under certain circumstances, and this weeks code snippet demonstrates how to do just that. This is possible via the CommitMode property on the SqlCeTransaction object Commit method, as demonstrated below:

using (SqlCeConnection conn = new SqlCeConnection(@"Data Source=C:\data\AdventureWorks.sdf;"))
{
    conn.Open();
    // Start a local transaction; SQL Server Compact supports the following
    // isolation levels: ReadCommitted, RepeatableRead, Serializable
    using (SqlCeTransaction tx = conn.BeginTransaction(IsolationLevel.ReadCommitted))
    {
        using (SqlCeCommand cmd1 = conn.CreateCommand())
        {
            // To enlist a command in a transaction, set the Transaction property
            cmd1.Transaction = tx;
            try
            {
                cmd1.CommandText = "INSERT INTO FactSalesQuota " +
                    "(EmployeeKey, TimeKey, SalesAmountQuota) " +
                    "VALUES (2, 1158, 150000.00)";
                cmd1.ExecuteNonQuery();

                // Commit the changes to disk immediately, if everything above succeeded;
                // Use Deferred mode for optimal performance; the changes will
                // be flashed to disk within the timespan specified in the
                // ConnectionString 'FLUSH INTERVAL' property (default 10 seconds);
                //
                tx.Commit(CommitMode.Immediate);
            }

            catch (Exception)
            {
                tx.Rollback();
            }
        }
    }
}

 

Thursday, May 9, 2013

SQL Server Compact Code Snippet of the Week #14 : script all data in a table

Another entry in the scripting API samples, you will find an overview of getting started with the API here.

This weeks entry demonstrates the general pattern for scripting smaller chunks of SQL based on a single table, in this case a INSERT statement for each row in the table.

using (IRepository repository = new DBRepository(@"Data Source=C:\Northwind.sdf"))
{
    Generator generator = new Generator(repository, null);
    foreach (var tableName in repository.GetAllTableNames())
    {
        generator.GenerateTableContent(tableName, false);
    }
    System.IO.File.WriteAllText(@"C:\script.sqlce", generator.GeneratedScript);
}


For SQL Server Compact 4.0, the scripting library is now available on NuGet, making it even easier to get started. https://nuget.org/packages/ErikEJ.SqlCeScripting

Friday, May 3, 2013

SQL Server Compact Code Snippet of the Week #13 : reseed (reset) an IDENTITY column

A question that keeps re-appearing in the forum is, how can I reseed/reset an IDENTITY column in SQL Server Compact, as no DBCC command is available. You can simply use a special syntax of the ALTER TABLE command to do this, as follows:

ALTER TABLE [MyTableName] ALTER COLUMN [Id] IDENTITY (1, 1)

This will make the value of the next generated IDENTITY value 1 and increment with 1. Notice that you do not specify the column type, only the IDENTITY specification.