Chinaunix首页 | 论坛 | 博客
  • 博客访问: 707864
  • 博文数量: 255
  • 博客积分: 5000
  • 博客等级: 大校
  • 技术积分: 2811
  • 用 户 组: 普通用户
  • 注册时间: 2010-06-09 13:29
个人简介

IT业行者,行者无疆

文章分类

全部博文(255)

文章存档

2011年(121)

2010年(134)

我的朋友

分类: 数据库开发技术

2010-10-07 11:53:06

解密SQL SERVER 2005加密存储过程,函数


2008-05-08 16:32:27

 标签:SERVER SQL 2005 数据库    [推送到技术圈]

SQL SERVER 2005中必须用专用管理连接才可以查看过程过程中用到的表

EGsqlcmd -A

1>use test

2>go

1>sp_decrypt 'p_testa'

2>go

Text
----------------------
Create procedure P_testa

with encryption

as

select * from test

 

create PROCEDURE [dbo].[sp_decrypt]
(@
procedure sysname = NULL)  
AS  
SET NOCOUNT ON  
BEGIN
DECLARE @intProcSpace bigint, @t bigint, @maxColID smallint,@intEncrypted  
tinyint,@procNameLength int  
select @maxColID = max(subobjid),@intEncrypted = imageval FROM  
sys.sysobjvalues
WHERE objid = object_id(@procedure)  
GROUP BY imageval  

select @procNameLength = datalength(@procedure) + 29  
DECLARE @real_01 nvarchar(max)  
DECLARE @fake_01 nvarchar(max)  
DECLARE @fake_encrypt_01 nvarchar(max)  
DECLARE @real_decrypt_01 nvarchar(max),@real_decrypt_01a nvarchar(max)  
declare @objtype varchar(2),@ParentName nvarchar(max)  
select @real_decrypt_01a = ''  
--提取对象的类型如是存储过程还是函数,如果是触发器,还要得到其父对象的名称  
select @objtype=type,@parentname=object_name(parent_object_id)  
from sys.objects where [object_id]=object_id(@procedure)  
-- sys.sysobjvalues里提出加密的imageval记录  
SET @real_01=(SELECT top 1 imageval FROM sys.sysobjvalues WHERE objid =  
object_id(@procedure) and valclass = 1 order by subobjid)  
--创建一个临时表  
create table #output ( [ident] [int] IDENTITY (1, 1) NOT NULL ,  
[real_decrypt]
NVARCHAR(MAX) )  
--开始一个事务,稍后回滚  
BEGIN TRAN  
--更改原始的存储过程,用短横线替换  
if @objtype='P'  
SET @fake_01='ALTER PROCEDURE '+ @procedure +' WITH ENCRYPTION AS  
'+REPLICATE('-', 40003 - @procNameLength)  
else if @objtype='FN'  
SET @fake_01='ALTER FUNCTION '+ @procedure +'() RETURNS INT WITH ENCRYPTION AS BEGIN RETURN 1  
/*'+REPLICATE('*', datalength(@real_01) /2 - @procNameLength)+'*/ END'  
else if @objtype='V'  
SET @fake_01='ALTER view '+ @procedure +' WITH ENCRYPTION AS select 1 as col  
/*'+REPLICATE('*', datalength(@real_01) /2 - @procNameLength)+'*/'  
else if @objtype='TR'  
SET @fake_01='ALTER trigger '+ @procedure +' ON '+@parentname+'WITH ENCRYPTION AFTER INSERT AS RAISERROR (''N'',16,10)  
/*'+REPLICATE('*', datalength(@real_01) /2 - @procNameLength)+'*/'  
EXECUTE (@fake_01)  
--sys.sysobjvalues里提出加密的假的  
SET @fake_encrypt_01=(SELECT top 1 imageval FROM sys.sysobjvalues WHERE objid =  
object_id(@procedure) and valclass = 1 order by subobjid )  
if @objtype='P'  
SET @fake_01='Create PROCEDURE '+ @procedure +' WITH ENCRYPTION AS  
'+REPLICATE('-', 40003 - @procNameLength)  
else if @objtype='FN'  
SET @fake_01='CREATE FUNCTION '+ @procedure +'() RETURNS INT WITH ENCRYPTION AS BEGIN RETURN 1  
/*'+REPLICATE('*', datalength(@real_01) /2 - @procNameLength)+'*/ END'  
else if @objtype='V'  
SET @fake_01='Create view '+ @procedure +' WITH ENCRYPTION AS select 1 as col  
/*'+REPLICATE('*', datalength(@real_01) /2 - @procNameLength)+'*/'  
else if @objtype='TR'  
SET @fake_01='Create trigger '+ @procedure +' ON '+@parentname+'WITH ENCRYPTION AFTER INSERT AS RAISERROR (''N'',16,10)  
/*'+REPLICATE('*', datalength(@real_01) /2 - @procNameLength)+'*/'  
--开始计数  
SET @intProcSpace=1  
--使用字符填充临时变量  
SET @real_decrypt_01 = replicate(N'A', (datalength(@real_01) /2 ))  
--循环设置每一个变量,创建真正的变量  
--每次一个字节  
SET @intProcSpace=1  
--如有必要,遍历每个@real_xx变量并解密  
WHILE @intProcSpace<=(datalength(@real_01)/2)  
BEGIN  
--真的和假的和加密的假的进行异或处理  
SET @real_decrypt_01 = stuff(@real_decrypt_01, @intProcSpace, 1,  
NCHAR(UNICODE(substring(@real_01, @intProcSpace, 1)) ^  
(
UNICODE(substring(@fake_01, @intProcSpace, 1)) ^  
UNICODE(substring(@fake_encrypt_01, @intProcSpace, 1)))))  
SET @intProcSpace=@intProcSpace+1  
END  
--通过sp_helptext逻辑向表#output里插入变量  
insert #output (real_decrypt) select @real_decrypt_01  
-- select real_decrypt AS '#output chek' from #output --测试  
-- -------------------------------------  
--开始从sp_helptext提取  
-- -------------------------------------  
declare @dbname sysname  
,@BlankSpaceAdded
int  
,@BasePos
int  
,@CurrentPos
int  
,@TextLength
int  
,@LineId
int  
,@AddOnLen
int  
,@LFCR
int --回车换行的长度  
,@DefinedLength
int  
,@SyscomText
nvarchar(4000)  
,@Line
nvarchar(255)  
Select @DefinedLength = 255  
SELECT @BlankSpaceAdded = 0 --跟踪行结束的空格。注意Len函数忽略了多余的空格  
CREATE TABLE #CommentText  
(LineId
int  
,
Text nvarchar(255) collate database_default)  
--使用#output代替sys.sysobjvalues  
DECLARE ms_crs_syscom CURSOR LOCAL  
FOR SELECT real_decrypt from #output  
ORDER BY ident  
FOR READ ONLY  
--获取文本  
SELECT @LFCR = 2  
SELECT @LineId = 1  
OPEN ms_crs_syscom  
FETCH NEXT FROM ms_crs_syscom into @SyscomText  
WHILE @@fetch_status >= 0  
BEGIN  
SELECT @BasePos = 1  
SELECT @CurrentPos = 1  
SELECT @TextLength = LEN(@SyscomText)  
WHILE @CurrentPos != 0  
BEGIN  
--通过回车查找行的结束  
SELECT @CurrentPos = CHARINDEX(char(13)+char(10), @SyscomText,  
@BasePos)  
--如果找到回车  
IF @CurrentPos != 0  
BEGIN  
--如果@Lines的长度的新值比设置的大就插入@Lines目前的内容并继续  
While (isnull(LEN(@Line),0) + @BlankSpaceAdded +  
@CurrentPos-@BasePos + @LFCR) > @DefinedLength  
BEGIN  
SELECT @AddOnLen = @DefinedLength-(isnull(LEN(@Line),0) +  
@BlankSpaceAdded)  
INSERT #CommentText VALUES  
( @LineId,  
isnull(@Line, N'') + isnull(SUBSTRING(@SyscomText,  
@BasePos, @AddOnLen), N
''))  
SELECT @Line = NULL, @LineId = @LineId + 1,  
@BasePos = @BasePos + @AddOnLen, @BlankSpaceAdded = 0  
END  
SELECT @Line = isnull(@Line, N'') +  
isnull(SUBSTRING(@SyscomText, @BasePos, @CurrentPos-@BasePos + @LFCR), N'')  
SELECT @BasePos = @CurrentPos+2  
INSERT #CommentText VALUES( @LineId, @Line )  
SELECT @LineId = @LineId + 1  
SELECT @Line = NULL  
END  
ELSE  
--如果回车没找到  
BEGIN  
IF @BasePos <= @TextLength  
BEGIN  
--如果@Lines长度的新值大于定义的长度  
While (isnull(LEN(@Line),0) + @BlankSpaceAdded +  
@TextLength-@BasePos+1 ) > @DefinedLength  
BEGIN  
SELECT @AddOnLen = @DefinedLength -  
(
isnull(LEN(@Line),0) + @BlankSpaceAdded)  
INSERT #CommentText VALUES  
( @LineId,  
isnull(@Line, N'') + isnull(SUBSTRING(@SyscomText,  
@BasePos, @AddOnLen), N
''))  
SELECT @Line = NULL, @LineId = @LineId + 1,  
@BasePos = @BasePos + @AddOnLen, @BlankSpaceAdded =  
0  
END  
SELECT @Line = isnull(@Line, N'') +  
isnull(SUBSTRING(@SyscomText, @BasePos, @TextLength-@BasePos+1 ), N'')  
if LEN(@Line) < @DefinedLength and charindex(' ',  
@SyscomText, @TextLength+1 ) > 0  
BEGIN  
SELECT @Line = @Line + ' ', @BlankSpaceAdded = 1  
END  
END  
END  
END  
FETCH NEXT FROM ms_crs_syscom into @SyscomText  
END  
IF @Line is NOT NULL  
INSERT #CommentText VALUES( @LineId, @Line )  
select Text from #CommentText order by LineId  
CLOSE ms_crs_syscom  
DEALLOCATE ms_crs_syscom  
DROP TABLE #CommentText  
-- -------------------------------------  
--结束从sp_helptext提取  
-- -------------------------------------  
--删除用短横线创建的存储过程并重建原始的存储过程  
ROLLBACK TRAN  
DROP TABLE #output

END

阅读(2828) | 评论(0) | 转发(0) |
给主人留下些什么吧!~~