diff --git a/EfCoreSamples.sln b/EfCoreSamples.sln index 1c2b9de..48253cf 100644 --- a/EfCoreSamples.sln +++ b/EfCoreSamples.sln @@ -64,6 +64,8 @@ Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "EnhancedJsonColumns", "Enha EndProject Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "EnhancedBulkUpdateAndDelete", "EnhancedBulkUpdateAndDelete\EnhancedBulkUpdateAndDelete.csproj", "{89031EE1-2782-404B-B06E-FCFEE98BAC1F}" EndProject +Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "HierarchyIds", "HierarchyIds\HierarchyIds.csproj", "{B18EB327-BF8D-4D61-B9F1-8392A9678F55}" +EndProject Global GlobalSection(SolutionConfigurationPlatforms) = preSolution Debug|Any CPU = Debug|Any CPU @@ -182,6 +184,10 @@ Global {89031EE1-2782-404B-B06E-FCFEE98BAC1F}.Debug|Any CPU.Build.0 = Debug|Any CPU {89031EE1-2782-404B-B06E-FCFEE98BAC1F}.Release|Any CPU.ActiveCfg = Release|Any CPU {89031EE1-2782-404B-B06E-FCFEE98BAC1F}.Release|Any CPU.Build.0 = Release|Any CPU + {B18EB327-BF8D-4D61-B9F1-8392A9678F55}.Debug|Any CPU.ActiveCfg = Debug|Any CPU + {B18EB327-BF8D-4D61-B9F1-8392A9678F55}.Debug|Any CPU.Build.0 = Debug|Any CPU + {B18EB327-BF8D-4D61-B9F1-8392A9678F55}.Release|Any CPU.ActiveCfg = Release|Any CPU + {B18EB327-BF8D-4D61-B9F1-8392A9678F55}.Release|Any CPU.Build.0 = Release|Any CPU EndGlobalSection GlobalSection(SolutionProperties) = preSolution HideSolutionNode = FALSE diff --git a/HierarchyIds/ApplicationDbContext.cs b/HierarchyIds/ApplicationDbContext.cs new file mode 100644 index 0000000..a61618e --- /dev/null +++ b/HierarchyIds/ApplicationDbContext.cs @@ -0,0 +1,19 @@ +using Common; +using Microsoft.EntityFrameworkCore; + +namespace HierarchyIds; + +public class ApplicationDbContext : DbContext +{ + public DbSet Employees => Set(); + + protected override void OnConfiguring(DbContextOptionsBuilder optionsBuilder) + { + optionsBuilder + .UseSqlServer(DbConnectionFactory.Create("HierarchyIds"), builder => builder.UseHierarchyId()); + } + + protected override void OnModelCreating(ModelBuilder modelBuilder) + { + } +} \ No newline at end of file diff --git a/HierarchyIds/Employee.cs b/HierarchyIds/Employee.cs new file mode 100644 index 0000000..d9633e7 --- /dev/null +++ b/HierarchyIds/Employee.cs @@ -0,0 +1,15 @@ +using Microsoft.EntityFrameworkCore; + +namespace HierarchyIds; + +public class Employee +{ + public int Id { get; private set; } + public required HierarchyId Path { get; init; } + public required string Name { get; init; } + + public override string ToString() + { + return $"Id: {Id}, Name: {Name}, Path: {Path}"; + } +} \ No newline at end of file diff --git a/HierarchyIds/HierarchyIds.csproj b/HierarchyIds/HierarchyIds.csproj new file mode 100644 index 0000000..30d78d7 --- /dev/null +++ b/HierarchyIds/HierarchyIds.csproj @@ -0,0 +1,14 @@ + + + + Exe + net8.0 + enable + enable + + + + + + + diff --git a/HierarchyIds/Program.cs b/HierarchyIds/Program.cs new file mode 100644 index 0000000..b1a11c8 --- /dev/null +++ b/HierarchyIds/Program.cs @@ -0,0 +1,54 @@ +using HierarchyIds; +using Microsoft.EntityFrameworkCore; + +Console.WriteLine("Hierarchy IDs Sample"); + +using var db = new ApplicationDbContext(); +db.Database.EnsureDeleted(); +db.Database.EnsureCreated(); + +var employees = new List +{ + new() { Name = "CEO", Path = HierarchyId.Parse("/")}, + new() { Name = "Product Manager", Path = HierarchyId.Parse("/1/")}, + new() { Name = "Tech Lead", Path = HierarchyId.Parse("/1/1/")}, + new() { Name = "Senior Dev", Path = HierarchyId.Parse("/1/1/1/")}, + new() { Name = "Junior Dev", Path = HierarchyId.Parse("/1/1/2/")}, + new() { Name = "Intern", Path = HierarchyId.Parse("/1/1/3/")}, +}; + +db.Employees.AddRange(employees); +db.SaveChanges(); + +var techLead = db.Employees.First(e => e.Path == HierarchyId.Parse("/1/1/")); + +// Get tech lead subordinates +var techLeadSubordinates = db.Employees + .AsNoTracking() + .Where(e => e.Path.IsDescendantOf(techLead.Path)) + .ToList(); + +Console.WriteLine("Tech Lead Team"); +techLeadSubordinates.ForEach(Console.WriteLine); + +// Get tech lead parents +var techLeadManagers = FindAllAncestors("Tech Lead").ToList(); +Console.WriteLine("Tech Lead Managers"); +techLeadManagers.ForEach(Console.WriteLine); + +var ceo = db.Employees.First(e => e.Path == HierarchyId.Parse("/")); + +Console.WriteLine($"Is Tech Lead a descendant of CEO? {techLead.Path.IsDescendantOf(ceo.Path)}"); +Console.WriteLine($"Is CEO a descendant of Tech Lead? {ceo.Path.IsDescendantOf(techLead.Path)}"); + +Console.ReadLine(); + +IQueryable FindAllAncestors(string name) + => db.Employees.Where( + ancestor => db.Employees + .Single( + descendent => + descendent.Name == name + && ancestor.Id != descendent.Id) + .Path.IsDescendantOf(ancestor.Path)) + .OrderByDescending(ancestor => ancestor.Path.GetLevel()); \ No newline at end of file diff --git a/HierarchyIds/readme.md b/HierarchyIds/readme.md new file mode 100644 index 0000000..1689cfb --- /dev/null +++ b/HierarchyIds/readme.md @@ -0,0 +1,16 @@ +# Hierarchy IDs + +Hierarchy IDs are a special data type in SQL Server that allow you to store and query hierarchical data. This is a great way to store data that has a parent-child relationship, such as a file system, organizational chart, or product categories. + +The DB is then able to run queries such as finding all descendants of a node, or finding the common ancestor of two nodes. + +NOTE: You will need the CLR enabled on your SQL Server instance for this to work. The Azure SQL Edge Docker image does not support this. + + +## Use Cases + +- Store and query hierarchical (i.e. tree-like) data + +## Resources + +- [EF Core Docs | Hierarchy IDs](https://learn.microsoft.com/en-us/ef/core/what-is-new/ef-core-8.0/whatsnew#hierarchyid-in-net-and-ef-core) diff --git a/docker-compose.yml b/docker-compose.yml index f8a1928..fc5d16e 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -5,11 +5,9 @@ services: environment: ACCEPT_EULA: "Y" SA_PASSWORD: "yourStrong(!)Password" - # mssql server image isn't available for arm64 architecture, so we use azure-sql instead - image: mcr.microsoft.com/azure-sql-edge:latest #container_name: "ef-core-samples" - # If you really want to use MS SQL Server, uncomment the following line - #image: mcr.microsoft.com/mssql/server + # NOTE: can't use azure-sql-edge as it doesn't support .NET CLR. + image: mcr.microsoft.com/mssql/server ports: # {{exposed}}:{{internal}} - you'll need to contain the exposed ports if you have more than one DB server running at a time - 1433:1433