Edit Data Service (#241)

This is a very large change. I'll try to outline what's going on.

1. This adds the **EditDataService** which manages editing **Sessions**.
    1. Each session has a **ResultSet** (from the QueryExecutionService) which has the rows of the table and basic metadata about the columns 
    2. Each session also has an **IEditTableMetadata** implementation which is derived from SMO metadata which provides more in-depth and trustworthy data about the table than SqlClient alone can.
    3. Each session holds a list of **RowEditBase** abstract class implementations
        1. **RowUpdate** - Update cells in a row (generates `UPDATE` statement)
        2. **RowDelete** - Delete an entire row (generates `DELETE` statement)
        3. **RowCreate** - Add a new row (generates `INSERT INTO` statement)
    4. Row edits have a collection of **CellUpdates** that hold updates for individual cells (except for RowDelete)
        1. Cell updates are generated from text
     5. RowEditBase offers some baseline functionality
        1. Generation of `WHERE` clauses (which can be parameterized)
        2. Validation of whether a column can be updated
2. New API Actions
    1. edit/initialize - Queries for the contents of a table/view, builds SMO metadata, sets up a session
    2. edit/createRow - Adds a new RowCreate to the Session
    3. edit/deleteRow - Adds a new RowDelete to the Session
    4. edit/updateCell - Adds a CellUpdate to a RowCreate or RowUpdate in the Session
    5. edit/revertRow - Removes a RowCreate, RowDelete, or RowUpdate from the Session
    6. edit/script - Generates a script for the changes in the Session and stores to disk
    7. edit/dispose - Removes a Session and releases the query
3. Smaller updates (unit test mock improvements, tweaks to query execution service)

**There are more updates planned -- this is just to get eyeballs on the main body of code**

* Initial stubs for edit data service

* Stubbing out update management code

* Adding rudimentary dispose request

* More stubbing out of update row code

* Adding complete edit command contracts, stubbing out request handlers

* Adding basic implementation of get script

* More in progress work to implement base of row edits

* More in progress work to implement base of row edits

* Adding string => object conversion logic and various cleanup

* Adding a formatter for using values in scripts

* Splitting IMessageSender into IEventSender and IRequestSender

* Adding inter-service method for executing queries

* Adding inter-service method for disposing of a query

* Changing edit contract to include the object to edit

* Fully fleshing out edit session initialization

* Generation of delete scripts is working

* Adding scripter for update statements

* Adding scripting functionality for INSERT statements

* Insert, Update, and Delete all working with SMO metadata

* Polishing for SqlScriptFormatter

* Unit tests and reworked byte[] conversion

* Replacing the awful and inflexible Dictionary<string, string>[][] with a much better test data set class

* Fixing syntax error in generated UPDATE statements

* Adding unit tests for RowCreate

* Adding tests for the row edit base class

* Adding row delete tests

* Adding RowUpdate tests, validation for number of key columns

* Adding tests for the unit class

* Adding get script tests for the session

* Service integration tests, except initialization tests

* Service integration tests, except initialization tests

* Adding messages to sr.strings

* Adding messages to sr.strings

* Fixing broken unit tests

* Adding factory pattern for SMO metadata provider

* Copyright and other comments

* Addressing first round of comments

* Refactoring EditDataService to have a single method for handling
session-dependent operations
* Refactoring Edit Data contracts to inherit from a Session and Row
operation params base class
* Copyright additions
* Small tweak to strings
* Updated unit tests to test the refactors

* More revisions as per pull request comments
This commit is contained in:
Benjamin Russell
2017-02-22 17:32:57 -08:00
committed by GitHub
parent 2b15890b00
commit 795eba3da6
49 changed files with 4370 additions and 137 deletions

View File

@@ -39,4 +39,21 @@ namespace Microsoft.SqlTools.ServiceLayer.Utility
return isTrue ? "1" : "0";
}
}
internal static class NullableExtensions
{
/// <summary>
/// Extension method to evaluate a bool? and determine if it has the value and is true.
/// This way we avoid throwing if the bool? doesn't have a value.
/// </summary>
/// <param name="obj">The <c>bool?</c> to process</param>
/// <returns>
/// <c>true</c> if <paramref name="obj"/> has a value and it is <c>true</c>
/// <c>false</c> otherwise.
/// </returns>
public static bool HasTrue(this bool? obj)
{
return obj.HasValue && obj.Value;
}
}
}

View File

@@ -0,0 +1,263 @@
//
// Copyright (c) Microsoft. All rights reserved.
// Licensed under the MIT license. See LICENSE file in the project root for full license information.
//
using System;
using System.Collections.Generic;
using System.Data.Common;
using System.Globalization;
using System.Linq;
using System.Text;
using Microsoft.SqlTools.ServiceLayer.QueryExecution.Contracts;
namespace Microsoft.SqlTools.ServiceLayer.Utility
{
/// <summary>
/// Provides utility for converting arbitrary objects into strings that are ready to be
/// inserted into SQL strings
/// </summary>
public class SqlScriptFormatter
{
#region Constants
public const string NullString = "NULL";
private static readonly Dictionary<string, Func<object, DbColumn, string>> FormatFunctions =
new Dictionary<string, Func<object, DbColumn, string>>
{ // CLR Type --------
{"bigint", (val, col) => SimpleFormatter(val)}, // long
{"bit", (val, col) => FormatBool(val)}, // bool
{"int", (val, col) => SimpleFormatter(val)}, // int
{"smallint", (val, col) => SimpleFormatter(val)}, // short
{"tinyint", (val, col) => SimpleFormatter(val)}, // byte
{"money", (val, col) => FormatMoney(val, "MONEY")}, // Decimal
{"smallmoney", (val, col) => FormatMoney(val, "SMALLMONEY")}, // Decimal
{"decimal", (val, col) => FormatPreciseNumeric(val, col, "DECIMAL")}, // Decimal
{"numeric", (val, col) => FormatPreciseNumeric(val, col, "NUMERIC")}, // Decimal
{"real", (val, col) => FormatFloat(val)}, // float
{"float", (val, col) => FormatDouble(val)}, // double
{"smalldatetime", (val, col) => FormatDateTime(val, "yyyy-MM-dd HH:mm:ss")}, // DateTime
{"datetime", (val, col) => FormatDateTime(val, "yyyy-MM-dd HH:mm:ss.FFF") }, // DateTime
{"datetime2", (val, col) => FormatDateTime(val, "yyyy-MM-dd HH:mm:ss.FFFFFFF")}, // DateTime
{"date", (val, col) => FormatDateTime(val, "yyyy-MM-dd")}, // DateTime
{"datetimeoffset", (val, col) => FormatDateTimeOffset(val)}, // DateTimeOffset
{"time", (val, col) => FormatTimeSpan(val)}, // TimeSpan
{"char", (val, col) => SimpleStringFormatter(val)}, // string
{"nchar", (val, col) => SimpleStringFormatter(val)}, // string
{"varchar", (val, col) => SimpleStringFormatter(val)}, // string
{"nvarchar", (val, col) => SimpleStringFormatter(val)}, // string
{"text", (val, col) => SimpleStringFormatter(val)}, // string
{"ntext", (val, col) => SimpleStringFormatter(val)}, // string
{"xml", (val, col) => SimpleStringFormatter(val)}, // string
{"binary", (val, col) => FormatBinary(val)}, // byte[]
{"varbinary", (val, col) => FormatBinary(val)}, // byte[]
{"image", (val, col) => FormatBinary(val)}, // byte[]
{"uniqueidentifier", (val, col) => SimpleStringFormatter(val)}, // Guid
// Unsupported types:
// *.sys.hierarchyid - cannot cast byte string to hierarchyid
// geography - cannot cast byte string to geography
// geometry - cannot cast byte string to geometry
// timestamp - cannot insert/update timestamp columns
// sql_variant - casting logic isn't good enough
// sysname - it doesn't appear possible to insert a sysname column
};
#endregion
/// <summary>
/// Converts an object into a string for SQL script
/// </summary>
/// <param name="value">The object to convert</param>
/// <param name="column">The column metadata for the cell to insert</param>
/// <returns>String version of the cell value for use in SQL scripts</returns>
public static string FormatValue(object value, DbColumn column)
{
Validate.IsNotNull(nameof(column), column);
// Handle nulls firstly
if (value == null)
{
return NullString;
}
// Determine how to format based on the column type
string dataType = column.DataTypeName.ToLowerInvariant();
if (!FormatFunctions.ContainsKey(dataType))
{
// Attempt to handle UDTs
// @TODO: to constants file
throw new ArgumentOutOfRangeException(nameof(column.DataTypeName), "A converter for {column type} is not available");
}
return FormatFunctions[dataType](value, column);
}
/// <summary>
/// Converts a cell value into a string for SQL script
/// </summary>
/// <param name="value">The cell to convert</param>
/// <param name="column">The column metadata for the cell to insert</param>
/// <returns>String version of the cell value for use in SQL scripts</returns>
public static string FormatValue(DbCellValue value, DbColumn column)
{
Validate.IsNotNull(nameof(value), value);
return FormatValue(value.RawObject, column);
}
/// <summary>
/// Escapes an identifier such as a table name or column name by wrapping it in square brackets
/// </summary>
/// <param name="identifier">The identifier to format</param>
/// <returns>Identifier formatted for use in a SQL script</returns>
public static string FormatIdentifier(string identifier)
{
return $"[{EscapeString(identifier, ']')}]";
}
/// <summary>
/// Escapes a multi-part identifier such as a table name or column name with multiple
/// parts split by '.'
/// </summary>
/// <param name="identifier">The identifier to escape</param>
/// <returns>The escaped identifier</returns>
public static string FormatMultipartIdentifier(string identifier)
{
// If the object is a multi-part identifier (eg, dbo.tablename) split it, and escape as necessary
return FormatMultipartIdentifier(identifier.Split('.'));
}
/// <summary>
/// Escapes a multipart identifier such as a table name, given an array of the parts of the
/// multipart identifier.
/// </summary>
/// <param name="identifiers">The parts of the identifier to escape</param>
/// <returns>An escaped version of the multipart identifier</returns>
public static string FormatMultipartIdentifier(string[] identifiers)
{
IEnumerable<string> escapedParts = identifiers.Select(FormatIdentifier);
return string.Join(".", escapedParts);
}
#region Private Helpers
private static string SimpleFormatter(object value)
{
return value.ToString();
}
private static string SimpleStringFormatter(object value)
{
return EscapeQuotedSqlString(value.ToString());
}
private static string FormatMoney(object value, string type)
{
// we have to manually format the string by ToStringing the value first, and then converting
// the potential (European formatted) comma to a period.
string numericString = ((decimal)value).ToString(CultureInfo.InvariantCulture);
return $"CAST({numericString} AS {type})";
}
private static string FormatFloat(object value)
{
// The "R" formatting means "Round Trip", which preserves fidelity
return ((float)value).ToString("R");
}
private static string FormatDouble(object value)
{
// The "R" formatting means "Round Trip", which preserves fidelity
return ((double)value).ToString("R");
}
private static string FormatBool(object value)
{
// Attempt to cast to bool
bool boolValue = (bool)value;
return boolValue ? "1" : "0";
}
private static string FormatPreciseNumeric(object value, DbColumn column, string type)
{
// Make sure we have numeric precision and numeric scale
if (!column.NumericPrecision.HasValue || !column.NumericScale.HasValue)
{
// @TODO Move to constants
throw new InvalidOperationException("Decimal column is missing numeric precision or numeric scale");
}
// Convert the value to a decimal, then convert that to a string
string numericString = ((decimal)value).ToString(CultureInfo.InvariantCulture);
return string.Format(CultureInfo.InvariantCulture, "CAST({0} AS {1}({2}, {3}))",
numericString, type, column.NumericPrecision.Value, column.NumericScale.Value);
}
private static string FormatTimeSpan(object value)
{
// "c" provides "HH:mm:ss.FFFFFFF", and time column accepts up to 7 precision
string timeSpanString = ((TimeSpan)value).ToString("c", CultureInfo.InvariantCulture);
return EscapeQuotedSqlString(timeSpanString);
}
private static string FormatDateTime(object value, string format)
{
string dateTimeString = ((DateTime)value).ToString(format, CultureInfo.InvariantCulture);
return EscapeQuotedSqlString(dateTimeString);
}
private static string FormatDateTimeOffset(object value)
{
string dateTimeString = ((DateTimeOffset)value).ToString(CultureInfo.InvariantCulture);
return EscapeQuotedSqlString(dateTimeString);
}
private static string FormatBinary(object value)
{
byte[] bytes = value as byte[];
if (bytes == null)
{
// Bypass processing if we can't turn this into a byte[]
return "NULL";
}
return "0x" + BitConverter.ToString(bytes).Replace("-", string.Empty);
}
/// <summary>
/// Returns a valid SQL string packaged in single quotes with single quotes inside escaped
/// </summary>
/// <param name="rawString">String to be formatted</param>
/// <returns>Formatted SQL string</returns>
private static string EscapeQuotedSqlString(string rawString)
{
return $"N'{EscapeString(rawString, '\'')}'";
}
/// <summary>
/// Replaces all instances of <paramref name="escapeCharacter"/> with a duplicate of
/// <paramref name="escapeCharacter"/>. For example "can't" becomes "can''t"
/// </summary>
/// <param name="value">The string to escape</param>
/// <param name="escapeCharacter">The character to escape</param>
/// <returns>The escaped string</returns>
private static string EscapeString(string value, char escapeCharacter)
{
Validate.IsNotNull(nameof(value), value);
StringBuilder sb = new StringBuilder();
foreach (char c in value)
{
sb.Append(c);
if (escapeCharacter == c)
{
sb.Append(c);
}
}
return sb.ToString();
}
#endregion
}
}