Created With Sql (markdown)

AlexLEWIS
2021-09-27 13:28:40 +08:00
parent 6c320c5bef
commit fd372a69bd

269
With-Sql.md Normal file

@@ -0,0 +1,269 @@
[中文](withsql) | **English**
# WithSql 自定义SQL
定义实体类
```csharp
public class TestClass
{
[Column(Name = "ID", IsPrimary = true)]
public string No { get; set; }
public int? Age { get; set; }
public string Name { get; set; }
[Column(Name = "BIRTH_DAY")]
public DateTime? Birthday { get; set; }
public decimal Point { get; set; }
public Sex? Sex { get; set; }
}
public class TestClssDto
{
public string ID { get; set; }
public int? Age { get; set; }
}
```
不同的查询方式。
- 返回`DataTable`
- 返回`List<Tuplue>``List<(string,string)>`元组
- 返回`List<object>` 且能支持分页
- 返回`List<TestClassDto>`且能支持分页
### 1.返回DataTable
```csharp
DataTable dt1 = _fsql.Select<object>()
.WithSql("select * from TestClass ")
.ToDataTable("ID,Age");
```
```sql
SELECT ID,Age
FROM(select * from TestClass ) a
```
### 2.返回DataTable
```csharp
DataTable dt2 = _fsql.Select<object>()
.WithSql("select * from TestClass ")
.ToDataTable("*");
```
```sql
SELECT *
FROM ( select * from TestClass ) a
```
### 3.返回`List<Tuplue>` 即`List<(string,string)>` 元组
```csharp
List<(string,string)> list1 = _fsql
.Select<object>()
.WithSql("select * from TestClass ")
.ToList<(string, string)>("ID,Age");
```
```sql
SELECT ID, Age
FROM(select * from TestClass ) a
```
### 4.返回`List<object>`
```csharp
var list2 = _fsql.Select<object>()
.WithSql("select * from TestClass ")
.ToList<object>("*");
```
```sql
SELECT *
FROM(select * from TestClass ) a
```
### 5.返回`List<object>` 且能支持分页
```csharp
var list3 = _fsql.Select<object>()
.WithSql("select * from TestClass ")
.WhereIf(true, "1=1")
.Page(1, 10).OrderBy("ID DESC")
.ToList<object>("ID,Age");
```
```sql
SELECT ID, Age
FROM(select * from TestClass ) a
WHERE(1 = 1)
ORDER BY ID DESC
limit 0,10
```
### 6.返回`List<TestClassDto>`且能支持分页
```csharp
var list4 = _fsql.Select<object>()
.WithSql("select * from TestClass ")
.WhereIf(true, "1=1")
.Page(1, 10)
.OrderBy("ID DESC")
.ToList<TestClssDto>("ID,Age");
```
```sql
SELECT ID, Age
FROM(select * from TestClass ) a
WHERE(1 = 1)
ORDER BY ID DESC
limit 0,10
```
## 通过 WithSql+ ToSQL实现 Union ALL 查询方法
### 1、二次 ISelect 查询WithSql 使用多次,等于 UNION ALL 查询
WithSql 使用多次为 UNION ALL 查询,所以我们可以利用 ISelect.ToSql(FieldAliasOptions.AsProperty) 得到生成的 SQL如下
```csharp
var sql1 = fsql.Select<Topic>()
.Where(a => a.Title.Contains("xxx"))
.ToSql();
var sql2 = fsql.Select<Topic>()
.Where(a => a.Title.Contains("yyy"))
.ToSql();
fsql.Select<Topic>()
.WithSql(sql1)
.WithSql(sql2)
.ToList();
```
```sql
SELECT * from (SELECT a.`Id`, a.`Clicks`, a.`TypeGuid`, a.`Title`, a.`CreateTime`
FROM ( SELECT a.`Id`, a.`Clicks`, a.`TypeGuid`, a.`Title`, a.`CreateTime`
FROM `tb_topic` a
WHERE ((a.`Title`) LIKE '%xxx%') ) a) ftb
UNION ALL
SELECT * from (SELECT a.`Id`, a.`Clicks`, a.`TypeGuid`, a.`Title`, a.`CreateTime`
FROM ( SELECT a.`Id`, a.`Clicks`, a.`TypeGuid`, a.`Title`, a.`CreateTime`
FROM `tb_topic` a
WHERE ((a.`Title`) LIKE '%yyy%') ) a) ftb
```
### 2、跨分表查询AsTable 相同实体多次操作,等于 Union ALL 查询
```c#
var sql = fsql.Select<User>()
.AsTable((type, oldname) => "table_1")a
.AsTable((type, oldname) => "table_2")
.ToSql(a => a.Id);
```
```sql
select * from (SELECT a."Id" as1 FROM "table_1" a) ftb
UNION ALL
select * from (SELECT a."Id" as1 FROM "table_2" a) ftb
```
### 3、利用 ToSql 拼接新的 SQL使用 IAdo 执行
```c#
var sql1 = fsql.Select<Topic>()
.Where(a => a.Id > 100 && a.Id < 200)
.ToSql(a => new { a.Id, a.Title }, FieldAliasOptions.AsProperty);
var sql2 = fsql.Select<Topic>()
.Where(a => a.Id > 1001 && a.Id < 1200)
.ToSql(a => new { a.Id, a.Title }, FieldAliasOptions.AsProperty);
fsql.Ado.CommandFluent($"{sql1} UNION ALL {sql2}")
.ExecuteDataTable();
```
## 分页问题
Union All 之后 如果直接 分页会有一个问题。请看具体示例
### 多次WithSql+Page存在问题每个WithSql内都有一个Page分页
```csharp
var sql1 = fsql.Select<Topic>()
.Where(a => a.Title.Contains("xxx"))
.ToSql();
var sql2 = fsql.Select<Topic>()
.Where(a => a.Title.Contains("yyy"))
.ToSql();
fsql.Select<Topic>().WithSql(sql1).WithSql(sql2).Page(1, 20).ToList();
```
```sql
SELECT * from (SELECT a.`Id`, a.`Clicks`, a.`TypeGuid`, a.`Title`, a.`CreateTime`
FROM ( SELECT a.`Id`, a.`Clicks`, a.`TypeGuid`, a.`Title`, a.`CreateTime`
FROM `tb_topic` a
WHERE ((a.`Title`) LIKE '%xxx%') ) a
limit 0,20) ftb
UNION ALL
SELECT * from (SELECT a.`Id`, a.`Clicks`, a.`TypeGuid`, a.`Title`, a.`CreateTime`
FROM ( SELECT a.`Id`, a.`Clicks`, a.`TypeGuid`, a.`Title`, a.`CreateTime`
FROM `tb_topic` a
WHERE ((a.`Title`) LIKE '%yyy%') ) a
limit 0,20) ftb
```
多个sql union all使用withsql直接Page分页会导致每个子表都生效子表都生成分页。
WithSql 可以和 AsTable 实现分表的功能。
分表跨表查询的时候分页是要向每个子表即每个WithSql中的SQL分页都生效。
## Solution
### Call WithSql Multiple Times
Call WithSql multiple times. If you need to paging, you need to follow the two steps below.
- Step 1: combine the two Sql statements into one by `WithSql`:
```csharp
var sql = fsql.Select<Topic>()
.WithSql("SELECT * FROM tb_topic where id > 11")
.WithSql("SELECT * FROM tb_topic where id < 10")
.ToSql("*")
```
The above code will be generated as a Sql statement using `UNION ALL`:
```sql
SELECT * from (SELECT *
FROM ( SELECT * FROM tb_topic where id > 11 ) a) ftb
UNION ALL
SELECT * from (SELECT *
FROM ( SELECT * FROM tb_topic where id < 10 ) a) ftb
```
- Step 2: on the basis of the SQL statement containing `UNION ALL`, page by calling the `Page` method:
```csharp
var sql2 = g.mysql.Select<Topic>()
.WithSql(sql)
.Page(2, 10)
.ToSql();
```
```sql
SELECT a.`Id`, a.`Clicks`, a.`TypeGuid`, a.`Title`, a.`CreateTime`
FROM ( SELECT * from (SELECT *
FROM ( SELECT * FROM tb_topic where id > 11 ) a) ftb
UNION ALL
SELECT * from (SELECT *
FROM ( SELECT * FROM tb_topic where id < 10 ) a) ftb ) a
limit 10,10
```