From eb07bccfa79f069af97c96d3cfa982114248efc3 Mon Sep 17 00:00:00 2001 From: Soar360 Date: Fri, 13 Sep 2024 11:16:58 +0800 Subject: [PATCH 1/7] =?UTF-8?q?=E6=94=AF=E6=8C=81=E5=88=9B=E5=BB=BA?= =?UTF-8?q?=E6=95=B0=E7=BB=84=E5=AD=97=E6=AE=B5?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- XCode/Configuration/FieldItem.cs | 1 + XCode/DataAccessLayer/Database/PostgreSQL.cs | 2 ++ .../DataAccessLayer/MetaData/DbMetaData_Positive.cs | 13 ++++++++++++- 3 files changed, 15 insertions(+), 1 deletion(-) diff --git a/XCode/Configuration/FieldItem.cs b/XCode/Configuration/FieldItem.cs index c000c6431..687886405 100644 --- a/XCode/Configuration/FieldItem.cs +++ b/XCode/Configuration/FieldItem.cs @@ -223,6 +223,7 @@ public void Fill(IDataColumn field) dc.DefaultValue = col.DefaultValue; //dc.ItemDefaultValue = col.ItemDefaultValue; dc.DataScale = col.DataScale; + dc.IsArray = col.IsArray; } // 特别处理,兼容旧版本 diff --git a/XCode/DataAccessLayer/Database/PostgreSQL.cs b/XCode/DataAccessLayer/Database/PostgreSQL.cs index e708042d3..3d33ef3e2 100644 --- a/XCode/DataAccessLayer/Database/PostgreSQL.cs +++ b/XCode/DataAccessLayer/Database/PostgreSQL.cs @@ -334,6 +334,8 @@ internal class PostgreSQLMetaData : RemoteDbMetaData { typeof(String), new String[] { "varchar({0})", "character varying", "text" } }, }; + protected override String? ArrayTypePostfix => "[]"; + #endregion 数据类型 protected override void FixTable(IDataTable table, DataRow dr, IDictionary data) diff --git a/XCode/DataAccessLayer/MetaData/DbMetaData_Positive.cs b/XCode/DataAccessLayer/MetaData/DbMetaData_Positive.cs index 63b2ffa13..8e338f7ff 100644 --- a/XCode/DataAccessLayer/MetaData/DbMetaData_Positive.cs +++ b/XCode/DataAccessLayer/MetaData/DbMetaData_Positive.cs @@ -393,6 +393,9 @@ protected virtual List> FieldTypeMaps } } + /// 数组类型后缀。为空则表示该数据库类型不支持数组。 + protected virtual string? ArrayTypePostfix { get; } = null; + /// 取字段类型 /// 字段 /// @@ -401,6 +404,9 @@ protected virtual List> FieldTypeMaps var type = field.DataType; if (type == null) return null; + //处理数组 + if (type.IsArray) type = type.GetElementType(); + // 处理枚举 if (type.IsEnum) type = typeof(Int32); @@ -416,7 +422,12 @@ protected virtual List> FieldTypeMaps else typeName = String.Format(typeName, field.Length); } - + if (field.IsArray) + { + var postfix = this.ArrayTypePostfix; + if (string.IsNullOrWhiteSpace(postfix)) throw new XCodeException($"数据库不支持数组类型"); + typeName += postfix; + } return typeName; } From dc2e7b6d177aea05800122a36b591662ed01717b Mon Sep 17 00:00:00 2001 From: Soar360 Date: Fri, 13 Sep 2024 13:12:21 +0800 Subject: [PATCH 2/7] PostgreSQL.FormatValue --- XCode/DataAccessLayer/Database/PostgreSQL.cs | 98 ++++++++++++++++++-- 1 file changed, 91 insertions(+), 7 deletions(-) diff --git a/XCode/DataAccessLayer/Database/PostgreSQL.cs b/XCode/DataAccessLayer/Database/PostgreSQL.cs index 3d33ef3e2..ebe61cb34 100644 --- a/XCode/DataAccessLayer/Database/PostgreSQL.cs +++ b/XCode/DataAccessLayer/Database/PostgreSQL.cs @@ -1,4 +1,5 @@ -using System.Data; +using System.Collections; +using System.Data; using System.Data.Common; using System.Net; using System.Text; @@ -6,6 +7,7 @@ using NewLife.Collections; using NewLife.Data; using NewLife.Log; +using NewLife.Reflection; namespace XCode.DataAccessLayer; @@ -88,18 +90,100 @@ public override String FormatKeyWord(String keyWord) /// 字段 /// 数值 /// - public override String FormatValue(IDataColumn field, Object? value) + public override String FormatValue(IDataColumn? column, Object? value) { - if (field.DataType == typeof(String)) + var isNullable = true; + var isArray = false; + Type? type = null; + if (column != null) { - if (value == null) return field.Nullable ? "null" : "''"; + type = column.DataType; + isNullable = column.Nullable; + isArray = column.IsArray; + } + else if (value != null) + { + type = value.GetType(); + isArray = type.IsArray; + } + + // 如果类型是Nullable的,则获取对应的类型 + type = Nullable.GetUnderlyingType(type) ?? type; + //如果是数组,就取数组的元素类型 + if (type?.IsArray == true) + { + var element = type.GetElementType(); + if (element != typeof(byte))//blob类型需要特殊处理 + { + isArray = true; + type = element; + } + } + if (isArray) + { + if (value is null) return isNullable ? "NULL" : "ARRAY[]"; + var count = 0; + var builder = new StringBuilder(); + builder.Append("ARRAY["); + foreach (var v in (IEnumerable)value) + { + builder.Append(ValueToSQL(type, isNullable, v)); + builder.Append(','); + count++; + } + if (count != 0) builder.Length--; + builder.Append("]"); + return builder.ToString(); + } + else + { + return ValueToSQL(type, isNullable, value); + } + } + + private string ValueToSQL(Type? type, bool isNullable, object? value) + { + if (type == typeof(String)) + { + if (value is null) return isNullable ? "null" : "''"; return "'" + value.ToString().Replace("'", "''") + "'"; } - else if (field.DataType == typeof(Boolean)) + if (type == typeof(DateTime)) + { + if (value == null) return isNullable ? "null" : "''"; + var dt = Convert.ToDateTime(value); + + if (isNullable && (dt <= DateTime.MinValue || dt >= DateTime.MaxValue)) return "null"; + + return FormatDateTime(dt); + } + if (type == typeof(Boolean)) { - return (Boolean)value ? "true" : "false"; + if (value == null) return isNullable ? "null" : ""; + return Convert.ToBoolean(value) ? "true" : "false"; } - return base.FormatValue(field, value); + if (type == typeof(Byte[])) + { + if (value is not Byte[] bts || bts.Length <= 0) return isNullable ? "null" : "0x0"; + + return "0x" + BitConverter.ToString(bts).Replace("-", null); + } + if (type == typeof(Guid)) + { + if (value == null) return isNullable ? "null" : "''"; + + return $"'{value}'"; + } + + if (value == null) return isNullable ? "null" : ""; + // 枚举 + if (type != null && type.IsEnum) type = typeof(Int32); + + // 转为目标类型,比如枚举转为数字 + if (type != null) value = value.ChangeType(type); + if (value == null) return isNullable ? "null" : ""; + + return value.ToString(); } /// 长文本长度 From c88bab9d99d64fd90a80ffd09de4cc0ad84dc0f9 Mon Sep 17 00:00:00 2001 From: Soar360 Date: Fri, 13 Sep 2024 20:44:58 +0800 Subject: [PATCH 3/7] =?UTF-8?q?=E4=BC=98=E5=8C=96=20Byte[]=20=E7=B1=BB?= =?UTF-8?q?=E5=9E=8B=E7=9A=84=E5=A4=84=E7=90=86?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- XCode/DataAccessLayer/Database/PostgreSQL.cs | 16 ++++++++-------- 1 file changed, 8 insertions(+), 8 deletions(-) diff --git a/XCode/DataAccessLayer/Database/PostgreSQL.cs b/XCode/DataAccessLayer/Database/PostgreSQL.cs index ebe61cb34..8759dafff 100644 --- a/XCode/DataAccessLayer/Database/PostgreSQL.cs +++ b/XCode/DataAccessLayer/Database/PostgreSQL.cs @@ -93,18 +93,18 @@ public override String FormatKeyWord(String keyWord) public override String FormatValue(IDataColumn? column, Object? value) { var isNullable = true; - var isArray = false; + var isArrayField = false; Type? type = null; if (column != null) { type = column.DataType; isNullable = column.Nullable; - isArray = column.IsArray; + isArrayField = column.IsArray; } else if (value != null) { type = value.GetType(); - isArray = type.IsArray; + isArrayField = type.IsArray; } // 如果类型是Nullable的,则获取对应的类型 @@ -112,14 +112,14 @@ public override String FormatValue(IDataColumn? column, Object? value) //如果是数组,就取数组的元素类型 if (type?.IsArray == true) { - var element = type.GetElementType(); - if (element != typeof(byte))//blob类型需要特殊处理 + //Byte[] 数组可能是 Blob,不应该当作数组字段处理 + if (column?.IsArray == true || type != typeof(Byte[])) { - isArray = true; - type = element; + isArrayField = true; + type = type.GetElementType(); } } - if (isArray) + if (isArrayField) { if (value is null) return isNullable ? "NULL" : "ARRAY[]"; var count = 0; From 2d73587d8ae7b90ca94144fbd1d6d1471f3335f5 Mon Sep 17 00:00:00 2001 From: Soar360 Date: Fri, 13 Sep 2024 20:56:40 +0800 Subject: [PATCH 4/7] autoincrementing eight-byte integer --- XCode/DataAccessLayer/Database/PostgreSQL.cs | 9 ++++++++- 1 file changed, 8 insertions(+), 1 deletion(-) diff --git a/XCode/DataAccessLayer/Database/PostgreSQL.cs b/XCode/DataAccessLayer/Database/PostgreSQL.cs index 8759dafff..ad8f5c0d2 100644 --- a/XCode/DataAccessLayer/Database/PostgreSQL.cs +++ b/XCode/DataAccessLayer/Database/PostgreSQL.cs @@ -468,7 +468,14 @@ protected override void FixField(IDataColumn field, DataRow dr) public override String FieldClause(IDataColumn field, Boolean onlyDefine) { - if (field.Identity) return $"{FormatName(field)} serial NOT NULL"; + if (field.Identity) + { + if (field.DataType == typeof(Int64)) + { + return $"{FormatName(field)} serial8 NOT NULL"; + } + return $"{FormatName(field)} serial NOT NULL"; + } var sql = base.FieldClause(field, onlyDefine); From 97a9818e3dfd6e2a4a7c3320f35ac64a4ba25a6c Mon Sep 17 00:00:00 2001 From: Soar360 Date: Fri, 13 Sep 2024 21:41:54 +0800 Subject: [PATCH 5/7] =?UTF-8?q?PostgreSQL=20=E6=94=AF=E6=8C=81=E8=8E=B7?= =?UTF-8?q?=E5=8F=96=E8=A1=A8=E5=92=8C=E5=88=97=E7=9A=84=E6=B3=A8=E9=87=8A?= =?UTF-8?q?=E3=80=82?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- XCode/DataAccessLayer/Database/PostgreSQL.cs | 71 ++++++++++++++++++++ 1 file changed, 71 insertions(+) diff --git a/XCode/DataAccessLayer/Database/PostgreSQL.cs b/XCode/DataAccessLayer/Database/PostgreSQL.cs index ad8f5c0d2..3765b7380 100644 --- a/XCode/DataAccessLayer/Database/PostgreSQL.cs +++ b/XCode/DataAccessLayer/Database/PostgreSQL.cs @@ -564,4 +564,75 @@ public override String CreateTableSQL(IDataTable table) public override String DropColumnDescriptionSQL(IDataColumn field) => $"Comment On Column {FormatName(field.Table)}.{FormatName(field)} is ''"; #endregion 架构定义 + + #region 表构架 + protected override List OnGetTables(String[]? names) + { + var tables = base.OnGetTables(names); + var session = Database.CreateSession(); + using var _ = session.SetShowSql(false); + const string sql = @"with tables as ( + select c + .oid, + ns.nspname as schema_name, + c.relname as table_name, + d.description as table_description, + pg_get_userbyid ( c.relowner ) as table_owner + from + pg_catalog.pg_class + as c join pg_catalog.pg_namespace as ns on c.relnamespace = ns. + oid left join pg_catalog.pg_description d on c.oid = d.objoid + and d.objsubid = 0 + where + ns.nspname not in ( 'pg_catalog' ) +) select +c.table_name as table_name, +t.table_description, +c.column_name as column_name, +c.ordinal_position, +d.description as column_description +from + tables + t join information_schema.columns c on c.table_schema = t.schema_name + and c.table_name = t. + table_name left join pg_catalog.pg_description d on d.objoid = t.oid + and d.objsubid = c.ordinal_position + and d.objsubid > 0 +where + c.table_schema = 'public' +order by + t.schema_name, + t.table_name, + c.ordinal_position"; + var ds = session.Query(sql); + if (ds.Tables.Count != 0) + { + var dt = ds.Tables[0]!; + foreach (var table in tables) + { + var rows = dt.Select($"table_name = '{table.TableName}'"); + if (rows is { Length: > 0 }) + { + if (string.IsNullOrWhiteSpace(table.Description)) + { + foreach (var row in rows) + { + table.Description = Convert.ToString(row["table_description"]); + break; + } + } + foreach (var row in rows) + { + string columnName = Convert.ToString(row["column_name"]); + if (string.IsNullOrWhiteSpace(columnName)) continue; + var col = table.GetColumn(columnName); + if (col == null) continue; + if (string.IsNullOrWhiteSpace(col.Description)) col.Description = Convert.ToString(row["column_description"]); + } + } + } + } + return tables; + } + #endregion } \ No newline at end of file From 6f90ce153f9c0bead004e9116065fdac5456f264 Mon Sep 17 00:00:00 2001 From: Soar360 Date: Fri, 13 Sep 2024 21:57:48 +0800 Subject: [PATCH 6/7] =?UTF-8?q?pgsql=20=E6=94=AF=E6=8C=81=E4=BB=8E?= =?UTF-8?q?=E6=95=B0=E6=8D=AE=E5=BA=93=E6=8E=A8=E5=AF=BC=20C#=20=E6=95=B0?= =?UTF-8?q?=E7=BB=84=E7=B1=BB=E5=9E=8B?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- XCode/DataAccessLayer/Database/PostgreSQL.cs | 13 +++++++++++++ 1 file changed, 13 insertions(+) diff --git a/XCode/DataAccessLayer/Database/PostgreSQL.cs b/XCode/DataAccessLayer/Database/PostgreSQL.cs index 3765b7380..a79072fc1 100644 --- a/XCode/DataAccessLayer/Database/PostgreSQL.cs +++ b/XCode/DataAccessLayer/Database/PostgreSQL.cs @@ -420,6 +420,19 @@ internal class PostgreSQLMetaData : RemoteDbMetaData protected override String? ArrayTypePostfix => "[]"; + protected override Type? GetDataType(IDataColumn field) + { + var postfix = this.ArrayTypePostfix!; + if (field.RawType?.EndsWith(postfix) == true) + { + field.IsArray = true; + var clone = field.Clone(field.Table); + clone.RawType = field.RawType.Substring(0, field.RawType.Length - postfix.Length); + var type = base.GetDataType(clone); + if (type != null) return type.MakeArrayType(); + } + return base.GetDataType(field); + } #endregion 数据类型 protected override void FixTable(IDataTable table, DataRow dr, IDictionary data) From a15d5322523525d36b885f02acebab3f5c3955c1 Mon Sep 17 00:00:00 2001 From: Soar360 Date: Sat, 14 Sep 2024 10:33:27 +0800 Subject: [PATCH 7/7] PostgreSQLSession.Upsert --- XCode/DataAccessLayer/Database/PostgreSQL.cs | 114 +++++++++++++++---- 1 file changed, 92 insertions(+), 22 deletions(-) diff --git a/XCode/DataAccessLayer/Database/PostgreSQL.cs b/XCode/DataAccessLayer/Database/PostgreSQL.cs index a79072fc1..c4bad4988 100644 --- a/XCode/DataAccessLayer/Database/PostgreSQL.cs +++ b/XCode/DataAccessLayer/Database/PostgreSQL.cs @@ -336,19 +336,11 @@ public override Task InsertAndGetIdentityAsync(String sql, CommandType ty #region 批量操作 - /* - insert into stat (siteid,statdate,`count`,cost,createtime,updatetime) values - (1,'2018-08-11 09:34:00',1,123,now(),now()), - (2,'2018-08-11 09:34:00',1,456,now(),now()), - (3,'2018-08-11 09:34:00',1,789,now(),now()), - (2,'2018-08-11 09:34:00',1,456,now(),now()) - on duplicate key update - `count`=`count`+values(`count`),cost=cost+values(cost), - updatetime=values(updatetime); - */ - - private String GetBatchSql(String action, IDataTable table, IDataColumn[] columns, ICollection updateColumns, ICollection addColumns, IEnumerable list) + + public override Int32 Insert(IDataTable table, IDataColumn[] columns, IEnumerable list) { + const string action = "Insert Into"; + var sb = Pool.StringBuilder.Get(); var db = Database as DbBase; @@ -361,21 +353,99 @@ private String GetBatchSql(String action, IDataTable table, IDataColumn[] column sb.Append(" Values"); BuildBatchValues(sb, db, action, table, columns, list); - // 重复键执行update - BuildDuplicateKey(sb, db, columns, updateColumns, addColumns); - - return sb.Put(true); - } - - public override Int32 Insert(IDataTable table, IDataColumn[] columns, IEnumerable list) - { - var sql = GetBatchSql("Insert Into", table, columns, null, null, list); + var sql = sb.Put(true); return Execute(sql); } public override Int32 Upsert(IDataTable table, IDataColumn[] columns, ICollection updateColumns, ICollection addColumns, IEnumerable list) { - var sql = GetBatchSql("Insert Into", table, columns, updateColumns, addColumns, list); + /* + * INSERT INTO table_name (列1, 列2, 列3, ...) + * VALUES (值1, 值2, 值3, ...),(值1, 值2, 值3, ...),(值1, 值2, 值3, ...)... + * ON conflict ( 索引列,主键或者唯一索引 ) + * DO UPDATE + * SET 列1 = EXCLUDED.列1, ... + * 列2 = EXCLUDED.列1 + table_name.列2 ... + * ; + */ + const string action = "Insert Into"; + + var sb = Pool.StringBuilder.Get(); + var db = Database as DbBase; + + // 字段列表 + columns ??= table.Columns.ToArray(); + BuildInsert(sb, db, action, table, columns); + DefaultSpan.Current?.AppendTag(sb.ToString()); + + // 值列表 + sb.Append(" Values"); + BuildBatchValues(sb, db, action, table, columns, list); + + if (updateColumns is { Count: > 0 } || addColumns is { Count: > 0 }) + { + //取唯一索引或主键 + var keys = table.PrimaryKeys.Select(f => f.ColumnName).ToArray(); + foreach (var idx in table.Indexes) + { + if (idx.Unique && idx.Columns is { Length: > 0 }) + { + if (idx.Columns.All(c => columns.Any(f => f.ColumnName == c))) + { + keys = idx.Columns; + break; + } + } + } + + if (keys is { Length: > 0 }) + { + var conflict = string.Join(",", keys.Select(f => db.FormatName(f))); + var tb = db.FormatName(table.TableName); + var setters = new List(columns.Length); + + if (updateColumns is { Count: > 0 }) + { + foreach (var dc in columns) + { + if (dc.Identity || dc.PrimaryKey) continue; + + if (updateColumns.Contains(dc.Name) && (addColumns?.Contains(dc.Name) != true)) + { + if (dc.Nullable) + { + setters.Add(String.Format("{0} = EXCLUDED.{0},", db.FormatName(dc))); + } + else + { + setters.Add(String.Format("{0} = COALESCE(EXCLUDED.{0},{1}.{0}),", db.FormatName(dc), tb)); + } + } + } + } + + if (addColumns is { Count: > 0 }) + { + foreach (var dc in columns) + { + if (dc.Identity || dc.PrimaryKey) continue; + + if (addColumns.Contains(dc.Name)) + { + setters.Add(String.Format("{0} = EXCLUDED.{0} + {1}.{0},", db.FormatName(dc), tb)); + } + } + } + + if (setters.Count != 0) + { + sb.Append($" ON conflict ({conflict}) DO UPDATE SET "); + sb.Append(string.Join(",", setters)); + } + } + } + + var sql = sb.Put(true); return Execute(sql); }