Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

自动识别Oracle SQL上线文本中的PLSQL程序块 #2071

Merged
merged 19 commits into from
Mar 22, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions sql/engines/oracle.py
Original file line number Diff line number Diff line change
Expand Up @@ -691,6 +691,7 @@ def execute_check(self, db_name=None, sql="", close_conn=True):
critical_ddl_regex = config.get("critical_ddl_regex", "")
p = re.compile(critical_ddl_regex)
check_result.syntax_type = 2 # TODO 工单类型 0、其他 1、DDL,2、DML
sqlitem = None
try:
sqlitemList = get_full_sqlitem_list(sql, db_name)
for sqlitem in sqlitemList:
Expand Down
80 changes: 80 additions & 0 deletions sql/engines/tests.py
Original file line number Diff line number Diff line change
Expand Up @@ -1659,6 +1659,86 @@ def test_execute_check_normal_sql(
self.assertIsInstance(check_result, ReviewSet)
self.assertEqual(check_result.rows[0].__dict__, row.__dict__)

def test_get_sql_first_object_name(self):
"""
测试获取sql文本中的object_name
:return:
"""
new_engine = OracleEngine(instance=self.ins)
sql = """create or replace procedure INSERTUSER
(id IN NUMBER,
name IN VARCHAR2)
is
begin
insert into user1 values(id,name);
end;"""
object_name = new_engine.get_sql_first_object_name(sql)
self.assertEqual(object_name, "INSERTUSER")

@patch(
"sql.engines.oracle.OracleEngine.get_sql_first_object_name",
return_value="INSERTUSER",
)
@patch("sql.engines.oracle.OracleEngine.object_name_check", return_value=True)
def test_execute_check_replace_exist_plsql_object(
self, _get_sql_first_object_name, _object_name_check
):
sql = """create or replace procedure INSERTUSER
(id IN NUMBER,
name IN VARCHAR2)
is
begin
insert into user1 values(id,name);
end;"""
row = ReviewResult(
id=1,
errlevel=1,
stagestatus=""""TRADE".INSERTUSER对象已经存在,请确认是否替换!""",
errormessage=""""TRADE".INSERTUSER对象已经存在,请确认是否替换!""",
sql=sqlparse.format(
sql, strip_comments=True, reindent=True, keyword_case="lower"
),
affected_rows=0,
execute_time=0,
stmt_type="SQL",
object_owner="",
object_type="",
object_name="",
)
new_engine = OracleEngine(instance=self.ins)
check_result = new_engine.execute_check(db_name="TRADE", sql=sql)
self.assertIsInstance(check_result, ReviewSet)
self.assertEqual(check_result.rows[0].__dict__, row.__dict__)

@patch(
"sql.engines.oracle.OracleEngine.get_sql_first_object_name",
return_value="INSERTUSER",
)
@patch("sql.engines.oracle.OracleEngine.object_name_check", return_value=True)
def test_execute_check_exist_plsql_object(
self, _get_sql_first_object_name, _object_name_check
):
sql = """create procedure INSERTUSER
(id IN NUMBER,
name IN VARCHAR2)
is
begin
insert into user1 values(id,name);
end;"""
row = ReviewResult(
id=1,
errlevel=2,
stagestatus=""""TRADE".INSERTUSER对象已经存在!""",
errormessage=""""TRADE".INSERTUSER对象已经存在!""",
sql=sqlparse.format(
sql, strip_comments=True, reindent=True, keyword_case="lower"
),
)
new_engine = OracleEngine(instance=self.ins)
check_result = new_engine.execute_check(db_name="TRADE", sql=sql)
self.assertIsInstance(check_result, ReviewSet)
self.assertEqual(check_result.rows[0].__dict__, row.__dict__)

@patch("cx_Oracle.connect.cursor.execute")
@patch("cx_Oracle.connect.cursor")
@patch("cx_Oracle.connect")
Expand Down
78 changes: 74 additions & 4 deletions sql/utils/sql_utils.py
Original file line number Diff line number Diff line change
Expand Up @@ -149,20 +149,85 @@ def get_base_sqlitem_list(full_sql):

def get_full_sqlitem_list(full_sql, db_name):
"""获取Sql对应的SqlItem列表, 包括PLSQL部分
PLSQL语句块由delimiter $$作为开始间隔符,以$$作为结束间隔符
:param full_sql: 全部sql内容
:return: SqlItem 列表
"""

"""预处理SQL文本,第一步:自动添加PLSQL块结尾标识符
根据PLSQL书写语法,识别结尾符号,在PLSQL语句结尾添加$$符号(单独一行),作为该平台处理PLSQL块结尾标识符
同时需要过滤掉PLSQL块中间可能存在的注释 /* 注释内容 */ 干扰
"""
pattern = r"(;(\s)*\n(/$|/\s))"
full_sql = re.sub(pattern, ";\n/\n$$", full_sql, flags=re.I)

"""预处理SQL文本,第二步:自动添加PLSQL块开始标识符
根据PLSQL书写语法,识别开始符号,在PLSQL语句开始前添加delimiter $$符号(单独一行),作为该平台处理PLSQL块开始标识符
PLSQL块包括:以declare开始的匿名块、以begin开始的匿名块、存储过程、函数、触发器、包以及包体、对象类型以及对象类型体
"""

"""1、调整PLSQL开始部分语句,对于开始部分(如:create or replace procedure)中间可能存在换行的调整为一行,
保证下一步处理中,使用换行分割时,PLSQL开始标识完整的落在一行内
"""
pattern_dict = {
r"(create\s+or\s+replace\s+procedure)": "create or replace procedure",
r"(create\s+or\s+replace\s+function)": "create or replace function",
r"(create\s+or\s+replace\s+trigger)": "create or replace trigger",
r"(create\s+or\s+replace\s+package)": "create or replace package",
r"(create\s+or\s+replace\s+type)": "create or replace type",
r"(create\s+procedure)": "create procedure",
r"(create\s+function)": "create function",
r"(create\s+trigger)": "create trigger",
r"(create\s+package)": "create package",
r"(create\s+type)": "create type",
}

for pattern in pattern_dict:
full_sql = re.sub(pattern, pattern_dict[pattern], full_sql, flags=re.I)

"""2、使用换行符分割SQL文本,逐行处理SQL文本:
识别PLSQL开始语法标识符,在开始标识符前加delimiter $$(独立一行),作为该平台识别PLSQL开始位置的标识符,
同时通过引入is_inside_plsqlblock参数,排除掉那些可能存在于PLSQL程序块内部的开始标识符(declare,begin,create [or replace] xx等)
"""
pre_sql_list = full_sql.split("\n")
full_sql_new = ""
is_inside_plsqlblock = 0

# 逐行处理SQL文本
for line in pre_sql_list:
# 匹配到declare和begin开始的行,同时该行SQL不是处于PLSQL程序块内部的,前面添加delimiter $$标识符(独立一行)
pattern = r"^(declare|begin)"
groups = re.match(pattern, line.lstrip(), re.IGNORECASE)
if groups and is_inside_plsqlblock == 0:
line = "delimiter $$" + "\n" + line
# 修改is_inside_plsqlblock参数为1,标识文本进入PLSQL块内部
is_inside_plsqlblock = 1

# 匹配到create [or replace] function|procedure|trigger|package|type开始的行,同时该行SQL不是处于PLSQL程序块内部的,
# 前面添加delimiter $$标识符(独立一行)
pattern = (
r"^create\s+(or\s+replace\s+)?(function|procedure|trigger|package|type)\s"
)
groups = re.match(pattern, line.lstrip(), re.IGNORECASE)
if groups and is_inside_plsqlblock == 0:
line = "delimiter $$" + "\n" + line
# 修改is_inside_plsqlblock参数为1,标识文本进入PLSQL块内部
is_inside_plsqlblock = 1

# 匹配到内容为$$的行,修改is_inside_plsqlblock参数为0,标识文本跳出PLSQL块
if line.strip() == "$$":
is_inside_plsqlblock = 0
full_sql_new = full_sql_new + line + "\n"

list = []

# 定义开始分隔符,两端用括号,是为了re.split()返回列表包含分隔符
regex_delimiter = r"(delimiter\s*\$\$)"
# 注意:必须把package body置于package之前,否则将永远匹配不上package body
regex_objdefine = r'create\s+or\s+replace\s+(function|procedure|trigger|package\s+body|package|view)\s+("?\w+"?\.)?"?\w+"?[\s+|\(]'
regex_objdefine = r'create\s+or\s+replace\s+(function|procedure|trigger|package\s+body|package|type\s+body|type)\s+("?\w+"?\.)?"?\w+"?[\s+|\(]'
# 对象命名,两端有双引号
regex_objname = r'^".+"$'

sql_list = re.split(pattern=regex_delimiter, string=full_sql, flags=re.I)
sql_list = re.split(pattern=regex_delimiter, string=full_sql_new, flags=re.I)

# delimiter_flag => 分隔符标记, 0:不是, 1:是
# 遇到分隔符标记为1, 则本块SQL要去判断是否有PLSQL内容
Expand Down Expand Up @@ -272,7 +337,9 @@ def get_full_sqlitem_list(full_sql, db_name):

if length > pos + 2:
# 处理$$之后的那些语句, 默认为单条可执行SQL的集合
sql_area = sql[pos + 2 :].strip()
# 创建视图、序列、表,语句作为SQL处理最后如果加了 / ,预处理中会在 / 后一行加$$,
# 这里需要将SQL文本中 /\n$$ 去除后再传给get_base_sqlitem_list函数
sql_area = sql[pos + 2 :].replace("/\n$$", "").strip()
if len(sql_area) > 0:
tmp_list = get_base_sqlitem_list(sql_area)
list.extend(tmp_list)
Expand All @@ -286,6 +353,9 @@ def get_full_sqlitem_list(full_sql, db_name):
delimiter_flag = 0
else:
# 表示当前为以;结尾的正常sql
# 创建视图、序列、表,语句作为SQL处理最后如果加了 / ,预处理中会在 / 后一行加$$,
# 这里需要将SQL文本中 /\n$$ 去除后再传给get_base_sqlitem_list函数
sql = sql.replace("/\n$$", "")
tmp_list = get_base_sqlitem_list(sql)
list.extend(tmp_list)
return list
Expand Down
Loading