USE [datastage]
GO
/****** Object: StoredProcedure [dbo].[sp_CodeGenerator] Script Date: 09/30/2013 13:20:06 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
— =============================================
— Author: John Olsen
— Create date: 20120323
— Update date: 20120425
— Review date:
— Description: Generate column related t-sql
— and c# code for specified table
— because i have had carpul
— tunnel surgery once already
— =============================================
ALTER PROCEDURE [dbo].[sp_CodeGenerator] ( @tabname varchar(128) )
AS
BEGIN
————————————-
–DECLARE @tabname varchar(128)
–SET @tabname = ‘truck_transfers’
————————————-
SET NOCOUNT ON;
DECLARE @types TABLE ( xtype tinyint
, sql_type varchar(128)
, csharp_type varchar(30)
, db_type varchar(128)
, use_len tinyint
, use_prec tinyint
, use_scale tinyint
, type_class tinyint )
INSERT INTO @types (xtype, sql_type, csharp_type, db_type, use_len, use_prec, use_scale, type_class)
SELECT 127, ‘bigint’, ‘int’, ‘BigInt’,0,0,0,1
UNION SELECT 173, ‘binary’, ‘byte[]’, ‘Binary’,0,0,0,1
UNION SELECT 104, ‘bit’, ‘int’, ‘Bit’,0,0,0,1
UNION SELECT 175, ‘char’, ‘string’, ‘Char’,1,1,0,2
UNION SELECT 40, ‘date’, ‘string’, ‘VarChar’,1,1,0,3
UNION SELECT 61, ‘datetime’, ‘string’, ‘DateTime’,0,0,0,3
UNION SELECT 42, ‘datetime2’, ‘string’, ‘DateTime’,0,0,0,3
UNION SELECT 43, ‘datetimeoffset’, ‘string’, ‘VarChar’,1,1,0,3
UNION SELECT 106, ‘decimal’, ‘float’, ‘Decimal’,0,1,1,1
UNION SELECT 62, ‘float’, ‘float’, ‘Float’,0,1,1,1
UNION SELECT 240, ‘geography’, ‘SqlGeography’, ‘Geography’,0,0,0,4
UNION SELECT 240, ‘geometry’, ‘SqlGeometry’, ‘Geometry’,0,0,0,4
UNION SELECT 240, ‘hierarchyid’, ‘string’, ‘NVarChar’,1,1,0,4
UNION SELECT 34, ‘image’, ‘byte[]’, ‘Image’,0,0,0,4
UNION SELECT 56, ‘int’, ‘int’, ‘Int’,0,0,0,1
UNION SELECT 60, ‘money’, ‘float’, ‘Money’,0,0,0,1
UNION SELECT 239, ‘nchar’, ‘string’, ‘NChar’,1,1,0,2
UNION SELECT 99, ‘ntext’, ‘string’, ‘NText’,0,0,0,2
UNION SELECT 108, ‘numeric’, ‘float’, ‘Decimal’,0,1,1,1
UNION SELECT 231, ‘nvarchar’, ‘string’, ‘NVarChar’,1,1,0,2
UNION SELECT 59, ‘real’, ‘float’, ‘Real’,0,1,1,1
UNION SELECT 58, ‘smalldatetime’, ‘string’, ‘SmallDateTime’,0,0,0,3
UNION SELECT 52, ‘smallint’, ‘int’, ‘SmallInt’,0,0,0,1
UNION SELECT 122, ‘smallmoney’, ‘float’, ‘SmallMoney’,0,0,0,1
UNION SELECT 98, ‘sql_variant’, ‘object’, ‘Variant’,0,0,0,4
UNION SELECT 231, ‘sysname’, ‘string’, ‘VarChar’,1,1,0,2
UNION SELECT 35, ‘text’, ‘string’, ‘Text’,0,0,0,2
UNION SELECT 41, ‘time’, ‘string’, ‘VarChar’,0,0,0,3
UNION SELECT 189, ‘timestamp’, ‘string’, ‘Timestamp’,0,0,0,3
UNION SELECT 48, ‘tinyint’, ‘int’, ‘TinyInt’,0,0,0,1
UNION SELECT 36, ‘uniqueidentifier’, ‘SqlGuid’, ‘UniqueIdentifier’,0,0,0,4
UNION SELECT 165, ‘varbinary’, ‘byte[]’, ‘VarBinary’,1,1,0,4
UNION SELECT 167, ‘varchar’, ‘string’, ‘VarChar’,1,1,0,2
UNION SELECT 241, ‘xml’, ‘string’, ‘Text’,0,0,0,2
–SELECT * FROM @types
DECLARE @cols TABLE ( id int identity(1,1)
, colname varchar(128)
, parmname varchar(128)
, sql_type varchar(128)
, db_type varchar(128)
, csharp_type varchar(30)
)
DECLARE @i int
, @crlf char(2)
, @classname varchar(128)
, @colname varchar(128)
, @parmname varchar(128)
, @sql_type varchar(128)
, @db_type varchar(128)
, @csharp_type varchar(30)
, @s_dec varchar(8000)
, @s_assn varchar(8000)
, @s_assnB varchar(8000)
, @s_collist varchar(8000)
, @s_parmlist varchar(8000)
, @c_dec varchar(8000)
, @c_update varchar(8000)
, @c_pop varchar(8000)
, @c_parm varchar(8000)
SET @crlf = char(13) + char(10)
INSERT INTO @cols ( colname, parmname, sql_type, db_type, csharp_type )
SELECT B.name “colname”
, ‘@’ + B.name “parmname”
, (case when C.use_scale = 1 then C.sql_type + ‘(‘ + cast(B.prec as varchar(30)) + ‘,’ + cast(B.scale as varchar(30)) + ‘)’
when C.use_prec = 1 then C.sql_type + ‘(‘ + (case when B.prec = -1 then ‘max’ else cast(B.prec as varchar(30)) end) + ‘)’
else C.sql_type end) “sql_type”
, (case when C.use_len = 1 and B.prec > 0 then ‘SqlDbType.’ + C.db_type + ‘, ‘ + cast(B.prec as varchar(30))
else ‘SqlDbType.’ + C.db_type end) “db_type”
, C.csharp_type
FROM sysobjects A (NOLOCK)
INNER JOIN syscolumns B (NOLOCK)
ON A.id = B.id
INNER JOIN @types C
ON B.xtype = C.xtype
WHERE A.type = ‘U’
AND A.name = @tabname
ORDER BY A.name ASC
, B.colorder DESC
SELECT @i = max(id)
FROM @cols
SET @classname = dbo.fnTitleCase(@tabname)
SET @s_parmlist = ”
SET @s_collist = ”
SET @s_dec = ”
SET @s_assn = ”
SET @s_assnB = ”
SET @c_dec = ‘ public class ‘ + @classname + ‘DAO : DAO’ + @crlf + ‘ {‘
SET @c_pop = ‘ public void populate(DataRow row)’ + @crlf + ‘ {‘
SET @c_update = ‘ public void update()’ + @crlf + ‘ {‘ + @crlf + ‘ SqlCommand oCmd = new SqlCommand();’ + @crlf + ‘ oCmd.CommandType = CommandType.StoredProcedure;’ + @crlf + ‘ oCmd.CommandText = “pUpdate”;’
SET @c_parm = ”
WHILE @i > 0
BEGIN
SELECT @colname = A.colname
, @parmname = A.parmname
, @sql_type = A.sql_type
, @db_type = A.db_type
, @csharp_type = A.csharp_type
FROM @cols A
WHERE A.id = @i
SET @s_collist += @crlf + ‘ , ‘ + @colname
SET @s_parmlist += @crlf + ‘ , ‘ + @parmname
SET @s_dec += @crlf + ‘ , ‘ + @parmname + ‘ ‘ + @sql_type
SET @s_assn += @crlf + ‘ , A.’ + @colname + ‘ = ‘ + @parmname
SET @s_assnB += @crlf + ‘ , A.’ + @colname + ‘ = B.’ + @colname
SET @c_dec += @crlf + ‘ public ‘ + @csharp_type + ‘ ‘ + @colname + (case when @csharp_type = ‘string’ then ‘ = “”;’ else ‘ = 0;’ end)
SET @c_pop += @crlf + ‘ this.’ + @colname + ‘ = ‘
+ (case when @csharp_type in (‘float’,’int’) then @csharp_type + ‘.Parse(row[“‘ + @colname + ‘”].ToString());’
when @csharp_type in (‘string’) then ‘row[“‘ + @colname + ‘”].ToString();’
else ‘(‘+@csharp_type+’) row[“‘ + @colname + ‘”];’ end )
SET @c_update += @crlf + ‘ oCmd.Parameters.Add(“‘ + @parmname + ‘”, ‘ + @db_type + ‘).Value = this.’ + @colname + ‘;’
SET @i -= 1
END
PRINT @s_collist + @crlf
PRINT @s_parmlist + @crlf
PRINT @s_dec + @crlf
PRINT @s_assn + @crlf + @crlf
PRINT @s_assnB + @crlf + @crlf
PRINT @c_dec + @crlf + @crlf
PRINT @c_pop + @crlf + ‘ }//populate()’ + @crlf + @crlf
PRINT @c_update + @crlf + ‘ }//update()’ + @crlf + @crlf
PRINT @c_parm + @crlf
PRINT ‘ } //’ + @classname
END –sp_CodeGenerator()
Month: April 2012
Cannot insert the value null into column ‘diagram_id’, table dbo.sysdiagrams
Error Condition: Cannot insert the value null into column ‘diagram_id’, table dbo.sysdiagrams
Problem: This sometimes occurs when a SQL Server database is ported from one version to another (such as 2000 to 2005 or 2005 to 2008) or possibly also when using the SSMS for a newer version of SQL Server against and older database.
Fix: Drop and recreated dbo.sysdiagrams making the column diagram_id an identity column.
GO
CREATE TABLE [dbo].[sysdiagrams]
[principal_id] [int] NOT NULL,
[diagram_id] [int] identity(1,1) NOT NULL,
[version] [int] NULL,
[definition] [varbinary](max) NULL
)
GO
NOTE: If you want to preserve the diagrams, then rename the table and create a
new one, then SELECT – INTO to copy the data into the new table.
Problem: Unable to run a query through a linked server SQL Server 2008 R2. This problem occurs with a non-sysadmin account.
Error Message:
Msg 7416, Level 16, State 2, Line 1
Access to the remote server is denied because no login-mapping exists. (Microsoft SQL Server, Error: 7416)
Cause: When creating a linked server with the parameter @provstr and you use a local SQL Server non-admin or non-Windows account, you have to add the parameter “User Name” into the @provstr
Note: Also do not use ‘SQL Server’ (note space) as product name, as you cannot specify a provider or any properties for product ‘SQL Server’
Resolution : Add “User ID=remoteLogin” into the provider string on your linked server
EXEC master.dbo.sp_addlinkedserver @server = N’LinkServerName’, @provider=N’SQLNCLI’,@srvproduct = ‘SQLSERVER’, @provstr=N’SERVER=serverNameInstanceName;User ID=remoteLogin’
EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname = N’LinkServerName’, @locallogin = ‘localLogin’ , @useself = N’False’, @rmtuser = N’remoteLogin’, @rmtpassword = N’*****’
Check:
SELECT * FROM OPENQUERY ([LinkServerName], ‘SELECT * FROM sysobjects’)
Searching Procedures for Key Terms
SELECT name
, object_definition(object_id)
FROM sys.procedures
WHERE object_definition(object_id) LIKE ‘%SomeSearchTerm%’