/*
* DynamORM - Dynamic Object-Relational Mapping library.
* Copyright (c) 2012, Grzegorz Russek (grzegorz.russek@gmail.com)
* All rights reserved.
*
* Redistribution and use in source and binary forms, with or without
* modification, are permitted provided that the following conditions are met:
*
* Redistributions of source code must retain the above copyright notice,
* this list of conditions and the following disclaimer.
*
* Redistributions in binary form must reproduce the above copyright notice,
* this list of conditions and the following disclaimer in the documentation
* and/or other materials provided with the distribution.
*
* THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS"
* AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE
* IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE
* ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE
* LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR
* CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF
* SUBSTITUTE GOODS OR SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS
* INTERRUPTION) HOWEVER CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN
* CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE)
* ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN IF ADVISED OF
* THE POSSIBILITY OF SUCH DAMAGE.
*/
using System;
using System.Collections.Generic;
using System.Dynamic;
using System.Linq;
using DynamORM.Builders;
using DynamORM.Helpers;
using DynamORM.Mapper;
namespace DynamORM
{
/// Dynamic table is a simple ORM using dynamic objects.
///
/// Assume that we have a table representing Users class.
///
/// Let's take a look at Query posibilities. Assume we want
/// to get enumerator for all records in database, mapped to our class
/// instead of dynamic type we can use following syntax.
/// Approach first. Use dynamic Query method and just set type
/// then just cast it to user class. Remember that you must cast result
/// of Queryto IEnumerable<object>. because from
/// point of view of runtime you are operating on object type.
/// (db.Table<User>().Query(type: typeof(User)) as IEnumerable<object>).Cast<User>();
/// Second approach is similar. We ask database using dynamic
/// Query method. The difference is that we use extension method of
/// IEnumerable<object> (to which we must cast to) to map
/// object.
/// (db.Table<User>().Query(columns: "*") as IEnumerable<object>).MapEnumerable<User>();
/// You can also use generic approach. But be careful this method is currently avaliable thanks to framework hack.
/// (db.Table<User>().Query<User>() as IEnumerable<object>).Cast<User>()
/// Another approach uses existing methods, but still requires a
/// cast, because Query also returns dynamic object enumerator.
/// (db.Table<User>().Query().Execute() as IEnumerable<object>).MapEnumerable<User>();
///
/// Below you can find various invocations of dynamic and non dynemic
/// methods of this class. x variable is a class instance.
/// First various selects:
/// x.Count(columns: "id");
/// x.Count(last: new DynamicColumn
/// {
/// Operator = DynamicColumn.CompareOperator.In,
/// Value = new object[] { "Hendricks", "Goodwin", "Freeman" }.Take(3)
/// });
/// x.Count(last: new DynamicColumn
/// {
/// Operator = DynamicColumn.CompareOperator.In,
/// Value = new object[] { "Hendricks", "Goodwin", "Freeman" }
/// });
/// x.First(columns: "id").id;
/// x.Last(columns: "id").id;
/// x.Count(first: "Ori");
/// x.Min(columns: "id");
/// x.Max(columns: "id");
/// x.Avg(columns: "id");
/// x.Sum(columns: "id");
/// x.Scalar(columns: "first", id: 19);
/// x.Scalar(columns: "first:first:group_concat", id: new DynamicColumn { Operator = DynamicColumn.CompareOperator.Lt, Value = 20 });
/// x.Scalar(columns: "group_concat(first):first", id: new DynamicColumn { Operator = DynamicColumn.CompareOperator.Lt, Value = 20 });
/// var v = (x.Query(columns: "first,first:occurs:count", group: "first", order: ":desc:2") as IEnumerable<dynamic>).ToList();
/// x.Scalar(columns: @"length(""login""):len:avg");
/// x.Avg(columns: @"length(""email""):len");
/// x.Count(condition1:
/// new DynamicColumn()
/// {
/// ColumnName = "email",
/// Aggregate = "length",
/// Operator = DynamicColumn.CompareOperator.Gt,
/// Value = 27
/// });
/// var o = x.Single(columns: "id,first,last", id: 19);
/// x.Single(where: new DynamicColumn("id").Eq(100)).login;
/// x.Count(where: new DynamicColumn("id").Not(100));
/// x.Single(where: new DynamicColumn("login").Like("Hoyt.%")).id;
/// x.Count(where: new DynamicColumn("login").NotLike("Hoyt.%"));
/// x.Count(where: new DynamicColumn("id").Greater(100));
/// x.Count(where: new DynamicColumn("id").GreaterOrEqual(100));
/// x.Count(where: new DynamicColumn("id").Less(100));
/// x.Count(where: new DynamicColumn("id").LessOrEqual(100));
/// x.Count(where: new DynamicColumn("id").Between(75, 100));
/// x.Count(where: new DynamicColumn("id").In(75, 99, 100));
/// x.Count(where: new DynamicColumn("id").In(new[] { 75, 99, 100 }));
/// Inserts:
/// x.Insert(code: 201, first: "Juri", last: "Gagarin", email: "juri.gagarin@megacorp.com", quote: "bla, bla, bla");
/// x.Insert(values: new { code = 202, first = "Juri", last = "Gagarin", email = "juri.gagarin@megacorp.com", quote = "bla, bla, bla" });
/// x.Insert(values: new Users
/// {
/// Id = u.Max(columns: "id") + 1,
/// Code = "203",
/// First = "Juri",
/// Last = "Gagarin",
/// Email = "juri.gagarin@megacorp.com",
/// Quote = "bla, bla, bla"
/// });
/// x.Insert(values: new users
/// {
/// id = u.Max(columns: "id") + 1,
/// code = "204",
/// first = "Juri",
/// last = "Gagarin",
/// email = "juri.gagarin@megacorp.com",
/// quote = "bla, bla, bla"
/// });
/// x.Update(id: 1, code: 201, first: "Juri", last: "Gagarin", email: "juri.gagarin@megacorp.com", quote: "bla, bla, bla");
/// x.Update(update: new { id = 2, code = 202, first = "Juri", last = "Gagarin", email = "juri.gagarin@megacorp.com", quote = "bla, bla, bla" });
/// Updates:
/// x.Update(update: new Users
/// {
/// Id = 3,
/// Code = "203",
/// First = "Juri",
/// Last = "Gagarin",
/// Email = "juri.gagarin@megacorp.com",
/// Quote = "bla, bla, bla"
/// });
/// x.Update(update: new users
/// {
/// id = 4,
/// code = "204",
/// first = "Juri",
/// last = "Gagarin",
/// email = "juri.gagarin@megacorp.com",
/// quote = "bla, bla, bla"
/// });
/// x.Update(values: new { code = 205, first = "Juri", last = "Gagarin", email = "juri.gagarin@megacorp.com", quote = "bla, bla, bla" }, where: new { id = 5 });
/// x.Update(values: new Users
/// {
/// Id = 6,
/// Code = "206",
/// First = "Juri",
/// Last = "Gagarin",
/// Email = "juri.gagarin@megacorp.com",
/// Quote = "bla, bla, bla"
/// }, id: 6);
/// x.Update(values: new users
/// {
/// id = 7,
/// code = "207",
/// first = "Juri",
/// last = "Gagarin",
/// email = "juri.gagarin@megacorp.com",
/// quote = "bla, bla, bla"
/// }, id: 7);
/// Delete:
/// x.Delete(code: 10);
/// x.Delete(delete: new { id = 11, code = 11, first = "Juri", last = "Gagarin", email = "juri.gagarin@megacorp.com", quote = "bla, bla, bla" });
/// x.Delete(delete: new Users
/// {
/// Id = 12,
/// Code = "12",
/// First = "Juri",
/// Last = "Gagarin",
/// Email = "juri.gagarin@megacorp.com",
/// Quote = "bla, bla, bla"
/// });
/// x.Delete(delete: new users
/// {
/// id = 13,
/// code = "13",
/// first = "Juri",
/// last = "Gagarin",
/// email = "juri.gagarin@megacorp.com",
/// quote = "bla, bla, bla"
/// });
/// x.Delete(where: new { id = 14, code = 14 });
///
public class DynamicTable : DynamicObject, IDisposable, ICloneable
{
private static HashSet _allowedCommands = new HashSet
{
"Insert", "Update", "Delete",
"Query", "Single", "Where",
"First", "Last", "Get",
"Count", "Sum", "Avg",
"Min", "Max", "Scalar"
};
/// Gets dynamic database.
internal DynamicDatabase Database { get; private set; }
/// Gets type of table (for coning and schema building).
internal Type TableType { get; private set; }
/// Gets name of table.
public virtual string TableName { get; private set; }
/// Gets table schema.
/// If database doesn't support schema, only key columns are listed here.
public virtual Dictionary Schema { get; private set; }
private DynamicTable() { }
/// Initializes a new instance of the class.
/// Database and connection management.
/// Table name.
/// Override keys in schema.
public DynamicTable(DynamicDatabase database, string table = "", string[] keys = null)
{
Database = database;
TableName = table;
TableType = null;
BuildAndCacheSchema(keys);
}
/// Initializes a new instance of the class.
/// Database and connection management.
/// Type describing table.
/// Override keys in schema.
public DynamicTable(DynamicDatabase database, Type type, string[] keys = null)
{
if (type == null)
throw new ArgumentNullException("type", "Type can't be null.");
Database = database;
TableType = type;
var mapper = DynamicMapperCache.GetMapper(type);
if (mapper != null)
TableName = mapper.Table == null || string.IsNullOrEmpty(mapper.Table.Name) ?
type.Name : mapper.Table.Name;
BuildAndCacheSchema(keys);
}
#region Schema
private void BuildAndCacheSchema(string[] keys)
{
Dictionary schema = null;
schema = Database.GetSchema(TableType) ??
Database.GetSchema(TableName);
#region Fill currrent table schema
if (keys == null && TableType != null)
{
var mapper = DynamicMapperCache.GetMapper(TableType);
if (mapper != null)
{
var k = mapper.ColumnsMap.Where(p => p.Value.Column != null && p.Value.Column.IsKey).Select(p => p.Key);
if (k.Count() > 0)
keys = k.ToArray();
}
}
if (schema != null)
{
if (keys == null)
Schema = new Dictionary(schema);
else
{
// TODO: Make this.... nicer
List ks = keys.Select(k => k.ToLower()).ToList();
Schema = schema.ToDictionary(k => k.Key, (v) =>
{
DynamicSchemaColumn dsc = v.Value;
dsc.IsKey = ks.Contains(v.Key);
return dsc;
});
}
}
#endregion Fill currrent table schema
#region Build ad-hock schema
if (keys != null && Schema == null)
{
Schema = keys.Select(k => k.ToLower()).ToList()
.ToDictionary(k => k, k => new DynamicSchemaColumn { Name = k, IsKey = true });
}
#endregion Build ad-hock schema
}
#endregion Schema
#region Basic Queries
/// Enumerate the reader and yield the result.
/// Sql query containing numered parameters in format provided by
/// methods. Also names should be formated with
/// method.
/// Arguments (parameters).
/// Enumerator of objects expanded from query.
public virtual IEnumerable Query(string sql, params object[] args)
{
using (var con = Database.Open())
using (var cmd = con.CreateCommand())
{
using (var rdr = cmd
.SetCommand(sql)
.AddParameters(Database, args)
.ExecuteReader())
while (rdr.Read())
yield return rdr.RowToDynamic();
}
}
/// Enumerate the reader and yield the result.
/// Command builder.
/// Enumerator of objects expanded from query.
public virtual IEnumerable Query(IDynamicQueryBuilder builder)
{
using (var con = Database.Open())
using (var cmd = con.CreateCommand())
{
using (var rdr = cmd
.SetCommand(builder)
.ExecuteReader())
while (rdr.Read())
yield return rdr.RowToDynamic();
}
}
/// Create new .
/// New instance.
public virtual DynamicSelectQueryBuilder Query()
{
return new DynamicSelectQueryBuilder(this);
}
/// Returns a single result.
/// Sql query containing numered parameters in format provided by
/// methods. Also names should be formated with
/// method.
/// Arguments (parameters).
/// Result of a query.
public virtual object Scalar(string sql, params object[] args)
{
using (var con = Database.Open())
using (var cmd = con.CreateCommand())
{
return cmd
.SetCommand(sql).AddParameters(Database, args)
.ExecuteScalar();
}
}
/// Returns a single result.
/// Command builder.
/// Result of a query.
public virtual object Scalar(IDynamicQueryBuilder builder)
{
using (var con = Database.Open())
using (var cmd = con.CreateCommand())
{
return cmd
.SetCommand(builder)
.ExecuteScalar();
}
}
/// Execute non query.
/// Sql query containing numered parameters in format provided by
/// methods. Also names should be formated with
/// method.
/// Arguments (parameters).
/// Number of affected rows.
public virtual int Execute(string sql, params object[] args)
{
using (var con = Database.Open())
using (var cmd = con.CreateCommand())
{
return cmd
.SetCommand(sql).AddParameters(Database, args)
.ExecuteNonQuery();
}
}
/// Execute non query.
/// Command builder.
/// Number of affected rows.
public virtual int Execute(IDynamicQueryBuilder builder)
{
using (var con = Database.Open())
using (var cmd = con.CreateCommand())
{
return cmd
.SetCommand(builder)
.ExecuteNonQuery();
}
}
/// Execute non query.
/// Command builders.
/// Number of affected rows.
public virtual int Execute(IDynamicQueryBuilder[] builers)
{
int ret = 0;
using (var con = Database.Open())
{
using (var trans = con.BeginTransaction())
{
foreach (var builder in builers)
{
using (var cmd = con.CreateCommand())
{
ret += cmd
.SetCommand(builder)
.ExecuteNonQuery();
}
}
trans.Commit();
}
}
return ret;
}
#endregion Basic Queries
#region Insert
/// Create new .
/// New instance.
public DynamicInsertQueryBuilder Insert()
{
return new DynamicInsertQueryBuilder(this);
}
/// Adds a record to the database. You can pass in an Anonymous object, an ExpandoObject,
/// A regular old POCO, or a NameValueColletion from a Request.Form or Request.QueryString.
/// Anonymous object, an ExpandoObject, a regular old POCO, or a NameValueCollection
/// from a Request.Form or Request.QueryString, containing fields to update.
/// Number of updated rows.
public virtual int Insert(object o)
{
return Insert()
.Insert(o)
.Execute();
}
#endregion Insert
#region Update
/// Create new .
/// New instance.
public DynamicUpdateQueryBuilder Update()
{
return new DynamicUpdateQueryBuilder(this);
}
/// Updates a record in the database. You can pass in an Anonymous object, an ExpandoObject,
/// a regular old POCO, or a NameValueCollection from a Request.Form or Request.QueryString.
/// Anonymous object, an ExpandoObject, a regular old POCO, or a NameValueCollection
/// from a Request.Form or Request.QueryString, containing fields to update.
/// Anonymous object, an ExpandoObject, a regular old POCO, or a NameValueCollection
/// from a Request.Form or Request.QueryString, containing fields with conditions.
/// Number of updated rows.
public virtual int Update(object o, object key)
{
return Update()
.Values(o)
.Where(key)
.Execute();
}
/// Updates a record in the database using schema. You can pass in an Anonymous object, an ExpandoObject,
/// a regular old POCO, or a NameValueCollection from a Request.Form or Request.QueryString.
/// Anonymous object, an ExpandoObject, a regular old POCO, or a NameValueCollection
/// from a Request.Form or Request.QueryString, containing fields to update and conditions.
/// Number of updated rows.
public virtual int Update(object o)
{
return Update()
.Update(o)
.Execute();
}
#endregion Update
#region Delete
/// Create new .
/// New instance.
public DynamicDeleteQueryBuilder Delete()
{
return new DynamicDeleteQueryBuilder(this);
}
/// Removes a record from the database. You can pass in an Anonymous object, an ExpandoObject,
/// A regular old POCO, or a NameValueColletion from a Request.Form or Request.QueryString.
/// Anonymous object, an ExpandoObject, a regular old POCO, or a NameValueCollection
/// from a Request.Form or Request.QueryString, containing fields with where conditions.
/// If true use schema to determine key columns and ignore those which
/// aren't keys.
/// Number of updated rows.
public virtual int Delete(object o, bool schema = true)
{
return Delete()
.Where(o, schema)
.Execute();
}
#endregion Delete
#region Universal Dynamic Invoker
/// This is where the magic begins.
/// Binder to invoke.
/// Binder arguments.
/// Binder invoke result.
/// Returns true if invoke was performed.
public override bool TryInvokeMember(InvokeMemberBinder binder, object[] args, out object result)
{
// parse the method
var info = binder.CallInfo;
// Get generic types
var types = binder.GetGenericTypeArguments();
// accepting named args only... SKEET!
if (info.ArgumentNames.Count != args.Length)
throw new InvalidOperationException("Please use named arguments for this type of query - the column name, orderby, columns, etc");
var op = binder.Name;
// Avoid strange things
if (!_allowedCommands.Contains(op))
throw new InvalidOperationException(string.Format("Dynamic method '{0}' is not supported.", op));
switch (op)
{
case "Insert":
result = DynamicInsert(args, info, types);
break;
case "Update":
result = DynamicUpdate(args, info, types);
break;
case "Delete":
result = DynamicDelete(args, info, types);
break;
default:
result = DynamicQuery(args, info, op, types);
break;
}
return true;
}
private object DynamicInsert(object[] args, CallInfo info, IList types)
{
var builder = new DynamicInsertQueryBuilder(this);
if (types != null && types.Count == 1)
HandleTypeArgument(null, info, ref types, builder, 0);
// loop the named args - see if we have order, columns and constraints
if (info.ArgumentNames.Count > 0)
{
for (int i = 0; i < args.Length; i++)
{
var name = info.ArgumentNames[i].ToLower();
switch (name)
{
case "table":
if (args[i] is string)
builder.Table(args[i].ToString());
else goto default;
break;
case "values":
builder.Insert(args[i]);
break;
case "type":
if (types == null || types.Count == 0)
HandleTypeArgument(args, info, ref types, builder, i);
else goto default;
break;
default:
builder.Insert(name, args[i]);
break;
}
}
}
// Execute
return Execute(builder);
}
private object DynamicUpdate(object[] args, CallInfo info, IList types)
{
var builder = new DynamicUpdateQueryBuilder(this);
if (types != null && types.Count == 1)
HandleTypeArgument(null, info, ref types, builder, 0);
// loop the named args - see if we have order, columns and constraints
if (info.ArgumentNames.Count > 0)
{
for (int i = 0; i < args.Length; i++)
{
var name = info.ArgumentNames[i].ToLower();
switch (name)
{
case "table":
if (args[i] is string)
builder.Table(args[i].ToString());
else goto default;
break;
case "update":
builder.Update(args[i]);
break;
case "values":
builder.Values(args[i]);
break;
case "where":
builder.Where(args[i]);
break;
case "type":
if (types == null || types.Count == 0)
HandleTypeArgument(args, info, ref types, builder, i);
else goto default;
break;
default:
builder.Update(name, args[i]);
break;
}
}
}
// Execute
return Execute(builder);
}
private object DynamicDelete(object[] args, CallInfo info, IList types)
{
var builder = new DynamicDeleteQueryBuilder(this);
if (types != null && types.Count == 1)
HandleTypeArgument(null, info, ref types, builder, 0);
// loop the named args - see if we have order, columns and constraints
if (info.ArgumentNames.Count > 0)
{
for (int i = 0; i < args.Length; i++)
{
var name = info.ArgumentNames[i].ToLower();
switch (name)
{
case "table":
if (args[i] is string)
builder.Table(args[i].ToString());
else goto default;
break;
case "where":
builder.Where(args[i], false);
break;
case "delete":
builder.Where(args[i], true);
break;
case "type":
if (types == null || types.Count == 0)
HandleTypeArgument(args, info, ref types, builder, i);
else goto default;
break;
default:
builder.Where(name, args[i]);
break;
}
}
}
// Execute
return Execute(builder);
}
private object DynamicQuery(object[] args, CallInfo info, string op, IList types)
{
object result;
var builder = new DynamicSelectQueryBuilder(this);
if (types != null && types.Count == 1)
HandleTypeArgument(null, info, ref types, builder, 0);
// loop the named args - see if we have order, columns and constraints
if (info.ArgumentNames.Count > 0)
{
for (int i = 0; i < args.Length; i++)
{
var name = info.ArgumentNames[i].ToLower();
// TODO: Make this nicer
switch (name)
{
case "order":
if (args[i] is string)
builder.OrderBy(((string)args[i]).Split(','));
else if (args[i] is string[])
builder.OrderBy(args[i] as string);
else if (args[i] is DynamicColumn[])
builder.OrderBy((DynamicColumn[])args[i]);
else if (args[i] is DynamicColumn)
builder.OrderBy((DynamicColumn)args[i]);
else goto default;
break;
case "group":
if (args[i] is string)
builder.GroupBy(((string)args[i]).Split(','));
else if (args[i] is string[])
builder.GroupBy(args[i] as string);
else if (args[i] is DynamicColumn[])
builder.GroupBy((DynamicColumn[])args[i]);
else if (args[i] is DynamicColumn)
builder.GroupBy((DynamicColumn)args[i]);
else goto default;
break;
case "columns":
if (args[i] is string)
builder.Select(((string)args[i]).Split(','));
else if (args[i] is string[])
builder.Select(args[i] as string);
else if (args[i] is DynamicColumn[])
builder.Select((DynamicColumn[])args[i]);
else if (args[i] is DynamicColumn)
builder.Select((DynamicColumn)args[i]);
else goto default;
break;
case "where":
builder.Where(args[i]);
break;
case "table":
if (args[i] is string)
builder.Table(args[i].ToString());
else goto default;
break;
case "type":
if (types == null || types.Count == 0)
HandleTypeArgument(args, info, ref types, builder, i);
else goto default;
break;
default:
builder.Where(name, args[i]);
break;
}
}
}
if (op == "Count" && builder.Columns.Count == 0)
{
result = Scalar(builder.Select(new DynamicColumn
{
ColumnName = "*",
Aggregate = op.ToUpper(),
Alias = "Count"
}));
if (result is long)
result = (int)(long)result;
}
else if (op == "Sum" || op == "Max" ||
op == "Min" || op == "Avg" || op == "Count")
{
if (builder.Columns.Count == 0)
throw new InvalidOperationException("You must select at least one column to agregate.");
foreach (var o in builder.Columns)
o.Aggregate = op.ToUpper();
if (builder.Columns.Count == 1)
{
result = Scalar(builder);
if (op == "Count" && result is long)
result = (int)(long)result;
}
else
{
result = Query(builder).FirstOrDefault(); // return lots
}
}
else
{
// build the SQL
var justOne = op == "First" || op == "Last" || op == "Get" || op == "Single";
// Be sure to sort by DESC on selected columns
if (op == "Last")
{
if (builder.Order.Count > 0)
foreach (var o in builder.Order)
o.Order = o.Order == DynamicColumn.SortOrder.Desc ?
DynamicColumn.SortOrder.Asc : DynamicColumn.SortOrder.Desc;
}
if (justOne && !(op == "Last" && builder.Order.Count == 0))
{
if ((Database.Options & DynamicDatabaseOptions.SupportLimitOffset) == DynamicDatabaseOptions.SupportLimitOffset)
builder.Limit(1);
else if ((Database.Options & DynamicDatabaseOptions.SupportTop) == DynamicDatabaseOptions.SupportTop)
builder.Top(1);
}
if (op == "Scalar")
{
if (builder.Columns.Count != 1)
throw new InvalidOperationException("You must select one column in scalar steatement.");
result = Scalar(builder);
}
else
{
if (justOne)
{
if (op == "Last" && builder.Order.Count == 0)
result = Query(builder).LastOrDefault(); // Last record fallback
else
result = Query(builder).FirstOrDefault(); // return a single record
}
else
result = Query(builder); // return lots
// MapEnumerable to specified result (still needs to be casted after that)
if (types != null)
{
if (types.Count == 1)
result = justOne ?
result.Map(types[0]) :
((IEnumerable