324 lines
		
	
	
		
			14 KiB
		
	
	
	
		
			Plaintext
		
	
	
			
		
		
	
	
			324 lines
		
	
	
		
			14 KiB
		
	
	
	
		
			Plaintext
		
	
	
<#+
 | 
						|
	public class config
 | 
						|
	{
 | 
						|
        public static readonly string ConnectionString = "Server=106.14.89.110,1435;Database=Test_IRC;User ID=sa;Password=xc@123456;TrustServerCertificate=true";
 | 
						|
        public static readonly string DbDatabase = "Test_IRC";
 | 
						|
        //表名称用字符串,拼接
 | 
						|
        public static readonly string TableName = "UserPassWordLog";
 | 
						|
        //具体文件里面  例如service 可以配置是否分页
 | 
						|
	}
 | 
						|
#>
 | 
						|
<#+ 
 | 
						|
    public class DbHelper
 | 
						|
    {
 | 
						|
        #region GetDbTables
 | 
						|
 | 
						|
		 public static List<string> GetDbTablesNew(string connectionString, string database,string tables = null)
 | 
						|
        { 
 | 
						|
			 if (!string.IsNullOrEmpty(tables))
 | 
						|
            {
 | 
						|
                tables = string.Format(" and obj.name in ('{0}')", tables.Replace(",", "','"));
 | 
						|
            }
 | 
						|
            string sql = string.Format(@"SELECT
 | 
						|
                obj.name tablename
 | 
						|
                from sys.objects obj 
 | 
						|
                inner join dbo.sysindexes idx on obj.object_id=idx.id and idx.indid<=1
 | 
						|
                INNER JOIN sys.schemas schem ON obj.schema_id=schem.schema_id
 | 
						|
                left join sys.extended_properties g ON (obj.object_id = g.major_id AND g.minor_id = 0 AND g.name= 'MS_Description')
 | 
						|
                where type='U' {0} 
 | 
						|
                order by obj.name",tables);
 | 
						|
            DataTable dt = GetDataTable(connectionString, sql);
 | 
						|
            return dt.Rows.Cast<DataRow>().Select(row =>row.Field<string>("tablename")).ToList();
 | 
						|
        }
 | 
						|
 | 
						|
        public static List<DbTable> GetDbTables(string connectionString, string database, string tables = null)
 | 
						|
        {
 | 
						|
 | 
						|
            if (!string.IsNullOrEmpty(tables))
 | 
						|
            {
 | 
						|
                tables = string.Format(" and obj.name in ('{0}')", tables.Replace(",", "','"));
 | 
						|
            }
 | 
						|
            #region SQL
 | 
						|
            string sql = string.Format(@"SELECT
 | 
						|
									obj.name tablename,
 | 
						|
									schem.name schemname,
 | 
						|
									idx.rows,
 | 
						|
									CAST
 | 
						|
									(
 | 
						|
										CASE 
 | 
						|
											WHEN (SELECT COUNT(1) FROM sys.indexes WHERE object_id= obj.OBJECT_ID AND is_primary_key=1) >=1 THEN 1
 | 
						|
											ELSE 0
 | 
						|
										END 
 | 
						|
									AS BIT) HasPrimaryKey                                         
 | 
						|
									from sys.objects obj 
 | 
						|
									inner join dbo.sysindexes idx on obj.object_id=idx.id and idx.indid<=1
 | 
						|
									INNER JOIN sys.schemas schem ON obj.schema_id=schem.schema_id
 | 
						|
									where type='U' {0}
 | 
						|
									order by obj.name", tables);
 | 
						|
            #endregion
 | 
						|
            DataTable dt = GetDataTable(connectionString, sql);
 | 
						|
            return dt.Rows.Cast<DataRow>().Select(row => new DbTable
 | 
						|
            {
 | 
						|
                TableName = row.Field<string>("tablename"),
 | 
						|
                SchemaName = row.Field<string>("schemname"),
 | 
						|
                Rows = row.Field<int>("rows"),
 | 
						|
                HasPrimaryKey = row.Field<bool>("HasPrimaryKey")
 | 
						|
            }).ToList();
 | 
						|
        }
 | 
						|
        #endregion
 | 
						|
 | 
						|
        #region GetDbColumns
 | 
						|
 | 
						|
        public static List<DbColumn> GetDbColumns(string connectionString, string database, string tableName, string schema = "dbo")
 | 
						|
        {
 | 
						|
            #region SQL
 | 
						|
            string sql = string.Format(@"
 | 
						|
                                    WITH indexCTE AS
 | 
						|
                                    (
 | 
						|
	                                    SELECT 
 | 
						|
                                        ic.column_id,
 | 
						|
                                        ic.index_column_id,
 | 
						|
                                        ic.object_id    
 | 
						|
                                        FROM sys.indexes idx
 | 
						|
                                        INNER JOIN sys.index_columns ic ON idx.index_id = ic.index_id AND idx.object_id = ic.object_id
 | 
						|
                                        WHERE  idx.object_id =OBJECT_ID(@tableName) AND idx.is_primary_key=1
 | 
						|
                                    )
 | 
						|
                                    select
 | 
						|
									colm.column_id ColumnID,
 | 
						|
                                    CAST(CASE WHEN indexCTE.column_id IS NULL THEN 0 ELSE 1 END AS BIT) IsPrimaryKey,
 | 
						|
                                    colm.name ColumnName,
 | 
						|
                                    systype.name ColumnType,
 | 
						|
                                    colm.is_identity IsIdentity,
 | 
						|
                                    colm.is_nullable IsNullable,
 | 
						|
                                    cast(colm.max_length as int) ByteLength,
 | 
						|
                                    (
 | 
						|
                                        case 
 | 
						|
                                            when systype.name='nvarchar' and colm.max_length>0 then colm.max_length/2 
 | 
						|
                                            when systype.name='nchar' and colm.max_length>0 then colm.max_length/2
 | 
						|
                                            when systype.name='ntext' and colm.max_length>0 then colm.max_length/2 
 | 
						|
                                            else colm.max_length
 | 
						|
                                        end
 | 
						|
                                    ) CharLength,
 | 
						|
                                    cast(colm.precision as int) Precision,
 | 
						|
                                    cast(colm.scale as int) Scale,
 | 
						|
                                    prop.value Remark
 | 
						|
                                    from sys.columns colm
 | 
						|
                                    inner join sys.types systype on colm.system_type_id=systype.system_type_id and colm.user_type_id=systype.user_type_id
 | 
						|
                                    left join sys.extended_properties prop on colm.object_id=prop.major_id and colm.column_id=prop.minor_id
 | 
						|
                                    LEFT JOIN indexCTE ON colm.column_id=indexCTE.column_id AND colm.object_id=indexCTE.object_id                                        
 | 
						|
                                    where colm.object_id=OBJECT_ID(@tableName)
 | 
						|
                                    order by colm.column_id");
 | 
						|
            #endregion
 | 
						|
            SqlParameter param = new SqlParameter("@tableName", SqlDbType.NVarChar, 100) { Value = string.Format("{0}.{1}", schema, tableName) };
 | 
						|
            DataTable dt = GetDataTable(connectionString, sql, param);
 | 
						|
            return dt.Rows.Cast<DataRow>().Select(row => new DbColumn()
 | 
						|
            {
 | 
						|
                ColumnID = row.Field<int>("ColumnID"),
 | 
						|
                IsPrimaryKey = row.Field<bool>("IsPrimaryKey"),
 | 
						|
                ColumnName = row.Field<string>("ColumnName"),
 | 
						|
                ColumnType = row.Field<string>("ColumnType"),
 | 
						|
                IsIdentity = row.Field<bool>("IsIdentity"),
 | 
						|
                IsNullable = row.Field<bool>("IsNullable"),
 | 
						|
                ByteLength = row.Field<int>("ByteLength"),
 | 
						|
                CharLength = row.Field<int>("CharLength"),
 | 
						|
				Precision=row.Field<int>("Precision"),
 | 
						|
                Scale = row.Field<int>("Scale"),
 | 
						|
                Remark = row["Remark"].ToString()
 | 
						|
            }).ToList();
 | 
						|
        }
 | 
						|
 | 
						|
        #endregion
 | 
						|
 | 
						|
        #region GetDataTable
 | 
						|
 | 
						|
        public static DataTable GetDataTable(string connectionString, string commandText, params SqlParameter[] parms)
 | 
						|
        {
 | 
						|
            using (SqlConnection connection = new SqlConnection(connectionString))
 | 
						|
            {
 | 
						|
                SqlCommand command = connection.CreateCommand();
 | 
						|
                command.CommandText = commandText;
 | 
						|
                command.Parameters.AddRange(parms);
 | 
						|
                SqlDataAdapter adapter = new SqlDataAdapter(command);
 | 
						|
 | 
						|
                DataTable dt = new DataTable();
 | 
						|
                adapter.Fill(dt);
 | 
						|
 | 
						|
                return dt;
 | 
						|
            }
 | 
						|
        }
 | 
						|
 | 
						|
        #endregion
 | 
						|
 | 
						|
	    #region GetPrimaryKey
 | 
						|
        public static string GetPrimaryKey(List<DbColumn> dbColumns)
 | 
						|
        {
 | 
						|
            string primaryKey = string.Empty;
 | 
						|
            if (dbColumns!=null&&dbColumns.Count>0)
 | 
						|
            {
 | 
						|
                foreach (var item in dbColumns)
 | 
						|
                {
 | 
						|
                    if (item.IsPrimaryKey==true)
 | 
						|
                    {
 | 
						|
                        primaryKey = item.ColumnName;
 | 
						|
                    }
 | 
						|
                }
 | 
						|
            }
 | 
						|
            return primaryKey;
 | 
						|
        }
 | 
						|
        #endregion
 | 
						|
    }
 | 
						|
 | 
						|
    #region DbTable
 | 
						|
    public sealed class DbTable
 | 
						|
    {
 | 
						|
        public string TableName { get; set; }
 | 
						|
        public string SchemaName { get; set; }
 | 
						|
        public int Rows { get; set; }
 | 
						|
 | 
						|
        public bool HasPrimaryKey { get; set; }
 | 
						|
    }
 | 
						|
    #endregion
 | 
						|
 | 
						|
    #region DbColumn
 | 
						|
    
 | 
						|
    public sealed class DbColumn
 | 
						|
    {
 | 
						|
        
 | 
						|
        public int ColumnID { get; set; }
 | 
						|
 | 
						|
       
 | 
						|
        public bool IsPrimaryKey { get; set; }
 | 
						|
 | 
						|
        
 | 
						|
        public string ColumnName { get; set; }
 | 
						|
 | 
						|
       
 | 
						|
        public string ColumnType { get; set; }
 | 
						|
 | 
						|
       
 | 
						|
        public string CSharpType
 | 
						|
        {
 | 
						|
            get
 | 
						|
            {
 | 
						|
                return SqlServerDbTypeMap.MapCsharpType(ColumnType);
 | 
						|
            }
 | 
						|
        }
 | 
						|
 | 
						|
        /// <summary>
 | 
						|
        /// 
 | 
						|
        /// </summary>
 | 
						|
        public Type CommonType
 | 
						|
        {
 | 
						|
            get
 | 
						|
            {
 | 
						|
                return SqlServerDbTypeMap.MapCommonType(ColumnType);
 | 
						|
            }
 | 
						|
        }
 | 
						|
 | 
						|
        public int ByteLength { get; set; }
 | 
						|
 | 
						|
        public int CharLength { get; set; }
 | 
						|
 | 
						|
		public int Precision{get;set;}
 | 
						|
        public int Scale { get; set; }
 | 
						|
 | 
						|
        public bool IsIdentity { get; set; }
 | 
						|
 | 
						|
        public bool IsNullable { get; set; }
 | 
						|
 | 
						|
        public string Remark { get; set; }
 | 
						|
    }
 | 
						|
    #endregion
 | 
						|
 | 
						|
    #region SqlServerDbTypeMap
 | 
						|
 | 
						|
    public class SqlServerDbTypeMap
 | 
						|
    {
 | 
						|
        public static string MapCsharpType(string dbtype)
 | 
						|
        {
 | 
						|
            if (string.IsNullOrEmpty(dbtype)) return dbtype;
 | 
						|
            dbtype = dbtype.ToLower();
 | 
						|
            string csharpType = "object";
 | 
						|
            switch (dbtype)
 | 
						|
            {
 | 
						|
                case "bigint": csharpType = "long"; break;
 | 
						|
                case "binary": csharpType = "byte[]"; break;
 | 
						|
                case "bit": csharpType = "bool"; break;
 | 
						|
                case "char": csharpType = "string"; break;
 | 
						|
                case "date": csharpType = "DateTime"; break;
 | 
						|
                case "datetime": csharpType = "DateTime"; break;
 | 
						|
                case "datetime2": csharpType = "DateTime"; break;
 | 
						|
                case "datetimeoffset": csharpType = "DateTimeOffset"; break;
 | 
						|
                case "decimal": csharpType = "decimal"; break;
 | 
						|
                case "float": csharpType = "double"; break;
 | 
						|
                case "image": csharpType = "byte[]"; break;
 | 
						|
                case "int": csharpType = "int"; break;
 | 
						|
                case "money": csharpType = "decimal"; break;
 | 
						|
                case "nchar": csharpType = "string"; break;
 | 
						|
                case "ntext": csharpType = "string"; break;
 | 
						|
                case "numeric": csharpType = "decimal"; break;
 | 
						|
                case "nvarchar": csharpType = "string"; break;
 | 
						|
                case "real": csharpType = "Single"; break;
 | 
						|
                case "smalldatetime": csharpType = "DateTime"; break;
 | 
						|
                case "smallint": csharpType = "short"; break;
 | 
						|
                case "smallmoney": csharpType = "decimal"; break;
 | 
						|
                case "sql_variant": csharpType = "object"; break;
 | 
						|
                case "sysname": csharpType = "object"; break;
 | 
						|
                case "text": csharpType = "string"; break;
 | 
						|
                case "time": csharpType = "TimeSpan"; break;
 | 
						|
                case "timestamp": csharpType = "byte[]"; break;
 | 
						|
                case "tinyint": csharpType = "byte"; break;
 | 
						|
                case "uniqueidentifier": csharpType = "Guid"; break;
 | 
						|
                case "varbinary": csharpType = "byte[]"; break;
 | 
						|
                case "varchar": csharpType = "string"; break;
 | 
						|
                case "xml": csharpType = "string"; break;
 | 
						|
                default: csharpType = "object"; break;
 | 
						|
            }
 | 
						|
            return csharpType;
 | 
						|
        }
 | 
						|
 | 
						|
        public static Type MapCommonType(string dbtype)
 | 
						|
        {
 | 
						|
            if (string.IsNullOrEmpty(dbtype)) return Type.Missing.GetType();
 | 
						|
            dbtype = dbtype.ToLower();
 | 
						|
            Type commonType = typeof(object);
 | 
						|
            switch (dbtype)
 | 
						|
            {
 | 
						|
                case "bigint": commonType = typeof(long); break;
 | 
						|
                case "binary": commonType = typeof(byte[]); break;
 | 
						|
                case "bit": commonType = typeof(bool); break;
 | 
						|
                case "char": commonType = typeof(string); break;
 | 
						|
                case "date": commonType = typeof(DateTime); break;
 | 
						|
                case "datetime": commonType = typeof(DateTime); break;
 | 
						|
                case "datetime2": commonType = typeof(DateTime); break;
 | 
						|
                case "datetimeoffset": commonType = typeof(DateTimeOffset); break;
 | 
						|
                case "decimal": commonType = typeof(decimal); break;
 | 
						|
                case "float": commonType = typeof(double); break;
 | 
						|
                case "image": commonType = typeof(byte[]); break;
 | 
						|
                case "int": commonType = typeof(int); break;
 | 
						|
                case "money": commonType = typeof(decimal); break;
 | 
						|
                case "nchar": commonType = typeof(string); break;
 | 
						|
                case "ntext": commonType = typeof(string); break;
 | 
						|
                case "numeric": commonType = typeof(decimal); break;
 | 
						|
                case "nvarchar": commonType = typeof(string); break;
 | 
						|
                case "real": commonType = typeof(Single); break;
 | 
						|
                case "smalldatetime": commonType = typeof(DateTime); break;
 | 
						|
                case "smallint": commonType = typeof(short); break;
 | 
						|
                case "smallmoney": commonType = typeof(decimal); break;
 | 
						|
                case "sql_variant": commonType = typeof(object); break;
 | 
						|
                case "sysname": commonType = typeof(object); break;
 | 
						|
                case "text": commonType = typeof(string); break;
 | 
						|
                case "time": commonType = typeof(TimeSpan); break;
 | 
						|
                case "timestamp": commonType = typeof(byte[]); break;
 | 
						|
                case "tinyint": commonType = typeof(byte); break;
 | 
						|
                case "uniqueidentifier": commonType = typeof(Guid); break;
 | 
						|
                case "varbinary": commonType = typeof(byte[]); break;
 | 
						|
                case "varchar": commonType = typeof(string); break;
 | 
						|
                case "xml": commonType = typeof(string); break;
 | 
						|
                default: commonType = typeof(object); break;
 | 
						|
            }
 | 
						|
            return commonType;
 | 
						|
        }
 | 
						|
    }
 | 
						|
    #endregion
 | 
						|
 #> |