-
Notifications
You must be signed in to change notification settings - Fork 3.2k
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Support sequence key generation on SQL Server, which is useful for Table-per-concrete-type (TPC) mappings #28096
Comments
@Ogglas It's generally quite hard to use generated key values with TPC. This is because each entity (row) needs to have a unique value across all tables. So if values 1 and 2 are used for I suspect you can use a database sequence for this, making sure that all tables get their values from the same sequence. I will discuss this with the team. |
Notes from triage:
|
Note also it is easy to configure this manually. Just define a sequence using the modelBuilder.HasSequence<int>("AnimalIds");
modelBuilder.Entity<Animal>()
.UseTpcMappingStrategy()
.Property(e => e.Id).HasDefaultValueSql("NEXT VALUE FOR [AnimalIds]"); Runnable example: public static class Your
{
public static string ConnectionString = @"Data Source=(LocalDb)\MSSQLLocalDB;Database=SixOh";
}
public abstract class Animal
{
public int Id { get; set; }
public string Species { get; set; }
}
public class Pet : Animal
{
public string Name { get; set; }
public ICollection<Human> Humans { get; } = new List<Human>();
}
public class Cat : Pet
{
public string Breed { get; set; }
}
public class Dog : Pet
{
public string Breed { get; set; }
}
public class Human : Animal
{
public string FirstName { get; set; }
public string LastName { get; set; }
public ICollection<Pet> Pets { get; } = new List<Pet>();
}
public class FarmAnimal : Animal
{
public Human Farmer { get; set; }
public decimal Value { get; set; }
}
public class SomeDbContext : DbContext
{
protected override void OnConfiguring(DbContextOptionsBuilder optionsBuilder)
=> optionsBuilder
.UseSqlServer(Your.ConnectionString)
.LogTo(Console.WriteLine, LogLevel.Information)
.EnableSensitiveDataLogging();
public DbSet<Animal> Animals { get; set; }
protected override void OnModelCreating(ModelBuilder modelBuilder)
{
modelBuilder.HasSequence<int>("AnimalIds");
modelBuilder.Entity<Animal>()
.UseTpcMappingStrategy()
.Property(e => e.Id).HasDefaultValueSql("NEXT VALUE FOR [AnimalIds]");
modelBuilder.Entity<Pet>();
modelBuilder.Entity<Cat>();
modelBuilder.Entity<Dog>();
modelBuilder.Entity<Human>();
modelBuilder.Entity<FarmAnimal>();
}
}
public class Program
{
public static void Main()
{
using (var context = new SomeDbContext())
{
context.Database.EnsureDeleted();
context.Database.EnsureCreated();
var arthur = new Human {FirstName = "Arthur", LastName = "Vickers", Species = "Pongo pygmaeus"};
var wendy = new Human {FirstName = "Wendy", LastName = "Vickers", Species = "Homo sapiens"};
var johnThePost = new Human {FirstName = "John", LastName = "The Post", Species = "Homo Scottish"};
context.AddRange(
new Cat {Name = "Alice", Species = "Felis catus", Humans = { arthur, wendy }},
new Cat {Name = "Mac", Species = "Felis catus", Humans = { arthur, wendy }},
new Dog {Name = "Toast", Species = "Canis familiaris", Humans = { arthur, wendy }},
new FarmAnimal {Value = 100.0m, Species = "Ovis aries", Farmer = johnThePost});
context.SaveChanges();
}
using (var context = new SomeDbContext())
{
foreach (var animal in context.Animals)
{
Console.WriteLine($"{animal.Id}: {animal.Species}");
}
}
}
} Output:
|
Design decision: we'll do this by default, but as a provider-specific feature rather than as a relational one (note that SQLite doesn't support sequences). However, if it makes sense we may introduce a reusable convention into relational which can then be opted-into by different providers. |
When implementing, pay attention to what happens when the table is renamed (do we rename the associated sequence etc.) |
Part of #28096 This PR adds the new key generation strategy. A second PR will change what happens by convention on SQL Server.
Part of #28096 This PR adds the new key generation strategy. A second PR will change what happens by convention on SQL Server.
Part of #28096 This PR adds the new key generation strategy. A second PR will change what happens by convention on SQL Server.
Part of #28096 This PR adds the new key generation strategy. A second PR will change what happens by convention on SQL Server.
Fixes #28096 Default for relational providers is `Never` Warning is generated by default for relational providers if `OnAdd` is set SQL Server sets the default to `OnAdd` with the `Sequence` strategy
As far as I understand when using TPC they are 2 ways to store primary keys:
I wonder what are consequences of using the approach with sequence. Are there any differences between Microsoft shows the example of key generation: modelBuilder.Entity<Cat>().ToTable("Cats", tb => tb.Property(e => e.Id).UseIdentityColumn(1, 4));
modelBuilder.Entity<Dog>().ToTable("Dogs", tb => tb.Property(e => e.Id).UseIdentityColumn(2, 4));
modelBuilder.Entity<FarmAnimal>().ToTable("FarmAnimals", tb => tb.Property(e => e.Id).UseIdentityColumn(3, 4));
modelBuilder.Entity<Human>().ToTable("Humans", tb => tb.Property(e => e.Id).UseIdentityColumn(4, 4)); So if I add or remove types from TPC hierarchy will it break the key generation or is the sequence not affected? I would be grateful if somebody gave me answers |
The example code you show does not use a sequence. Instead, it shows a different mechanism using identity columns. It's not recommended, but is an alternative if, for some reason, you don't want to use the sequence.
The sequence approach, which is the default for integer key properties and doesn't require any additional model configuration, is fine, and there really isn't any reason to use GUIDs because to avoid it. |
Now I am sure that I can use either sequences or identity columns as shown in Microsoft example, thank you for your answer. |
You mean TPC right? All entity types in a hierarchy must have distinct key (ID) values; if you happen to have the same key value across two tables participating in a hierarchy, EF will not be able to function correctly (it cannot track the two instances as they have the same key). As long as you make sure that you never have two rows with the same key across all your TPC tables, EF doesn't care which mechanism you use to achieve that (sequence or other). The easiest way to do that is to simply have a single sequence for the multiple tables - that automatically ensures key uniqueness without lots of complexity. However, you could have two identity columns - for Blog and ArchiveBlog - and make sure the values never overlap (e.g. start the ArchiveBlog identity at some very high value). However, is there a particular reason why you're trying to avoid having a sequence? |
Hi @roji In our case, we want to copy rows from the Blog table to the ArchivedBlog table with original values from the Blog table. So we don't need to generate and increment the SequenceNumber value in ArchivedBlog, it is just a value from the Blog table. However, in the base Blog class, we need to have SequenceNumber as SqlServer.Identity(1,1). |
@StakhurA if you can guarantee that the only rows in ArchiveBlog are copied across from Blog (and that these rows are deleted from Blog), then that indeed takes care of ID uniqueness. At that point you can indeed just use a regular identity column in Blog, and not have database-generated keys at all in ArchiveBlog (since you'll always be inserting the ID with the values copied from Blog). |
@roji yes, that was my intention to use a regular identity column (SequenceNumber) in Blog entity, and configure the SequenceNumber column in ArchivedBlog so that it should not be a database-generated. |
@StakhurA can you please open a new issue with a minimal, runnable code sample that shows the problem? |
Hi everyone, |
File a bug
Using:
.NET SDK 7.0.100-preview.4
https://dotnet.microsoft.com/en-us/download/dotnet/7.0
Visual Studio 2022 Preview 17.3
https://visualstudio.microsoft.com/vs/preview/
NuGet
Microsoft.EntityFrameworkCore 7.0.0-preview.4.22229.2
Code example:
ApplicationDbContext:
Migration will look like this:
Note that
RssBlog
is missing.Annotation("SqlServer:Identity", "1, 1")
.You will probably get a warning that looks like this:
I could not get it to work with either setting
modelBuilder.Entity<RssBlog>().Property(u => u.BlogId).UseIdentityColumn();
or using annotation[DatabaseGenerated(DatabaseGeneratedOption.Identity)]
.Include provider and version information
EF Core version: Microsoft.EntityFrameworkCore 7.0.0-preview.4.22229.2
Database provider: Microsoft.EntityFrameworkCore.SqlServer
Target framework: .NET 7
Operating system: Windows 10
IDE: Visual Studio 2022 Preview 17.3
The text was updated successfully, but these errors were encountered: