You cannot select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
PolyglotNotebooksStudy/Docs/多语言笔记.2.2.操作数据库-C#.md

515 lines
14 KiB
Markdown

This file contains ambiguous Unicode characters!

This file contains ambiguous Unicode characters that may be confused with others in your current locale. If your use case is intentional and legitimate, you can safely ignore this warning. Use the Escape button to highlight these characters.

使用 .net 程序操作数据库
=======================
除了使用SQL内核执行SQL语句直接操作数据库使用最多的是使用用.net程序操作数据库
+ ado.net 原生操作
+ 使用ORM框架比如 Daper、EFCore、SqlSugar、FreeSQL等
## 初始化
```csharp
#!import "./Base.ipynb"
//共享
#r "nuget:Microsoft.Data.SqlClient"
#r "nuget:MySql.Data"
#r "nuget:Npgsql"
#r "nuget:Microsoft.Data.Sqlite"
#r "nuget:DuckDB.NET.Data.Full"
#r "nuget:Dapper"
#r "nuget:Microsoft.EntityFrameworkCore"
#r "nuget:Microsoft.EntityFrameworkCore.SqlServer"
#r "nuget:Microsoft.EntityFrameworkCore.Sqlite"
#r "nuget:Npgsql.EntityFrameworkCore.PostgreSQL"
#r "nuget:MySql.EntityFrameworkCore"
//#r "nuget:Pomelo.EntityFrameworkCore.MySql"
#r "nuget:MongoDB.EntityFrameworkCore"
global using System.Text.Json;
global using System.Text.Json.Schema;
global using System.Text.Json.Serialization;
global using System.Data;
global using System.Data.Common;
global using System.Data.SqlTypes;
global using System.Data.SqlClient;
//global using System.Data.OracleClient;
global using Microsoft.Data.SqlClient;
global using Microsoft.Data.SqlClient.Server;
global using MySql.Data;
global using MySql.Data.Types;
global using MySql.Data.MySqlClient;
global using Microsoft.Data.Sqlite;
global using DuckDB.NET.Data;
global using DuckDB.NET.Data.DataChunk;
global using Dapper;
global using Npgsql;
global using Npgsql.Schema;
global using Npgsql.PostgresTypes;
global using Npgsql.TypeMapping;
global using Npgsql.Util;
global using Npgsql.NameTranslation;
global using Npgsql.BackendMessages;
global using Microsoft.EntityFrameworkCore;
global using Microsoft.EntityFrameworkCore.SqlServer;
global using Microsoft.EntityFrameworkCore.Sqlite;
global using Npgsql.EntityFrameworkCore.PostgreSQL;
global using MySql.EntityFrameworkCore;
global using MongoDB.EntityFrameworkCore;
//共享方法
public static List<Student> DatatableToStudent(DataTable studentTable)
{
var students = new List<Student>();
if(studentTable == null)
{
return students;
}
if(studentTable.Columns.Count ==0)
{
return students;
}
if(studentTable.Rows.Count <=0)
{
return students;
}
foreach(DataRow row in studentTable.Rows)
{
var student = new Student()
{
Id = (int)row["Id"],
Name = row["Name"] == DBNull.Value ? "" : (string)row["Name"].ToString(),
Age = row["Age"] == DBNull.Value ? 0 : (int)row["Age"]
};
students.Add(student);
}
return students;
}
```
## 使用 ADO.NET
### SQL Server 数据库(2019为例)
```csharp
//Ado.Net 操作SQL Server
{
DataSet ds = new DataSet();
using(var mssqlConnection = new SqlConnection(SharedDbConnect.MsSqlConnectionString))
{
mssqlConnection.Open();
var querySql = "select * FROM student where age >@age;";
SqlParameter[] parameters = new SqlParameter[]
{
new SqlParameter()
{
ParameterName = "age",
SqlDbType = SqlDbType.Int,
Value = 50,
Direction = ParameterDirection.Input,
Size = 4,
DbType = DbType.Int32,
IsNullable = false,
}
};
var command = new SqlCommand(querySql, mssqlConnection);
command.Parameters.AddRange(parameters);
var adapter = new SqlDataAdapter(command);
adapter.Fill(ds);
mssqlConnection.Close();
mssqlConnection.Dispose();
}
var students = DatatableToStudent(ds.Tables[0]);
Console.WriteLine($"查询到: {students.Count()} 行数据");
var jsonText = System.Text.Json.JsonSerializer.Serialize(students.Take<Student>(2), new System.Text.Json.JsonSerializerOptions()
{
Encoder = System.Text.Encodings.Web.JavaScriptEncoder.Create(System.Text.Unicode.UnicodeRanges.All),
WriteIndented = false,
});
Console.WriteLine($"前2行{jsonText}");
}
```
### MySQL
```csharp
//Ado.Net 操作MySQL
{
//查询数据
DataSet ds = new DataSet();
using(var sqlConnection = new MySqlConnection(SharedDbConnect.MySQLConnectionString))
{
sqlConnection.Open();
var querySql = "SELECT * FROM `Student` LIMIT 2;";
var command = new MySqlCommand(querySql, sqlConnection);
var adapter = new MySqlDataAdapter(command);
adapter.Fill(ds);
sqlConnection.Close();
sqlConnection.Dispose();
}
//输出数据
var dt = ds.Tables[0];
int padRightCount = 15;
//输出列
List<string> columnNames = new List<string>(100);
foreach(DataColumn c in dt.Columns)
{
columnNames.Add(c.ColumnName.PadRight(padRightCount));
}
Console.WriteLine(string.Join("", columnNames));
//输出数据
foreach(DataRow row in dt.Rows)
{
List<string> rowItemValues = new List<string>(100);
for(int i=0; i<columnNames.Count(); i++)
{
var valueText = row[i] == DBNull.Value? "null" : row[i].ToString();
rowItemValues.Add(valueText.PadRight(padRightCount));
}
Console.WriteLine(string.Join("",rowItemValues));
}
}
```
### PostgreSQL
```csharp
//Ado.Net 操作PostgreSQL
{
//查询数据
DataSet ds = new DataSet();
using(var sqlConnection = new NpgsqlConnection(SharedDbConnect.PSQLConnectionString))
{
sqlConnection.Open();
var querySql =
"""
SELECT * FROM "Student" LIMIT 5;
""";
var command = new NpgsqlCommand(querySql, sqlConnection);
var adapter = new NpgsqlDataAdapter(command);
adapter.Fill(ds);
sqlConnection.Close();
sqlConnection.Dispose();
}
//输出数据
var dt = ds.Tables[0];
int padRightCount = 15;
//输出列
List<string> columnNames = new List<string>(100);
foreach(DataColumn c in dt.Columns)
{
columnNames.Add(c.ColumnName.PadRight(padRightCount));
}
Console.WriteLine(string.Join("", columnNames));
//输出数据
foreach(DataRow row in dt.Rows)
{
List<string> rowItemValues = new List<string>(100);
for(int i=0; i<columnNames.Count(); i++)
{
var valueText = row[i] == DBNull.Value? "null" : row[i].ToString();
rowItemValues.Add(valueText.PadRight(padRightCount));
}
Console.WriteLine(string.Join("",rowItemValues));
}
}
```
```csharp
//Ado.Net 操作PostgreSQL: 客户端官方用法(异步)
{
//查询数据
DataSet ds = new DataSet();
int padRightCount = 15;
await using var dataSource = NpgsqlDataSource.Create(SharedDbConnect.PSQLConnectionString);
await using (var cmd = dataSource.CreateCommand("SELECT * FROM \"Student\" LIMIT 5;"))
await using (var reader = await cmd.ExecuteReaderAsync())
{
//输出列名
List<string> columnNames = reader.GetColumnSchema().Select(c => c.ColumnName.PadRight(padRightCount)).ToList();
Console.WriteLine(string.Join("", columnNames));
//循环输出行数据
while (await reader.ReadAsync())
{
List<string> rowItemValues = new List<string>(100);
for(int i=0; i<columnNames.Count(); i++)
{
var valueText = reader.GetFieldValue<object>(i).ToString();
rowItemValues.Add(valueText.PadRight(padRightCount));
}
Console.WriteLine(string.Join("",rowItemValues));
}
}
}
```
### SQLite
```csharp
//Ado.Net 操作SQLite
{
//查询数据
DataSet ds = new DataSet();
int padRightCount = 15;
using(var sqlConnection = new SqliteConnection(SharedDbConnect.SQLiteConnectionString))
{
sqlConnection.Open();
var querySql =
"""
SELECT * FROM Student LIMIT 5;
""";
var cmd = sqlConnection.CreateCommand();
cmd.CommandType = CommandType.Text;
cmd.CommandText = querySql;
using (var reader = await cmd.ExecuteReaderAsync())
{
//输出列名
List<string> columnNames = reader.GetColumnSchema().Select(c => c.ColumnName.PadRight(padRightCount)).ToList();
Console.WriteLine(string.Join("", columnNames));
//循环输出行数据
while (await reader.ReadAsync())
{
List<string> rowItemValues = new List<string>(100);
for(int i=0; i<columnNames.Count(); i++)
{
var valueText = reader.GetFieldValue<object>(i).ToString();
rowItemValues.Add(valueText.PadRight(padRightCount));
}
Console.WriteLine(string.Join("",rowItemValues));
}
}
sqlConnection.Close();
sqlConnection.Dispose();
}
}
```
### DuckDB
```csharp
//Ado.Net 操作DuckDB数据库
{
int padRightCount = 15;
using(var sqlConnection = new DuckDBConnection(SharedDbConnect.DuckDBConnectionString))
{
sqlConnection.Open();
//1、创建表
var createTableSql =
"""
CREATE TABLE Student
(
Id INTEGER,
Name TEXT,
Age INTEGER
);
""";
var createCommand = sqlConnection.CreateCommand();
createCommand.CommandType = CommandType.Text;
createCommand.CommandText = createTableSql;
var createCount = createCommand.ExecuteNonQuery();
//Console.WriteLine($"{createCount}");
//2、插入示例数据
var insertSql =
"""
INSERT INTO Student VALUES (1, '张三', 10), (2, '李四', 33), (3, '王五', 66);
""";
var insertCommand = sqlConnection.CreateCommand();
insertCommand.CommandType = CommandType.Text;
insertCommand.CommandText = insertSql;
var insertCount = insertCommand.ExecuteNonQuery();
//Console.WriteLine($"{insertCount}");
//3、查询数据
var querySql =
"""
SELECT * FROM Student ORDER BY Age
""";
var queryCommand = sqlConnection.CreateCommand();
queryCommand.CommandType = CommandType.Text;
queryCommand.CommandText = querySql;
using (var reader = await queryCommand.ExecuteReaderAsync())
{
//输出列名
List<string> columnNames = reader.GetColumnSchema().Select(c => c.ColumnName.PadRight(padRightCount)).ToList();
Console.WriteLine(string.Join("", columnNames));
//循环输出行数据
while (await reader.ReadAsync())
{
List<string> rowItemValues = new List<string>(100);
for(int i=0; i<columnNames.Count(); i++)
{
var valueText = reader.GetValue(i).ToString();
rowItemValues.Add(valueText.PadRight(padRightCount));
}
Console.WriteLine(string.Join("",rowItemValues));
}
}
sqlConnection.Close();
sqlConnection.Dispose();
}
}
```
## 使用 Dapper
### Dapper 操作 SQL Server 2019
```csharp
//Dapper 操作SQL Server
{
using(var mssqlConnection = new SqlConnection(SharedDbConnect.MsSqlConnectionString))
{
var querySql = "select * FROM student;";
var students = mssqlConnection.Query<Student>(querySql).Take(2);
var jsonText = System.Text.Json.JsonSerializer.Serialize(students, new System.Text.Json.JsonSerializerOptions()
{
Encoder = System.Text.Encodings.Web.JavaScriptEncoder.Create(System.Text.Unicode.UnicodeRanges.All),
WriteIndented = false,
});
Console.WriteLine(jsonText);
}
}
```
### Dapper 操作 MySQL
```csharp
//Dapper 操作MySQL
{
using(var dbConnection = new MySqlConnection(SharedDbConnect.MySQLConnectionString))
{
var querySql = "SELECT * FROM `Student` LIMIT @top;";
var students = dbConnection.Query<Student>(querySql, new {top=2});
var jsonText = System.Text.Json.JsonSerializer.Serialize(students, new System.Text.Json.JsonSerializerOptions()
{
Encoder = System.Text.Encodings.Web.JavaScriptEncoder.Create(System.Text.Unicode.UnicodeRanges.All),
WriteIndented = false,
});
Console.WriteLine(jsonText);
}
}
```
### Dapper 操作 PostgreSQL
```csharp
//Dapper 操作 PSQL
{
using(var dbConnection = new NpgsqlConnection(SharedDbConnect.PSQLConnectionString))
{
var querySql = "SELECT * FROM \"Student\" Where \"Age\" > @Age LIMIT @Top;";
var students = dbConnection.Query<Student>(querySql, new {Age = 50, top = 2});
var jsonText = System.Text.Json.JsonSerializer.Serialize(students, new System.Text.Json.JsonSerializerOptions()
{
Encoder = System.Text.Encodings.Web.JavaScriptEncoder.Create(System.Text.Unicode.UnicodeRanges.All),
WriteIndented = false,
});
Console.WriteLine(jsonText);
}
}
```
## 使用 EF Core
```csharp
//共享
/// <summary>
/// SQL Server DbContext
/// </summary>
public class StudyDbContext: DbContext
{
public StudyDbContext(DbContextOptions<StudyDbContext> option):base(option)
{
}
public DbSet<Student> Student {get; set;}
protected override void OnConfiguring(DbContextOptionsBuilder optionsBuilder)
{
base.OnConfiguring(optionsBuilder);
if(!optionsBuilder.IsConfigured)
{
Console.WriteLine("没有设置");
}
}
}
```
### EF Core 操作 SQL Server
```csharp
{ //EF Core SQL Server
var builder = new DbContextOptionsBuilder<StudyDbContext>();
builder.UseSqlServer(SharedDbConnect.MsSqlConnectionString);
var dbContext = new StudyDbContext(builder.Options);
var students = dbContext.Student.Where(s => s.Age> 95).ToList();
students.Display();
}
```
### EF Core 查询 MySQL
```csharp
{ //EF Core MySQL
var builder = new DbContextOptionsBuilder<StudyDbContext>();
builder.UseMySQL(SharedDbConnect.MySQLConnectionString);
var dbContext = new StudyDbContext(builder.Options);
var students = dbContext.Student.Where(s => s.Age> 95).ToList();
students.Display();
}
```
### EFCore PostgreSQL
```csharp
{
var builder = new DbContextOptionsBuilder<StudyDbContext>();
builder.UseNpgsql(SharedDbConnect.PSQLConnectionString);
var dbContext = new StudyDbContext(builder.Options);
var students = dbContext.Student.Where(s => s.Age> 95).ToList();
students.Display();
}
```