前往小程序,Get更优阅读体验!
立即前往
首页
学习
活动
专区
工具
TVP
发布
社区首页 >专栏 >sql server根据表中数据生成insert语句

sql server根据表中数据生成insert语句

作者头像
跟着阿笨一起玩NET
发布2018-09-18 16:07:58
1.5K0
发布2018-09-18 16:07:58
举报

几个收藏的根据数据库生成Insert语句的存储过程[修正版]

代码语言:javascript
复制
-- ======================================================
--根据表中数据生成insert语句的存储过程
--建立存储过程,执行spGenInsertSQL 表名
--感谢playyuer
----感谢szyicol
-- ======================================================
CREATE   proc [dbo].[spGenInsertSQL] 
(@tablename varchar(256))
as
begin
  declare @sql varchar(8000)
  declare @sqlValues varchar(8000)
 
  set @sql =' ('
  set @sqlValues = 'values (''+'
  select @sqlValues = @sqlValues + cols + ' + '','' + ' ,@sql = @sql + '[' + name + '],' 
    from 
        (select case 
                  when xtype in (48,52,56,59,60,62,104,106,108,122,127)                                
                       then 'case when ['+ name +'] is null then ''NULL'' else ' + 'cast(['+ name + '] as varchar)'+' end'
                  when xtype in (58,61)
                       then 'case when ['+ name +'] is null then ''NULL'' else '+''''''''' + ' + 'cast(['+ name +'] as varchar)'+ '+'''''''''+' end'
                 when xtype in (167)
                       then 'case when ['+ name +'] is null then ''NULL'' else '+''''''''' + ' + 'replace(['+ name+'],'''''''','''''''''''')' + '+'''''''''+' end'
                  when xtype in (231)
                       then 'case when ['+ name +'] is null then ''NULL'' else '+'''N'''''' + ' + 'replace(['+ name+'],'''''''','''''''''''')' + '+'''''''''+' end'
                  when xtype in (175)
                       then 'case when ['+ name +'] is null then ''NULL'' else '+''''''''' + ' + 'cast(replace(['+ name+'],'''''''','''''''''''') as Char(' + cast(length as varchar)  + '))+'''''''''+' end'
                  when xtype in (239)
                       then 'case when ['+ name +'] is null then ''NULL'' else '+'''N'''''' + ' + 'cast(replace(['+ name+'],'''''''','''''''''''') as Char(' + cast(length as varchar)  + '))+'''''''''+' end'
                  else '''NULL'''
                end as Cols,name
           from syscolumns  
          where id = object_id(@tablename) 
        ) T 
  set @sql ='select ''INSERT INTO ['+ @tablename + ']' + left(@sql,len(@sql)-1)+') ' + left(@sqlValues,len(@sqlValues)-4) + ')'' from '+@tablename
  --print @sql
  exec (@sql)
end

-- ======================================================
--根据表中数据生成insert语句的存储过程
--建立存储过程,执行proc_insert 表名
--感谢Sky_blue
--感谢szyicol
-- ======================================================
CREATE proc [dbo].[proc_insert] (@tablename varchar(256))
as
begin
       set nocount on
       --declare @tablename varchar(256)
       --set @tablename = 'AD'
       declare @sqlstr varchar(4000)
       declare @sqlstr1 varchar(4000)
       declare @sqlstr2 varchar(4000)
       select @sqlstr='select ''insert '+@tablename
 
       select @sqlstr1=''
       select @sqlstr2=' ('
       select @sqlstr1= ' values ( ''+'
       select @sqlstr1=@sqlstr1+col+'+'',''+' ,@sqlstr2=@sqlstr2+ '[' + name + ']' +',' from (select case 
--     when a.xtype =173 then 'case when '+a.name+' is null then ''NULL'' else '+'convert(varchar('+convert(varchar(4),a.length*2+2)+'),'+a.name +')'+' end'
       when a.xtype =104 then 'case when ['+a.name+'] is null then ''NULL'' else '+'convert(varchar(1),['+a.name +'])'+' end'
       when a.xtype =175 then 'case when ['+a.name+'] is null then ''NULL'' else '+'''''''''+'+'replace(['+a.name+'],'''''''','''''''''''')' + '+'''''''''+' end'
       when a.xtype =61  then 'case when ['+a.name+'] is null then ''NULL'' else '+'''''''''+'+'convert(varchar(23),['+a.name +'],121)'+ '+'''''''''+' end'
       when a.xtype =106 then 'case when ['+a.name+'] is null then ''NULL'' else '+'convert(varchar('+convert(varchar(4),a.xprec+2)+'),['+a.name +'])'+' end'
       when a.xtype =62  then 'case when ['+a.name+'] is null then ''NULL'' else '+'convert(varchar(23),['+a.name +'],2)'+' end'
       when a.xtype =56  then 'case when ['+a.name+'] is null then ''NULL'' else '+'convert(varchar(11),['+a.name +'])'+' end'
       when a.xtype =60  then 'case when ['+a.name+'] is null then ''NULL'' else '+'convert(varchar(22),['+a.name +'])'+' end'
       when a.xtype =239 then 'case when ['+a.name+'] is null then ''NULL'' else '+'''''''''+'+'replace(['+a.name+'],'''''''','''''''''''')' + '+'''''''''+' end'
       when a.xtype =108 then 'case when ['+a.name+'] is null then ''NULL'' else '+'convert(varchar('+convert(varchar(4),a.xprec+2)+'),['+a.name +'])'+' end'
       when a.xtype =231 then 'case when ['+a.name+'] is null then ''NULL'' else '+'''''''''+'+'replace(['+a.name+'],'''''''','''''''''''')' + '+'''''''''+' end'
       when a.xtype =59  then 'case when ['+a.name+'] is null then ''NULL'' else '+'convert(varchar(23),['+a.name +'],2)'+' end'
       when a.xtype =58  then 'case when ['+a.name+'] is null then ''NULL'' else '+'''''''''+'+'convert(varchar(23),['+a.name +'],121)'+ '+'''''''''+' end'
       when a.xtype =52  then 'case when ['+a.name+'] is null then ''NULL'' else '+'convert(varchar(12),['+a.name +'])'+' end'
       when a.xtype =122 then 'case when ['+a.name+'] is null then ''NULL'' else '+'convert(varchar(22),['+a.name +'])'+' end'
       when a.xtype =48  then 'case when ['+a.name+'] is null then ''NULL'' else '+'convert(varchar(6),['+a.name +'])'+' end'
--     when a.xtype =165 then 'case when '+a.name+' is null then ''NULL'' else '+'convert(varchar('+convert(varchar(4),a.length*2+2)+'),'+a.name +')'+' end'
       when a.xtype =167 then 'case when ['+a.name+'] is null then ''NULL'' else '+'''''''''+'+'replace(['+a.name+'],'''''''','''''''''''')' + '+'''''''''+' end'
       else '''NULL'''
       end as col,a.colid,a.name
       from syscolumns a where a.id = object_id(@tablename) and a.xtype <>189 and a.xtype <>34 and a.xtype <>35 and  a.xtype <>36
       )t order by colid
       select @sqlstr=@sqlstr+left(@sqlstr2,len(@sqlstr2)-1)+') '+left(@sqlstr1,len(@sqlstr1)-3)+')'' from '+@tablename
       --print @sqlstr
       exec( @sqlstr)
       set nocount off
end

原文:几个收藏的根据数据库生成Insert语句的存储过程

修正了表中的字段如果是SQL中的关键字(如Order)时,生成的脚本执行会出错的bug

本文参与 腾讯云自媒体分享计划,分享自作者个人站点/博客。
原始发表:2013-04-01 ,如有侵权请联系 cloudcommunity@tencent.com 删除

本文分享自 作者个人站点/博客 前往查看

如有侵权,请联系 cloudcommunity@tencent.com 删除。

本文参与 腾讯云自媒体分享计划  ,欢迎热爱写作的你一起参与!

评论
登录后参与评论
0 条评论
热度
最新
推荐阅读
领券
问题归档专栏文章快讯文章归档关键词归档开发者手册归档开发者手册 Section 归档