Skip to content
This repository has been archived by the owner on Nov 1, 2018. It is now read-only.

Initial implementation for DBConnection.GetSchema(String) #443 #449

Closed
wants to merge 9 commits into from
157 changes: 157 additions & 0 deletions src/Microsoft.Data.Sqlite.Core/SqliteConnection.cs
Original file line number Diff line number Diff line change
Expand Up @@ -556,5 +556,162 @@ public AggregateContext(T seed)
public T Accumulate { get; set; }
public Exception Exception { get; set; }
}

/// <summary>
/// System.Data.Common, initial implementation of API DBConnection.GetSchema(String)
/// Returns schema information for the data source of this DbConnection using the specified string for the schema name.
/// </summary>
/// <param name="collectionName">Specifies the name of the schema to return.</param>
/// <returns>A DataTable that contains schema information.</returns>
public override System.Data.DataTable GetSchema(string collectionName)
{
return GetSchema(collectionName, null);
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I suppose we should also add:

public override DataTable GetSchema()
    => GetSchema(DbMetaDataCollectionNames.MetaDataCollections, null);

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

done

}

/// <summary>
/// System.Data.Common, initial implementation of API DBConnection.GetSchema(String)
/// Returns schema information for the data source of this DbConnection using the specified string for the schema name.
/// </summary>
/// <param name="collectionName">Specifies the name of the schema to return.</param>
/// <param name="restrictions">Restrictions not supported yet.</param>
/// <returns>A DataTable that contains schema information.</returns>
public override System.Data.DataTable GetSchema(string collectionName, string[] restrictions)
{
var dt = new DataTable(collectionName);
switch (collectionName)
{
case "MetaDataCollections":
dt.Columns.AddRange(new[] {
new DataColumn("CollectionName", typeof(string)),
new DataColumn("NumberOfRestrictions", typeof(int)),
new DataColumn("NumberOfIdentifierParts", typeof(int))
});
dt.Rows.Add("MetaDataCollections", 0, 0);
dt.Rows.Add("DataTypes", 0, 0);
dt.Rows.Add("Tables", 0, 0);
dt.Rows.Add("ForeignKeys", 0, 0);
return dt;

case "DataTypes":
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Use DbMetaDataCollectionNames.DataTypes

dt.Columns.AddRange(new[] {
new DataColumn(DbMetaDataColumnNames.DataType, typeof(string)),
new DataColumn(DbMetaDataColumnNames.TypeName, typeof(string)),
new DataColumn(DbMetaDataColumnNames.ProviderDbType, typeof(int))
});
dt.Rows.Add(new object[] { "System.Int16", "smallint", 10 });
dt.Rows.Add(new object[] { "System.Int32","int",11 });
dt.Rows.Add(new object[] { "System.Double","real",8 });
dt.Rows.Add(new object[] { "System.Single","single",15 });
dt.Rows.Add(new object[] { "System.Double","float",8 });
dt.Rows.Add(new object[] { "System.Double","double",8 });
dt.Rows.Add(new object[] { "System.Decimal","money",7 });
dt.Rows.Add(new object[] { "System.Decimal","currency",7 });
dt.Rows.Add(new object[] { "System.Decimal","decimal",7 });
dt.Rows.Add(new object[] { "System.Decimal","numeric",7 });
dt.Rows.Add(new object[] { "System.Boolean","bit",3 });
dt.Rows.Add(new object[] { "System.Boolean","yesno",3 });
dt.Rows.Add(new object[] { "System.Boolean","logical",3 });
dt.Rows.Add(new object[] { "System.Boolean","bool",3 });
dt.Rows.Add(new object[] { "System.Boolean","boolean",3 });
dt.Rows.Add(new object[] { "System.Byte","tinyint",2 });
dt.Rows.Add(new object[] { "System.Int64","integer",12 });
dt.Rows.Add(new object[] { "System.Int64","counter",12 });
dt.Rows.Add(new object[] { "System.Int64","autoincrement",12 });
dt.Rows.Add(new object[] { "System.Int64","identity",12 });
dt.Rows.Add(new object[] { "System.Int64","long",12 });
dt.Rows.Add(new object[] { "System.Int64","bigint",12 });
dt.Rows.Add(new object[] { "System.Byte[]","binary",1 });
dt.Rows.Add(new object[] { "System.Byte[]","varbinary",1 });
dt.Rows.Add(new object[] { "System.Byte[]","blob",1 });
dt.Rows.Add(new object[] { "System.Byte[]","image",1 });
dt.Rows.Add(new object[] { "System.Byte[]","general",1 });
dt.Rows.Add(new object[] { "System.Byte[]","oleobject",1 });
dt.Rows.Add(new object[] { "System.String","varchar",16 });
dt.Rows.Add(new object[] { "System.String","nvarchar",16 });
dt.Rows.Add(new object[] { "System.String","memo",16 });
dt.Rows.Add(new object[] { "System.String","longtext",16 });
dt.Rows.Add(new object[] { "System.String","note",16 });
dt.Rows.Add(new object[] { "System.String","text",16 });
dt.Rows.Add(new object[] { "System.String","ntext",16 });
dt.Rows.Add(new object[] { "System.String","string",16 });
dt.Rows.Add(new object[] { "System.String","char",16 });
dt.Rows.Add(new object[] { "System.String","nchar",16 });
dt.Rows.Add(new object[] { "System.DateTime","datetime",6 });
dt.Rows.Add(new object[] { "System.DateTime","smalldate",6 });
dt.Rows.Add(new object[] { "System.DateTime","timestamp",6 });
dt.Rows.Add(new object[] { "System.DateTime","date",6 });
dt.Rows.Add(new object[] { "System.DateTime","time",6 });
dt.Rows.Add(new object[] { "System.Guid","uniqueidentifier",4 });
dt.Rows.Add(new object[] { "System.Guid","guid",4 });
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

We need to refine this information before merging.

Copy link
Author

@Thorium Thorium Oct 24, 2017

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The information here describes what types of .NET can be mapped to types that will be understood by the database driver, and the corresponding System.Data.Common DbTypes. This information is taken from the System.Data.SQLite.dll library.

I think this is more of a design decision. Do you want to continue from here?
I'm already happy with the current implementation but feel free to change what ever you need.

return dt;
case "Tables":
dt.Columns.AddRange(new[] {
new DataColumn("TABLE_TYPE"),
new DataColumn("TABLE_CATALOG"),
new DataColumn("TABLE_NAME")
});
var typesQuery = "SELECT type as TABLE_TYPE, 'main' as TABLE_CATALOG, name as TABLE_NAME FROM sqlite_master WHERE type='table';";
if(this.State != ConnectionState.Open)
{
this.Open();
}
using (var com = new SqliteCommand(typesQuery, this))
using(var reader = com.ExecuteReader())
{
while (reader.Read()) {
dt.Rows.Add(new object[] { reader.GetString(0), reader.GetString(1), reader.GetString(2) });
}
}
return dt;
case "ForeignKeys":
var tableQuery = "SELECT name as TABLE_NAME FROM sqlite_master WHERE type='table';";
var tables = new List<string>();

if (this.State != ConnectionState.Open)
{
this.Open();
}

using (var com = new SqliteCommand(tableQuery, this))
using (var reader = com.ExecuteReader())
{
while (reader.Read())
{
tables.Add(reader.GetString(0));
}
}
dt.Columns.AddRange(new[] {
new DataColumn("TABLE_NAME"),
new DataColumn("FKEY_TO_CATALOG"),
new DataColumn("TABLE_CATALOG"),
new DataColumn("FKEY_TO_TABLE"),
new DataColumn("FKEY_FROM_COLUMN"),
new DataColumn("FKEY_TO_COLUMN"),
new DataColumn("CONSTRAINT_NAME")
});
foreach(var tablename in tables){
var relationQuery = "pragma foreign_key_list(" + tablename + ")";
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Can combine this and the previous query using this syntax:

SELECT t.name,
       fk.table,
       fk.from,
       fk.to
FROM sqlite_master t,
     pragma_foreign_key_list(t.name) fk
WHERE t.type = 'table'

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Nice idea, however DB Browser for SQLite doesn't support that, so I don't know how widely that is supported.

using (var com = new SqliteCommand(relationQuery, this))
using (var reader = com.ExecuteReader())
{
while (reader.Read())
{
dt.Rows.Add(new object[] {
tablename,
"main",
"main",
reader.GetString(2),
reader.GetString(3),
reader.GetString(4),
"fk_" + tablename + reader.GetString(0)
});
}
}
}
return dt;
default:
throw new NotImplementedException("Not yet supported: GetSchema(\"" + collectionName + "\"). We do accept PRs.");
}
}
}
}
31 changes: 31 additions & 0 deletions test/Microsoft.Data.Sqlite.Tests/SqliteConnectionTest.cs
Original file line number Diff line number Diff line change
Expand Up @@ -890,5 +890,36 @@ public void DataChange_event_works()
Assert.Equal(101, list[0].RowId);
}
}

[Fact]
public void GetSchema_has_collections()
{
var connectionString = "Data Source=:memory:";

var connection = new SqliteConnection(connectionString);

var collections = connection.GetSchema("MetaDataCollections", new string[] { });
Assert.Equal("CollectionName", collections.Columns[0].ColumnName);
Assert.True(collections.Rows != null);
var crow1 = String.Join(",", collections.Rows[0].ItemArray);
Assert.Equal("MetaDataCollections,0,0", crow1);

var dataTypes = connection.GetSchema("DataTypes");
Assert.Equal("DataType", dataTypes.Columns[0].ColumnName);
Assert.True(dataTypes.Rows != null);
Assert.True(dataTypes.Rows.Count > 15);
var drow1 = String.Join(",", dataTypes.Rows[0].ItemArray);
Assert.Equal("System.Int16,smallint,10", drow1);

var tables = connection.GetSchema("Tables");
Assert.Equal("TABLE_TYPE", tables.Columns[0].ColumnName);
Assert.True(tables.Rows != null);

var fkKeys = connection.GetSchema("ForeignKeys");
Assert.Equal("TABLE_NAME", fkKeys.Columns[0].ColumnName);
Assert.True(fkKeys.Rows!=null);

}

}
}