• Heres a stored procedure I wrote sometime ago to generate get, add or update and delete stored procedures so you get the performance benefit of sps. As the naming convention is common you can generate class code etc. against them. I also use an sp to generate c# or vb class code to interface with the stored procedures. Doing data access in this way is very quick and tends to be bug free first time which is nice, possibly could be extended with your application to insert code specific to tables so that more table specific logic could be included. nb it also needs a stored procedure to retrieve records based on foreign keys.

    Phil Nicholas

     

    if exists(select * from sysobjects where name = 'sp_createStoredProcedures')

    drop procedure sp_createStoredProcedures

    GO

    create procedure sp_createStoredProcedures(@tablename varchar(255), @Encryption bit = 1)

    AS

    BEGIN

    DECLARE @SQL varchar(8000)

    -------------------------

    --select sp 

     SET NOCOUNT ON

     create table #temp(id int not null identity (1,1), txt varchar(8000))

     insert #temp (txt)

     select '--stored procedure to get an individual ' + @tablename + '  record' + @tablename

     insert #temp (txt)

     select 'if exists(select * from sysobjects where name = ''spGet_' + @tablename + ''')'

     insert #temp (txt)

     select 'drop procedure spGet_' + @tablename

     insert #temp (txt)

     select 'GO'

     insert #temp (txt)

     select 'create procedure spGet_' + @tablename

     insert #temp (txt)

     select char(9) + '@' + replace(c.name,' ', '_') + ' ' + t.name + ','

     from sysindexes i

     join sysobjects o on o.ID = i.id

     join sysindexkeys ik on ik.indid = i.indid  and ik.id = i.id

     join syscolumns c on c.id = ik.id  and ik.colid = c.colid

     join systypes t on c.xtype = t.xtype

     where o.name = @tablename AND (I.STATUS & 2048) = 2048

     order by ik.keyno asc

     

     if @@rowcount > 0

      update #temp

      set txt = substring(txt,1,len(txt)-1)

      where [id] = @@identity

     if @Encryption = 1

      insert #temp (txt)

      select 'WITH ENCRYPTION'

     insert #temp (txt)

     select 'AS'

     insert #temp (txt)

     select 'SELECT '

     insert #temp (txt)

     select char(9) + '[' + c.name + '],'

     from sysobjects o join syscolumns c on o.id = c.id

     where  o.name = @tablename

     order by colid asc

     if @@rowcount > 0

      update #temp

      set txt = substring(txt,1,len(txt)-1)

      where [id] = @@identity

     insert #temp (txt)

     select 'FROM '

     insert #temp (txt)

     select CHAR(9) + @tablename

     insert #temp  (txt)

     select 'where '

     insert #temp (txt)

     select char(9) + '[' + c.name + '] = @' + replace(c.name,' ', '_') + ' and'

     from sysindexes i

     join sysobjects o on o.ID = i.id

     join sysindexkeys ik on ik.indid = i.indid  and ik.id = i.id

     join syscolumns c on c.id = ik.id  and ik.colid = c.colid

     join systypes t on c.xtype = t.xtype

     where o.name = @tablename AND (I.STATUS & 2048) = 2048

     order by ik.keyno asc

     if @@rowcount > 0

      update #temp

      set txt = substring(txt,1,len(txt)-4)

      where [id] = @@identity

     insert #temp (txt)

     select 'GO'

     insert #temp (txt) values ('')

    -------------------------

    --delete sp 

     insert #temp (txt)

     select '--stored procedure to delete an individual ' + @tablename + '  record' + @tablename

     insert #temp (txt)

     select 'if exists(select * from sysobjects where name = ''spDelete_' + @tablename + ''')'

     insert #temp (txt)

     select 'drop procedure spDelete_' + @tablename

     insert #temp (txt)

     select 'GO'

     insert #temp (txt)

     select 'create procedure spDelete_' + @tablename

     insert #temp (txt)

     select char(9) + '@' + replace(c.name,' ', '_') + ' ' + t.name + ','

     from sysindexes i

     join sysobjects o on o.ID = i.id

     join sysindexkeys ik on ik.indid = i.indid  and ik.id = i.id

     join syscolumns c on c.id = ik.id  and ik.colid = c.colid

     join systypes t on c.xtype = t.xtype

     where o.name = @tablename AND (I.STATUS & 2048) = 2048

     order by ik.keyno asc

     if @@rowcount > 0

      update #temp

      set txt = substring(txt,1,len(txt)-1)

      where [id] = @@identity

     if @Encryption = 1

      insert #temp (txt)

      select 'WITH ENCRYPTION'

     insert #temp (txt)

     select 'AS'

     insert #temp (txt)

     select 'DELETE '

     insert #temp (txt)

     select 'FROM '

     insert #temp (txt)

     select CHAR(9) + @tablename

     insert #temp  (txt)

     select 'WHERE '

     insert #temp (txt)

     select char(9) + '[' + c.name + '] = @' + replace(c.name,' ', '_') + ' AND'

     from sysindexes i

     join sysobjects o on o.ID = i.id

     join sysindexkeys ik on ik.indid = i.indid  and ik.id = i.id

     join syscolumns c on c.id = ik.id  and ik.colid = c.colid

     join systypes t on c.xtype = t.xtype

     where o.name = @tablename AND (I.STATUS & 2048) = 2048

     order by ik.keyno asc

     if @@rowcount > 0

      update #temp

      set txt = substring(txt,1,len(txt)-4)

      where [id] = @@identity

     insert #temp (txt)

     select 'GO'

     insert #temp (txt) values ('')

    --sp_help tblpupil_key_indicators

    -------------------------

    --update/insert sp 

     insert #temp (txt)

     select '--stored procedure to insert/add an individual ' + @tablename + '  record' + @tablename

     insert #temp (txt)

     select 'if exists(select * from sysobjects where name = ''spAddUpdate_' + @tablename + ''')'

     insert #temp (txt)

     select 'drop procedure spAddUpdate_' + @tablename

     insert #temp (txt)

     select 'GO'

     insert #temp (txt)

     select 'create procedure spAddUpdate_' + @tablename

     insert #temp (txt)

     select char(9) + '@' + replace(c.name,' ', '_') + ' ' + t.name +

      case 

       when t.name in ('varchar', 'nvarchar', 'char', 'nchar') then ' (' + cast(c.length as varchar(20)) + ')'

       when t.name in ('decimal') then  ' (' + cast(c.prec as varchar(20)) + ','  + cast(c.scale as varchar(20)) + ')'

       else '' end + ','

     from

     sysobjects o

     join syscolumns c on c.id = o.id

     join systypes t on c.xtype = t.xtype

     where o.name = @tablename and NOT c.name LIKE '%_MOD_USER' and NOT c.name like '%_MOD_DATE'

     order by c.colid asc

     if @@rowcount > 0

      update #temp

      set txt = substring(txt,1,len(txt)-1)

      where [id] = @@identity

     if @Encryption = 1

      insert #temp (txt)

      select 'WITH ENCRYPTION'

     insert #temp (txt)

     select 'AS'

     --empty sql string

     set @SQL = ''

    --------do check for keys

    --change to autoval key or primary key

    if exists(select * from sysobjects o join syscolumns c on c.id = o.id where not autoval is null and o.name = @tablename)

     select @SQL = @SQL + 'coalesce(@' + replace(c.name,' ', '_') + ',0) = 0 and '

     from

     sysobjects o

     join syscolumns c on c.id = o.id

     where not c.autoval is null and o.name = @tablename

    else

     select @SQL = @SQL + 'coalesce(@' + replace(c.name,' ', '_') + ',0) = 0 and '

     from sysindexes i

     join sysobjects o on o.ID = i.id

     join sysindexkeys ik on ik.indid = i.indid  and ik.id = i.id

     join syscolumns c on c.id = ik.id  and ik.colid = c.colid

     join systypes t on c.xtype = t.xtype

     where o.name = @tablename AND (I.STATUS & 2048) = 2048

     order by ik.keyno asc

     if @@rowcount > 0

     begin

      set @SQL = 'IF ' + substring(@SQL,1,len(@SQL)-4)

      insert #temp (txt)

      select @SQL

     end

     insert #temp (txt)

     select 'BEGIN'

     --empty sql string

     set @SQL = ''

     --do insert col list

     select @SQL = @SQL + '[' + c.name + '],'

     from

     sysobjects o

     join syscolumns c on c.id = o.id

     join systypes t on c.xtype = t.xtype

     where o.name = @tablename and NOT c.name LIKE '%_MOD_USER' and NOT c.name like '%_MOD_DATE'

     AND COALESCE(AUTOVAL,0)=0

     order by c.colid asc

     --insert param list

     if @SQL<>''

     INSERT #TEMP

     SELECT char(9) + 'INSERT ' + @TableName + '(' + substring(@SQL,1, len(@SQL)-1) + ')'

     --empty sql string

     set @SQL = ''

     --do insert col list

     select @SQL = @SQL + '@' + replace(c.name,' ', '_') + ','

     from

     sysobjects o

     join syscolumns c on c.id = o.id

     join systypes t on c.xtype = t.xtype

     where o.name = @TableName and NOT c.name LIKE '%_MOD_USER' and NOT c.name like '%_MOD_DATE' AND COALESCE(AUTOVAL,0)=0

     order by c.colid asc

     --insert param list

     if @SQL<>''

     INSERT #TEMP (txt)

     SELECT char(9) + 'VALUES (' + substring(@SQL,1, len(@SQL)-1) + ')'

     if EXISTS( select * from  sysobjects o join syscolumns c on c.id = o.id

      where o.name = @tablename AND COALESCE(AUTOVAL,0)>=1)

     insert #temp

     select 'SELECT @@IDENTITY'

     

     insert #temp (txt)

     select 'END'

     INSERT #TEMP (txt)

     SELECT 'ELSE'

     

     INSERT #TEMP (txt)

     SELECT 'UPDATE ' + @tablename + ' SET '

     

     INSERT #TEMP (txt)

     select char(9) + '[' + c.name + '] = @' + replace(c.name,' ', '_') + ','

     from

     sysobjects o

     join syscolumns c on c.id = o.id

     where o.name = @TableName and NOT c.name LIKE '%_MOD_USER' and NOT c.name like '%_MOD_DATE'

     and not exists (select * from sysindexes i join sysindexkeys ik on ik.id = i.id  and ik.indid = i.indid where  (i.status & 2048) = 2048 and ik.colid = c.colid and i.id = o.id)

     and c.autoval is null

     order by c.colid asc

    --select * from sysindexkeys

     if @@rowcount > 0

      if @SQL<>''

       update #temp

       set txt = substring(txt,1,len(txt)-1)

       where [id] = @@identity

     INSERT #TEMP (txt)

     SELECT 'WHERE'

     insert #temp (txt)

     select  char(9) + '[' + c.name + '] = coalesce(@' + replace(c.name,' ', '_') + ',0) and '

     from sysindexes i

     join sysobjects o on o.ID = i.id

     join sysindexkeys ik on ik.indid = i.indid  and ik.id = i.id

     join syscolumns c on c.id = ik.id  and ik.colid = c.colid

     join systypes t on c.xtype = t.xtype

     where o.name = @tablename AND (I.STATUS & 2048) = 2048

     order by ik.keyno asc

     if @@rowcount > 0

      update #temp

      set txt = substring(txt,1,len(txt)-4)

      where [id] = @@identity

     insert #temp (txt)

     select 'GO'

     

     

     insert #temp (txt) values ('')

     select txt from #temp

     order by id asc

     drop table #temp

     SET NOCOUNT OFF

    END

    GO

    exec sp_createStoredProcedures 'sysobjects'

     


    Phil Nicholas