diff --git a/Home.md b/Home.md index 6af55b2..5a3e695 100644 --- a/Home.md +++ b/Home.md @@ -31,6 +31,7 @@ FreeSql是一个功能强大的 .NET ORM 功能库,支持 .NetFramework 4.0+ * [延时加载](https://github.com/2881099/FreeSql/wiki/%e5%bb%b6%e6%97%b6%e5%8a%a0%e8%bd%bd) * [贪婪加载!!](https://github.com/2881099/FreeSql/wiki/%e8%b4%aa%e5%a9%aa%e5%8a%a0%e8%bd%bd) * [LinqToSql](https://github.com/2881099/FreeSql/wiki/LinqToSql) + * [查询父子关系]](https://github.com/2881099/FreeSql/wiki/%e6%9f%a5%e8%af%a2%e7%88%b6%e5%ad%90%e5%85%b3%e7%b3%bb) * [仓储层Repository](https://github.com/2881099/FreeSql/wiki/Repository) * [UnitOfWork](https://github.com/2881099/FreeSql/wiki/%e5%b7%a5%e4%bd%9c%e5%8d%95%e5%85%83) * [联级保存](https://github.com/2881099/FreeSql/wiki/%e8%81%94%e7%ba%a7%e4%bf%9d%e5%ad%98) diff --git a/_Sidebar.md b/_Sidebar.md index 01cba54..7687e6a 100644 --- a/_Sidebar.md +++ b/_Sidebar.md @@ -19,6 +19,7 @@ * [延时加载](https://github.com/2881099/FreeSql/wiki/%e5%bb%b6%e6%97%b6%e5%8a%a0%e8%bd%bd) * [贪婪加载!!](https://github.com/2881099/FreeSql/wiki/%e8%b4%aa%e5%a9%aa%e5%8a%a0%e8%bd%bd) * [LinqToSql](https://github.com/2881099/FreeSql/wiki/LinqToSql) + * [查询父子关系]](https://github.com/2881099/FreeSql/wiki/%e6%9f%a5%e8%af%a2%e7%88%b6%e5%ad%90%e5%85%b3%e7%b3%bb) * [仓储层Repository](https://github.com/2881099/FreeSql/wiki/Repository) * [UnitOfWork](https://github.com/2881099/FreeSql/wiki/%e5%b7%a5%e4%bd%9c%e5%8d%95%e5%85%83) * [联级保存](https://github.com/2881099/FreeSql/wiki/%e8%81%94%e7%ba%a7%e4%bf%9d%e5%ad%98) diff --git a/查询父子关系.md b/查询父子关系.md new file mode 100644 index 0000000..a22c058 --- /dev/null +++ b/查询父子关系.md @@ -0,0 +1,199 @@ +无限级分类(父子)是一种比较常用的表设计,每种设计方式突出优势的同时也带来缺陷,如: + +- 方法1:表设计中只有 parent_id 字段,困扰:查询麻烦(本文可解决); +- 方法2:表设计中冗余子级id便于查询,困扰:添加/更新/删除的时候需要重新计算; +- 方法3:表设计中存储左右值编码,困扰:同上; + +方法1设计最简单,本文解决它的递归查询问题,让使用透明化。 + +## 父子导航属性 + +FreeSql 支持的导航属性的中,有针对父子关系的设置方式,如下: + +```csharp +public class Area +{ + [Column(IsPrimary = true)] + public string Code { get; set; } + + public string Name { get; set; } + public virtual string ParentCode { get; set; } + + [Navigate(nameof(ParentCode))] + public Area Parent { get; set; } + [Navigate(nameof(ParentCode))] + public List Childs { get; set; } +} +``` + +定义 Parent 属性,在表达式中可以这样: +```csharp +fsql.Select().Where(a => a.Parent.Parent.Parent.Name == "中国").First(); +``` + +定义 Childs 属性,在表达式中可以这样(子查询): +```csharp +fsql.Select().Where(a => a.Childs.AsSelect().Any(c => c.Name == "北京")).First(); +``` + +定义 Childs 属性,还可以使用[【级联保存】](https://github.com/dotnetcore/FreeSql/wiki/%E8%81%94%E7%BA%A7%E4%BF%9D%E5%AD%98)、[【贪婪加载】](https://github.com/2881099/FreeSql/wiki/%e8%b4%aa%e5%a9%aa%e5%8a%a0%e8%bd%bd) 等等操作。 + + +添加测试数据: + +```csharp +fsql.Delete().Where("1=1").ExecuteAffrows(); +var repo = fsql.GetRepository(); +repo.DbContextOptions.EnableAddOrUpdateNavigateList = true; +repo.DbContextOptions.NoneParameter = true; +repo.Insert(new Area +{ + Code = "100000", + Name = "中国", + Childs = new List(new[] { + new Area + { + Code = "110000", + Name = "北京", + Childs = new List(new[] { + new Area{ Code="110100", Name = "北京市" }, + new Area{ Code="110101", Name = "东城区" }, + }) + } + }) +}); +``` + +## 1、ToTreeList + +配置好父子属性之后,就可以这样用了: + +```csharp +var t1 = fsql.Select().ToTreeList(); +Assert.Single(t1); +Assert.Equal("100000", t1[0].Code); +Assert.Single(t1[0].Childs); +Assert.Equal("110000", t1[0].Childs[0].Code); +Assert.Equal(2, t1[0].Childs[0].Childs.Count); +Assert.Equal("110100", t1[0].Childs[0].Childs[0].Code); +Assert.Equal("110101", t1[0].Childs[0].Childs[1].Code); +``` + +查询数据本来是平面的,ToTreeList 方法将返回的平面数据加工为树型 List 返回。 + +## 2、AsTreeCte 递归查询 + +若不做数据冗余的无限级分类表设计,递归查询少不了,AsTreeCte 正是解决递归查询的封装,方法参数说明: + +| 参数 | 描述 | +| -- | -- | +| (可选) pathSelector | 路径内容选择,可以设置查询返回:中国 -> 北京 -> 东城区 | +| (可选) up | false(默认):由父级向子级的递归查询,true:由子级向父级的递归查询 | +| (可选) pathSeparator | 设置 pathSelector 的连接内容,默认:-> | +| (可选) level | 设置递归层级 | + + +姿势一:AsTreeCte() + ToTreeList + +```csharp +var t2 = fsql.Select() + .Where(a => a.Name == "中国") + .AsTreeCte() //查询 中国 下的所有记录 + .OrderBy(a => a.Code) + .ToTreeList(); //非必须,也可以使用 ToList(见姿势二) +Assert.Single(t2); +Assert.Equal("100000", t2[0].Code); +Assert.Single(t2[0].Childs); +Assert.Equal("110000", t2[0].Childs[0].Code); +Assert.Equal(2, t2[0].Childs[0].Childs.Count); +Assert.Equal("110100", t2[0].Childs[0].Childs[0].Code); +Assert.Equal("110101", t2[0].Childs[0].Childs[1].Code); +// WITH "as_tree_cte" +// as +// ( +// SELECT 0 as cte_level, a."Code", a."Name", a."ParentCode" +// FROM "Area" a +// WHERE (a."Name" = '中国') + +// union all + +// SELECT wct1.cte_level + 1 as cte_level, wct2."Code", wct2."Name", wct2."ParentCode" +// FROM "as_tree_cte" wct1 +// INNER JOIN "Area" wct2 ON wct2."ParentCode" = wct1."Code" +// ) +// SELECT a."Code", a."Name", a."ParentCode" +// FROM "as_tree_cte" a +// ORDER BY a."Code" +``` + +姿势二:AsTreeCte() + ToList +```csharp +t3 = fsql.Select() + .Where(a => a.Name == "中国") + .AsTreeCte() + .OrderBy(a => a.Code) + .ToList(); +Assert.Equal(4, t3.Count); +Assert.Equal("100000", t3[0].Code); +Assert.Equal("110000", t3[1].Code); +Assert.Equal("110100", t3[2].Code); +Assert.Equal("110101", t3[3].Code); +//执行的 SQL 与姿势一相同 +``` + +姿势三:AsTreeCte(pathSelector) + ToList + +设置 pathSelector 参数后,如何返回隐藏字段? + +```csharp +t4 = fsql.Select() + .Where(a => a.Name == "中国") + .AsTreeCte(a => a.Name + "[" + a.Code + "]") + .OrderBy(a => a.Code) + .ToList(a => new { + item = a, + level = Convert.ToInt32("a.cte_level"), + path = "a.cte_path" + }); +Assert.Equal(4, t4.Count); +Assert.Equal("100000", t4[0].item.Code); +Assert.Equal("110000", t4[1].item.Code); +Assert.Equal("110100", t4[2].item.Code); +Assert.Equal("110101", t4[3].item.Code); +Assert.Equal("中国[100000]", t4[0].path); +Assert.Equal("中国[100000] -> 北京[110000]", t4[1].path); +Assert.Equal("中国[100000] -> 北京[110000] -> 北京市[110100]", t4[2].path); +Assert.Equal("中国[100000] -> 北京[110000] -> 东城区[110101]", t4[3].path); +// WITH "as_tree_cte" +// as +// ( +// SELECT 0 as cte_level, a."Name" || '[' || a."Code" || ']' as cte_path, a."Code", a."Name", a."ParentCode" +// FROM "Area" a +// WHERE (a."Name" = '中国') + +// union all + +// SELECT wct1.cte_level + 1 as cte_level, wct1.cte_path || ' -> ' || wct2."Name" || '[' || wct2."Code" || ']' as cte_path, wct2."Code", wct2."Name", wct2."ParentCode" +// FROM "as_tree_cte" wct1 +// INNER JOIN "Area" wct2 ON wct2."ParentCode" = wct1."Code" +// ) +// SELECT a."Code" as1, a."Name" as2, a."ParentCode" as5, a.cte_level as6, a.cte_path as7 +// FROM "as_tree_cte" a +// ORDER BY a."Code" +``` + +> 更多姿势...请根据代码注释进行尝试 + +## 参考资料 + +- [《多表查询》](https://github.com/2881099/FreeSql/wiki/%e5%a4%9a%e8%a1%a8%e6%9f%a5%e8%af%a2) +- [《返回数据》](https://github.com/2881099/FreeSql/wiki/%e8%bf%94%e5%9b%9e%e6%95%b0%e6%8d%ae) +- [《LinqToSql》](https://github.com/2881099/FreeSql/wiki/LinqToSql) +- [《仓储层Repository》](https://github.com/2881099/FreeSql/wiki/Repository) +- [《过滤器、全局过滤器》](https://github.com/2881099/FreeSql/wiki/%e8%bf%87%e6%bb%a4%e5%99%a8) +- [《优化之:延时加载》](https://github.com/2881099/FreeSql/wiki/%e5%bb%b6%e6%97%b6%e5%8a%a0%e8%bd%bd) +- [《优化之:贪婪加载》](https://github.com/2881099/FreeSql/wiki/%e8%b4%aa%e5%a9%aa%e5%8a%a0%e8%bd%bd) +- [《Expression 表达式函数》](https://github.com/2881099/FreeSql/wiki/%e8%a1%a8%e8%be%be%e5%bc%8f%e5%87%bd%e6%95%b0) +- [《性能》](https://github.com/2881099/FreeSql/wiki/%e6%80%a7%e8%83%bd) +- [《分区、分表、分库》](https://github.com/2881099/FreeSql/wiki/%e5%88%86%e5%8c%ba%e5%88%86%e8%a1%a8) +- [《租户》](https://github.com/2881099/FreeSql/wiki/%e7%a7%9f%e6%88%b7) \ No newline at end of file