Open Lyra1337 opened 6 months ago
We currently still map the CLR type TimeSpan
to the MySQL type time
. But since time
only supports a range from -838:59:59
to 838:59:59
, it is not a good fit for representing a TimeSpan
(the CLR type TimeOnly
matches quite well though).
There is no good type in MySQL to represent a TimeSpan
at the moment, so we are likely going to map TimeSpan
to a bigint
for the 9.0
release, that then represents ticks.
Currently, we only translate TimeSpan.Hours
, TimeSpan.Minutes
, TimeSpan.Seconds
and TimeSpan.Milliseconds
(the same as the other major EF Core providers do).
So you could use context.Test.Sum(x => x.Time.Hours)
or context.Test.Sum(x => (x.Time.Hours * 60 * 60 * 1_000 + x.Time.Minutes * 60 * 1_000 + x.Time.Seconds * 1_000 + x.Time.Milliseconds) / 1_000.0 / 60.0 / 60.0)
.
If you want to add a custom implementation/mapping of TIME_TO_SEC
to your app instead, I can provide you with some code if you want.
@lauxjpn Interesting you are planning on changing the TimeSpan
mapping to bigint
. We have the same problem with the mapping in SQL Server, and it may be that bigint
is better, but it would be a break for existing Code First models. We're wondering if we should do the same thing, but concerned about the break. Any thoughts?
/cc @roji
@ajcvickers Pomelo has existing facilities in place to let users customize some type mappings (e.g. MySqlDefaultDataTypeMappings), so users can do something like .UseMySql([...], o => o.DefaultDataTypeMappings(m => m.WithClrTimeSpan(MySqlTimeSpanType.Time6)))
.
We would then add MySqlTimeSpanType.BigInt
, internally resolve MySqlTimeSpanType.Default
to it and implement the TimeSpan
-> bigint
support in addition to the already existing TimeSpan
mapping variants, so users can still choose to keep the old behavior if they want to.
When it comes to scaffolding, we have existing pseudo connection string parameters that only work at design time to customize the scaffolding process (we implemented theses before there was official support to pass parameters to providers at design time). So we could add another one for letting users switch between scaffolding time
to TimeOnly
or TimeSpan
(though I believe we already made time
-> TimeOnly
the default).
For migrations, users will suddenly be confronted with operations that change the column type out of the blue, so we should probably output a warning about it and how to keep the old mapping. We should/could also emit a data update operation to migrate the existing data over from time
-> bigint
(and then should probably support bigint
-> time
as well, though this could loose precision and should warn about it). I am not sure yet, if we want to just migrate the data by default, or if we want to add the data migration code with some explanation and throw to force users to manually confirm the change.
I think that's about the gist of it. What do you think?
@lauxjpn
If you want to add a custom implementation/mapping of
TIME_TO_SEC
to your app instead, I can provide you with some code if you want.
That would be great for the mean time.
I'd also love to contribute an implementation for this function or the translation of TimeSpan.Total* to the Pomelo code itself so others can also use this.
When it comes to scaffolding, we have existing pseudo connection string parameters that only work at design time to customize the scaffolding process (we implemented theses before there was official support to pass parameters to providers at design time). So we could add another one for letting users switch between scaffolding
time
toTimeOnly
orTimeSpan
(though I believe we already madetime
->TimeOnly
the default).For migrations, users will suddenly be confronted with operations that change the column type out of the blue, so we should probably output a warning about it and how to keep the old mapping. We should/could also emit a data update operation to migrate the existing data over from
time
->bigint
(and then should probably supportbigint
->time
as well, though this could loose precision and should warn about it). I am not sure yet, if we want to just migrate the data by default, or if we want to add the data migration code with some explanation and throw to force users to manually confirm the change.I think that's about the gist of it. What do you think?
I had this exact problem in the first place when migrating from .NET 6 to .NET 8. The scope was a legacy application with didn't use EF Core migrations. When upgrading to .NET 8 I switched to using migrations and the first step I took was to re-scaffold the entire database, so i have the correct current state of it when starting with EF migrations.
But then I had to migrate all my repositories to use TimeOnly and DateOnly and convert them back to TimeSpan / DateTime in the business layer. If there had been a switch to change the scaffolding process, it would had saved me many hours refactoring my app.
I'd also love to contribute an implementation for this function [...] to the Pomelo code itself so others can also use this.
Feel free to push a PR for it.
(Also, we are usually fine with backporting simple EF.Functions
implementations. So even if it is being implemented for 9.0
, we might backport it to 8.0
.)
I'd also love to contribute an implementation for [...] **the translation of TimeSpan.Total*** to the Pomelo code itself so others can also use this.
That doesn't currently make too much sense because of:
There is no good type in MySQL to represent a
TimeSpan
at the moment, so we are likely going to mapTimeSpan
to abigint
for the9.0
release, that then represents ticks.
I outlined the process of properly implementing this above in https://github.com/PomeloFoundation/Pomelo.EntityFrameworkCore.MySql/issues/1910#issuecomment-2068742564, that involves quite a bit and which we are likely to implement for the 9.0
release (but which will not be backported).
But then I had to migrate all my repositories to use TimeOnly and DateOnly and convert them back to TimeSpan / DateTime in the business layer. If there had been a switch to change the scaffolding process, it would had saved me many hours refactoring my app.
You should be able to scaffold the database (which would then generate TimeOnly
values for time(n)
columns) and just find/replace all occurrences of TimeOnly
with TimeSpan
in the generated model (same for DateOnly
).
This should work fine for most scaffolding scenarios.
However, if you want to control or override the scaffolding process in any way possible, you can do so as well. I posted some sample code in https://github.com/PomeloFoundation/Pomelo.EntityFrameworkCore.MySql/issues/1584#issuecomment-990967123 to demonstrate this.
(The code is a bit older. Nowadays, the CustomMySqlDesignTimeServices
class can just directly inherit from MySqlDesignTimeServices
, because MySqlDesignTimeServices.ConfigureDesignTimeServices()
is now virtual
, so you can directly override it to add your custom services.)
If you want to add a custom implementation/mapping of
TIME_TO_SEC
to your app instead, I can provide you with some code if you want.That would be great for the mean time.
Here is a sample console app, that demonstrates how to translate a custom EF.Functions
extension method to a SQL function:
I think that's about the gist of it. What do you think?
Sounds like a plan! Let's see how it goes.
@lauxjpn Thank you so much for your work. I finally found time to wrap my head around your code. It works flawless in my setup.
Your code sparked the idea to look deeper into how Pomelo handles the SQL translation and I loved what I saw and couldn't stop adding a translation for the TimeSpan.Total* properties. (#1917)
I added another virtual mapping for TimeToHour to avoid additional arithmetics in the queries:
public class CustomTimeToHourMethodCallTranslator : IMethodCallTranslator
{
private static readonly MethodInfo TimeToHourMethodInfo = typeof(CustomMySqlDbFunctionsExtensions)
.GetRuntimeMethod(
nameof(CustomMySqlDbFunctionsExtensions.TimeToHour),
[typeof(DbFunctions), typeof(TimeSpan)]);
private readonly MySqlSqlExpressionFactory sqlExpressionFactory;
private readonly IRelationalTypeMappingSource typeMappingSource;
public CustomTimeToHourMethodCallTranslator(
MySqlSqlExpressionFactory sqlExpressionFactory,
IRelationalTypeMappingSource typeMappingSource)
{
this.sqlExpressionFactory = sqlExpressionFactory;
this.typeMappingSource = typeMappingSource;
}
public SqlExpression Translate(
SqlExpression instance,
MethodInfo method,
IReadOnlyList<SqlExpression> arguments,
IDiagnosticsLogger<DbLoggerCategory.Query> logger)
{
if (method == TimeToHourMethodInfo)
{
var timeToSecExpression = this.sqlExpressionFactory.NullableFunction(
name: "TIME_TO_SEC",
arguments: new[] { arguments[1] },
returnType: typeof(int),
typeMapping: this.typeMappingSource.FindMapping(typeof(int))
);
var divideBy3600Expression = this.sqlExpressionFactory.Divide(timeToSecExpression, this.sqlExpressionFactory.Constant(3600d, this.typeMappingSource.FindMapping(typeof(double))));
return divideBy3600Expression;
}
else
{
return null;
}
}
}
public static class CustomMySqlDbFunctionsExtensions
{
public static int TimeToSec(this DbFunctions _, TimeSpan time)
=> throw new InvalidOperationException(CoreStrings.FunctionOnClient(nameof(TimeToSec)));
public static int TimeToHour(this DbFunctions _, TimeSpan time)
=> throw new InvalidOperationException(CoreStrings.FunctionOnClient(nameof(TimeToHour)));
}
public class CustomMethodCallTranslatorPlugin : IMethodCallTranslatorPlugin
{
public IEnumerable<IMethodCallTranslator> Translators { get; }
public CustomMethodCallTranslatorPlugin(
IRelationalTypeMappingSource typeMappingSource,
ISqlExpressionFactory sqlExpressionFactory)
{
var mySqlSqlExpressionFactory = (MySqlSqlExpressionFactory)sqlExpressionFactory;
this.Translators = new IMethodCallTranslator[]
{
new CustomTimeToSecMethodCallTranslator(mySqlSqlExpressionFactory, typeMappingSource),
new CustomTimeToHourMethodCallTranslator(mySqlSqlExpressionFactory, typeMappingSource),
};
}
}
Steps to reproduce
context.Test.Sum(x => x.Time.TotalHours)
neither works:
context.Test.Sum(x => EF.Functions.DateDiffMinute(x.Time.TotalHours, TimeSpan.Zero) / 60d)
The issue
Further technical details
Operating system: Windows / Linux Pomelo.EntityFrameworkCore.MySql version: 8.0.0 Microsoft.AspNetCore.App version: 8.0.200
So, it's dear to me that
TotalHours
can't be mapped. Is there an other way to sum up all time valued-rows? Can I add the functionTIME_TO_SEC
to the EF Functions to call it an then divide by 3600 to get the hours?Any help will be appreciated.
Thank you in advance.