├── README.md ├── install.sql ├── install_unit_tests.sql ├── packages ├── misplaced_hints.plsql ├── plsql_lexer.plsql ├── plsql_parser.bdy ├── plsql_parser.spc ├── statement_classifier.plsql ├── statement_feedback.plsql ├── statement_splitter.plsql ├── statement_terminator.plsql └── syntax_tree.plsql ├── tests ├── misplaced_hints_test.plsql ├── plsql_lexer_test.plsql ├── statement_classifier_test.plsql ├── statement_feedback_test.plsql ├── statement_splitter_test.plsql ├── statement_terminator_test.plsql ├── unit_tests.bdy └── unit_tests.spc ├── types.sql └── uninstall.sql /README.md: -------------------------------------------------------------------------------- 1 | `PLSQL_LEXER` 2.2.0 2 | =================== 3 | 4 | PL/SQL Lexer solves PL/SQL language problems such as tokenizing, splitting, classifying, feedback messages, and removing terminators. 5 | 6 | ## Packages and Types 7 | 8 | **Main Package** 9 | 10 | - *PLSQL_LEXER* - Convert statements into PL/SQL tokens and tokens back into strings. 11 | 12 | **Script Execution Packages** 13 | 14 | - *STATEMENT_CLASSIFIER* - Classify a statement as DDL, PL/SQL, SELECT, ALTER, etc. 15 | - *STATEMENT_FEEDBACK* - Get a message similar to SQL*Plus feedback messages. For example "0 rows created". 16 | - *STATEMENT_SPLITTER* - Split multiple statements into individual statements based on a terminator. 17 | - *STATEMENT_TERMINATOR* - Remove unnecessary terminating semicolon and SQL*Plus delimiters. This prepares a statement to run as dynamic SQL. 18 | 19 | **Code Analysis Packages** 20 | 21 | - *MISPLACED_HINTS* - Find hint in the wrong place. For example, `insert into /*+ append */ ...` is incorrect because the hint should be placed immediately after the `insert`. 22 | 23 | See the top of each file in the packages directory for more thorough documentation. 24 | 25 | **Types** 26 | 27 | See the file types.sql for all the type definitions. The most important type that's central to all programs is TOKEN: 28 | 29 | create or replace type token is object 30 | ( 31 | type varchar2(4000), --String to represent token type. See the constants in PLSQL_LEXER. 32 | value clob, --The text of the token. 33 | line_number number, --The line number the token starts at - useful for printing warning and error information. 34 | column_number number, --The column number the token starts at - useful for printing warning and error information. 35 | first_char_position number, --First character position of token in the whole string - useful for inserting before a token. 36 | last_char_position number, --Last character position of token in the whole string - useful for inserting after a token. 37 | sqlcode number, --Error code of serious parsing problem. 38 | sqlerrm varchar2(4000) --Error message of serious parsing problem. 39 | ); 40 | 41 | ## How to Install 42 | 43 | Click the green "Code" button, click "Download ZIP", extract the files, CD to the directory with those files, connect to SQL*Plus, and run these commands: 44 | 45 | 1. Create objects and packages on the desired schema: 46 | 47 | alter session set current_schema=&schema_name; 48 | @install 49 | 50 | 2. Install unit tests (optional): 51 | 52 | alter session set current_schema=&schema_name; 53 | @install_unit_tests 54 | 55 | ## How to uninstall 56 | 57 | alter session set current_schema=&schema_name; 58 | @uninstall 59 | 60 | ## Simple Example 61 | 62 | Statement classifier can determine the command name for even the weirdest SQL 63 | statement. Most people code this with a regular expression. But a regular 64 | expression cannot accurately classify non-trivial SQL statements. 65 | 66 | SQL> select statement_classifier.get_command_name('/**/((select * from dual))') command_name 67 | 2 from dual; 68 | 69 | COMMAND_NAME 70 | ------------------------------ 71 | SELECT 72 | 73 | 1 row selected. 74 | 75 | ## Complex Example 76 | 77 | PLSQL_LEXER provides functionality for handling groups of statements. This can 78 | be useful for a patch system, a logging utility, or a private SQL Fiddle. 79 | 80 | The example below shows almost all of the steps to build the backend for a 81 | private SQL Fiddle: a website where users enter "a bunch of statements" in a 82 | window and Oracle must run and report on their success. The basic steps are: 83 | 84 | 1. split the string into multiple statements and loop through them 85 | 2. classify statement, for example to disallow anonymous PL/SQL blocks 86 | 3. remove semicolons from some statements to prepare them for dynamic SQL 87 | 4. Run each statement 88 | 5. Report on the success or failure of each statement 89 | 90 | After following the installation steps above this code should be runnable: 91 | 92 | declare 93 | --A collection of statements separated by semicolons. 94 | --These may come from a website, text file, etc. 95 | v_statements clob := q'< 96 | create table my_table(a number); 97 | insert into my_table values(1); 98 | begin null; end; 99 | udpate my_table set a = 2; 100 | >'; 101 | 102 | v_split_statements token_table_table; 103 | v_category varchar2(100); 104 | v_statement_type varchar2(100); 105 | v_command_name varchar2(64); 106 | v_command_type number; 107 | v_lex_sqlcode number; 108 | v_lex_sqlerrm varchar2(4000); 109 | begin 110 | --Tokenize and split the string into multiple statements. 111 | v_split_statements := statement_splitter.split_by_semicolon( 112 | plsql_lexer.lex(v_statements)); 113 | 114 | --Loop through the statements. 115 | for i in 1 .. v_split_statements.count loop 116 | --Classify each statement. 117 | statement_classifier.classify( 118 | p_tokens => v_split_statements(i), 119 | p_category => v_category, 120 | p_statement_type => v_statement_type, 121 | p_command_name => v_command_name, 122 | p_command_type => v_command_type, 123 | p_lex_sqlcode => v_lex_sqlcode, 124 | p_lex_sqlerrm => v_lex_sqlerrm 125 | ); 126 | 127 | --For debugging, print the statement and COMMAND_NAME. 128 | dbms_output.put_line(chr(10)||'Statement '||i||' : '|| 129 | replace(replace( 130 | plsql_lexer.concatenate(v_split_statements(i)) 131 | ,chr(10)), chr(9))); 132 | dbms_output.put_line('Command Name: '||v_command_name); 133 | 134 | --Handle different command types. 135 | -- 136 | --Prevent Anonymous Blocks from running. 137 | if v_command_name = 'PL/SQL EXECUTE' then 138 | dbms_output.put_line('Error : Anonymous PL/SQL blocks not allowed.'); 139 | --Warning message if "Invalid" - probably a typo. 140 | elsif v_command_name = 'Invalid' then 141 | dbms_output.put_line('Warning : Could not classify this statement, '|| 142 | 'please check for a typo: '|| 143 | replace(replace(substr( 144 | plsql_lexer.concatenate(v_split_statements(i)) 145 | , 1, 30), chr(10)), chr(9))); 146 | --Warning message if "Nothing" 147 | elsif v_command_name = 'Nothing' then 148 | dbms_output.put_line('No statements found.'); 149 | --Run everything else. 150 | else 151 | declare 152 | v_success_message varchar2(4000); 153 | v_compile_warning_message varchar2(4000); 154 | begin 155 | --Remove extra semicolons and run. 156 | execute immediate to_clob(plsql_lexer.concatenate( 157 | statement_terminator.remove_semicolon( 158 | p_tokens => v_split_statements(i)))); 159 | --Get the feedback message. 160 | statement_feedback.get_feedback_message( 161 | p_tokens => v_split_statements(i), 162 | p_rowcount => sql%rowcount, 163 | p_success_message => v_success_message, 164 | p_compile_warning_message => v_compile_warning_message 165 | ); 166 | --Print success message. 167 | dbms_output.put_line('Status : '||v_success_message); 168 | --Print compile warning message, if any. 169 | --This happens when objects successfully compile but are invalid. 170 | if v_compile_warning_message is not null then 171 | dbms_output.put_line('Compile warning: '||v_compile_warning_message); 172 | end if; 173 | exception when others then 174 | dbms_output.put_line('Error : '||dbms_utility.format_error_stack|| 175 | dbms_utility.format_error_backtrace); 176 | end; 177 | end if; 178 | end loop; 179 | end; 180 | / 181 | 182 | Results: 183 | 184 | Statement 1 : create table my_table(a number); 185 | Command Name: CREATE TABLE 186 | Status : Table created. 187 | 188 | Statement 2 : insert into my_table values(1); 189 | Command Name: INSERT 190 | Status : 1 row created. 191 | 192 | Statement 3 : begin null; end; 193 | Command Name: PL/SQL EXECUTE 194 | Error : Anonymous PL/SQL blocks are not allowed. 195 | 196 | Statement 4 : udpate my_table set a = 2; 197 | Command Name: Invalid 198 | Warning : Could not classify this statement, please check for a typo: udpate my_table set a = 2; 199 | 200 | ## License 201 | `plsql_lexer` is licensed under the LGPL. 202 | -------------------------------------------------------------------------------- /install.sql: -------------------------------------------------------------------------------- 1 | --Purpose: Install PLSQL_LEXER. 2 | --How to run: 3 | -- alter session set current_schema=&schema_name; 4 | -- @install 5 | 6 | --#1: Stop the script at first error, make the installation less noisy. 7 | whenever sqlerror exit failure 8 | whenever oserror exit failure 9 | set feedback off 10 | 11 | 12 | --#2: Installation banner 13 | prompt 14 | prompt ============================ 15 | prompt = PLSQL_LEXER Installation = 16 | prompt ============================ 17 | prompt 18 | 19 | 20 | --#3: Quit if program is already installed. 21 | prompt Looking for existing installation... 22 | --Look for type names, throw error if any are found. 23 | declare 24 | v_installed_types varchar2(4000); 25 | begin 26 | select listagg(type_name, ',') within group (order by type_name) 27 | into v_installed_types 28 | from all_types 29 | where type_name in 30 | ( 31 | 'CLOB_TABLE', 'VARCHAR2_TABLE', 32 | 'TOKEN', 'TOKEN_TABLE', 'TOKEN_TABLE_TABLE', 33 | --Parser objects not ready yet: 34 | -- 'NODE', 'NODE_TABLE', 'NUMBER_TABLE', 35 | 'MISPLACED_HINTS_CODE_TYPE', 'MISPLACED_HINTS_CODE_TABLE', 36 | 'MISPLACED_HINTS_SCHEMA_TYPE', 'MISPLACED_HINTS_SCHEMA_TABLE' 37 | ) 38 | and owner = sys_context('userenv', 'current_schema'); 39 | 40 | if v_installed_types is not null then 41 | raise_application_error(-20000, 'Installation failed, the following '|| 42 | 'types already exist. Either run @uninstall.sql or manually remove '|| 43 | 'these types: '||v_installed_types); 44 | end if; 45 | end; 46 | / 47 | 48 | 49 | --#4: Install types. 50 | prompt Installing types... 51 | start types.sql 52 | 53 | 54 | --#5: Install packages. 55 | prompt Installing packages... 56 | 57 | start packages/plsql_lexer.plsql 58 | --Parser objects not ready yet: 59 | --start packages/syntax_tree.plsql 60 | --start packages/plsql_parser.spc 61 | --start packages/plsql_parser.bdy 62 | start packages/statement_classifier.plsql 63 | start packages/statement_splitter.plsql 64 | start packages/statement_feedback.plsql 65 | start packages/statement_terminator.plsql 66 | start packages/misplaced_hints.plsql 67 | 68 | 69 | --#6: Verify installation and print success message. 70 | prompt Verifying installation... 71 | 72 | --Display all invalid objects. 73 | column owner format a30; 74 | column object_name format a30; 75 | column object_type format a13; 76 | 77 | select owner, object_name, object_type 78 | from all_objects 79 | where object_name in 80 | ( 81 | 'PLSQL_LEXER', 'STATEMENT_CLASSIFIER', 'STATEMENT_SPLITTER', 'STATEMENT_FEEDBACK', 'STATEMENT_TERMINATOR', 'MISPLACED_HINTS' 82 | --Parser objects not ready yet: 83 | --,'PLSQL_PARSER', 'SYNTAX_TREE' 84 | ) 85 | and owner = sys_context('userenv', 'current_schema') 86 | and status <> 'VALID'; 87 | 88 | --Raise error if any packages are invalid. 89 | --(Because compilation errors may be "warnings" that won't fail the script.) 90 | declare 91 | v_count number; 92 | begin 93 | select count(*) 94 | into v_count 95 | from all_objects 96 | where object_name in 97 | ( 98 | 'PLSQL_LEXER', 'STATEMENT_CLASSIFIER', 'STATEMENT_SPLITTER', 'STATEMENT_FEEDBACK', 'STATEMENT_TERMINATOR', 'MISPLACED_HINTS' 99 | --Parser objects not ready yet: 100 | --,'PLSQL_PARSER', 'SYNTAX_TREE' 101 | ) 102 | and owner = sys_context('userenv', 'current_schema') 103 | and status <> 'VALID'; 104 | 105 | if v_count >= 1 then 106 | raise_application_error(-20000, 'Installation failed, the above objects '|| 107 | 'are invalid.'); 108 | end if; 109 | end; 110 | / 111 | 112 | 113 | prompt 114 | prompt Installation successful. 115 | 116 | --#7: Return SQL*Plus to normal environment. 117 | whenever sqlerror continue 118 | whenever oserror continue 119 | set feedback on 120 | -------------------------------------------------------------------------------- /install_unit_tests.sql: -------------------------------------------------------------------------------- 1 | --Purpose: Install unit tests for PLSQL_LEXER. 2 | --How to run: 3 | -- alter session set current_schema=&schema_name; 4 | -- @install_unit_tests 5 | 6 | --#1: Stop the script at first error, make the installation less noisy. 7 | whenever sqlerror exit failure 8 | whenever oserror exit failure 9 | set feedback off 10 | 11 | --#2: Installation banner 12 | prompt 13 | prompt ====================================== 14 | prompt = PLSQL_LEXER Unit Test Installation = 15 | prompt ====================================== 16 | prompt 17 | 18 | 19 | --#3: Install packages. 20 | prompt Installing packages... 21 | start tests/unit_tests.spc 22 | start tests/statement_classifier_test.plsql 23 | start tests/statement_feedback_test.plsql 24 | start tests/statement_splitter_test.plsql 25 | start tests/statement_terminator_test.plsql 26 | start tests/plsql_lexer_test.plsql 27 | start tests/misplaced_hints_test.plsql 28 | --Separate spec and body because of circular dependency. 29 | start tests/unit_tests.bdy 30 | 31 | 32 | --#4: Verify installation. 33 | prompt Verifying installation... 34 | 35 | --Display all invalid objects. 36 | column owner format a30; 37 | column object_name format a30; 38 | column object_type format a13; 39 | 40 | select owner, object_name, object_type 41 | from all_objects 42 | where object_name in ('PLSQL_LEXER_TEST', 'STATEMENT_CLASSIFIER_TEST', 'STATEMENT_FEEDBACK_TEST', 43 | 'STATEMENT_SPLITTER_TEST', 'STATEMENT_TERMINATOR_TEST', 'UNIT_TESTS', 'MISPLACED_HINTS_TEST') 44 | and owner = sys_context('userenv', 'current_schema') 45 | and status <> 'VALID'; 46 | 47 | --Raise error if any packages are invalid. 48 | --(Because compilation errors may be "warnings" that won't fail the script.) 49 | declare 50 | v_count number; 51 | begin 52 | select count(*) 53 | into v_count 54 | from all_objects 55 | where object_name in ('PLSQL_LEXER_TEST', 'STATEMENT_CLASSIFIER_TEST', 'STATEMENT_CLASSIFIER_TEST', 56 | 'STATEMENT_SPLITTER_TEST', 'STATEMENT_TERMINATOR_TEST', 'PLSQL_LEXER_TEST', 'MISPLACED_HINTS_TEST') 57 | and owner = sys_context('userenv', 'current_schema') 58 | and status <> 'VALID'; 59 | 60 | if v_count >= 1 then 61 | raise_application_error(-20000, 'Installation failed, the above objects '|| 62 | 'are invalid.'); 63 | end if; 64 | end; 65 | / 66 | 67 | 68 | --#5: Run unit tests and print success message. 69 | prompt Running unit tests, this may take a minute... 70 | set serveroutput on 71 | set linesize 1000 72 | begin 73 | unit_tests.run_static_tests; 74 | end; 75 | / 76 | 77 | prompt 78 | prompt 79 | prompt 80 | prompt 81 | prompt Unit test installation successful. 82 | prompt (But do not trust any packages with a FAIL message above.) 83 | 84 | 85 | --#6: Return SQL*Plus to normal environment. 86 | whenever sqlerror continue 87 | whenever oserror continue 88 | set feedback on 89 | -------------------------------------------------------------------------------- /packages/misplaced_hints.plsql: -------------------------------------------------------------------------------- 1 | create or replace package misplaced_hints authid current_user is 2 | --Copyright (C) 2016 Jon Heller. This program is licensed under the LGPLv3. 3 | 4 | function get_misplaced_hints_in_code(p_text in clob) return misplaced_hints_code_table; 5 | function get_misplaced_hints_in_schema(p_schema in varchar2) return misplaced_hints_schema_table; 6 | 7 | /* 8 | 9 | == Purpose == 10 | 11 | Find misplaced hints. Hints in the wrong place do not generate errors or 12 | warnings, they are simply "ignored". 13 | 14 | Hints should be placed directly after the first keyword. For example: 15 | select --+ parallel(8) ... 16 | insert --+ append ... 17 | 18 | These are invalid hints: 19 | select * --+ parallel(8) ... 20 | insert into --+ append ... 21 | 22 | == Example == 23 | 24 | select * from table(misplaced_hints.get_misplaced_hints_in_schema('TEST_USER')); 25 | 26 | == Parameters == 27 | 28 | P_TEXT - The source code check for bad hints. Can be either SQL or PL/SQL. 29 | P_SCHEMA - The name of the schema to check for bad hints. 30 | */ 31 | 32 | end; 33 | / 34 | create or replace package body misplaced_hints is 35 | 36 | -------------------------------------------------------------------------------- 37 | --Purpose: Get the line with the hint on it. 38 | function get_line(p_tokens token_table, p_hint_index number) return varchar2 is 39 | v_newline_position number; 40 | v_line clob; 41 | 42 | --DBMS_INSTR does not allow negative positions so we must loop through to find the last. 43 | function find_last_newline_position(p_clob in clob) return number is 44 | v_nth number := 1; 45 | v_new_newline_position number; 46 | v_previous_newline_position number; 47 | begin 48 | v_previous_newline_position := dbms_lob.instr(lob_loc => p_clob, pattern => chr(10), nth => v_nth); 49 | 50 | loop 51 | v_nth := v_nth + 1; 52 | v_new_newline_position := dbms_lob.instr(lob_loc => p_clob, pattern => chr(10), nth => v_nth); 53 | 54 | if v_new_newline_position = 0 then 55 | return v_previous_newline_position; 56 | else 57 | v_previous_newline_position := v_new_newline_position; 58 | end if; 59 | end loop; 60 | end find_last_newline_position; 61 | begin 62 | --Get text before index token and after previous newline. 63 | for i in reverse 1 .. p_hint_index - 1 loop 64 | --Look for the last newline. 65 | v_newline_position := find_last_newline_position(p_tokens(i).value); 66 | 67 | --Get everything after newline if there is one, and exit. 68 | if v_newline_position > 0 then 69 | --(If the last character is a newline, the +1 will return null, which is what we want anyway.) 70 | v_line := dbms_lob.substr(lob_loc => p_tokens(i).value, offset => v_newline_position + 1) || v_line; 71 | exit; 72 | --Add entire string to the line if there was no newline. 73 | else 74 | v_line := p_tokens(i).value || v_line; 75 | end if; 76 | end loop; 77 | 78 | --Get text from hint token until the next newline. 79 | for i in p_hint_index .. p_tokens.count loop 80 | v_newline_position := dbms_lob.instr(lob_loc => p_tokens(i).value, pattern => chr(10)); 81 | if v_newline_position = 0 then 82 | v_line := v_line || p_tokens(i).value; 83 | else 84 | v_line := v_line || dbms_lob.substr(lob_loc => p_tokens(i).value, offset => 1, amount => v_newline_position - 1); 85 | exit; 86 | end if; 87 | end loop; 88 | 89 | --Only return the first 4K bytes of data, to fit in SQL varchar2(4000). 90 | return substrb(cast(substr(v_line, 1, 4000) as varchar2), 1, 4000); 91 | end get_line; 92 | 93 | 94 | -------------------------------------------------------------------------------- 95 | --Purpose: Get misplaced hints in a single block of code. 96 | function get_misplaced_hints_in_code(p_text in clob) return misplaced_hints_code_table is 97 | v_tokens token_table; 98 | v_bad_hints misplaced_hints_code_table := misplaced_hints_code_table(); 99 | begin 100 | --Convert to tokens. 101 | v_tokens := plsql_lexer.lex(p_text); 102 | 103 | --Loop through all tokens and build a table of bad hints. 104 | for v_hint_index in 1 .. v_tokens.count loop 105 | 106 | --Examine token stream if this token is a comment and a hint. 107 | if 108 | ( 109 | v_tokens(v_hint_index).type = plsql_lexer.c_comment 110 | and 111 | ( 112 | v_tokens(v_hint_index).value like '/*+%' 113 | or v_tokens(v_hint_index).value like '--+%' 114 | ) 115 | ) then 116 | --Get the previous non-whitespace token. 117 | for v_non_whitespace_index in reverse 1 .. v_hint_index-1 loop 118 | --Stop if subscript is 0 or lower. 119 | if v_non_whitespace_index <= 0 then 120 | exit; 121 | --Stop at first non-whitespace. 122 | elsif v_tokens(v_non_whitespace_index).type <> plsql_lexer.c_whitespace then 123 | --Add to bad tokens if it's not the right SQL keyword. 124 | if upper(v_tokens(v_non_whitespace_index).value) not in ('SELECT', 'INSERT', 'UPDATE', 'DELETE', 'MERGE') then 125 | v_bad_hints.extend; 126 | v_bad_hints(v_bad_hints.count) := misplaced_hints_code_type( 127 | v_tokens(v_hint_index).line_number, 128 | v_tokens(v_hint_index).column_number, 129 | get_line(v_tokens, v_hint_index) 130 | ); 131 | end if; 132 | exit; 133 | end if; 134 | end loop; 135 | end if; 136 | end loop; 137 | 138 | --Return bad hints, if any. 139 | return v_bad_hints; 140 | end get_misplaced_hints_in_code; 141 | 142 | 143 | -------------------------------------------------------------------------------- 144 | --Purpose: Get misplaced hints in all objects in a schema. 145 | function get_misplaced_hints_in_schema(p_schema in varchar2) return misplaced_hints_schema_table is 146 | v_bad_hints_per_schema misplaced_hints_schema_table := misplaced_hints_schema_table(); 147 | 148 | v_bad_hints_per_object misplaced_hints_code_table; 149 | v_code clob; 150 | begin 151 | --Loop through all objects owned by that schema. 152 | for objects in 153 | ( 154 | --Convert ALL_OBJECTS.OBJECT_TYPE to DBMS_METADATA object type. 155 | --Based on http://stackoverflow.com/a/10886633/409172 156 | select 157 | owner, 158 | object_name, 159 | decode(object_type, 160 | 'DATABASE LINK', 'DB_LINK', 161 | 'JAVA CLASS', 'JAVA_CLASS', 162 | 'JAVA RESOURCE', 'JAVA_RESOURCE', 163 | 'JOB', 'PROCOBJ', 164 | 'PACKAGE', 'PACKAGE_SPEC', 165 | 'PACKAGE BODY', 'PACKAGE_BODY', 166 | 'TYPE', 'TYPE_SPEC', 167 | 'TYPE BODY', 'TYPE_BODY', 168 | 'MATERIALIZED VIEW', 'MATERIALIZED_VIEW', 169 | object_type 170 | ) object_type 171 | from all_objects 172 | where owner = upper(trim(p_schema)) 173 | --These objects are included with other object types. 174 | and object_type not in ('INDEX PARTITION','INDEX SUBPARTITION', 'LOB','LOB PARTITION','TABLE PARTITION','TABLE SUBPARTITION') 175 | --These objects cannot have SQL in them: 176 | and object_type not in ('ASSEMBLY', 'INDEX', 'JAVA CLASS', 'JAVA RESOURCE', 'JAVA SOURCE', 'TABLE') 177 | --Ignore system-generated types that support collection processing. 178 | and not (object_type like 'TYPE' and object_name like 'SYS_PLSQL_%') 179 | order by owner, object_name, object_type 180 | ) loop 181 | --Get source code for the object. 182 | v_code := dbms_metadata.get_ddl(objects.object_type, objects.object_name, objects.owner); 183 | 184 | --Get bad hints for that objects. 185 | v_bad_hints_per_object := get_misplaced_hints_in_code(v_code); 186 | 187 | --Add bad hints to the list. 188 | for i in 1 .. v_bad_hints_per_object.count loop 189 | v_bad_hints_per_schema.extend; 190 | v_bad_hints_per_schema(v_bad_hints_per_schema.count) := 191 | misplaced_hints_schema_type( 192 | objects.object_name, 193 | objects.object_type, 194 | --DBMS_METADATA.GET_DDL adds a newline to the beginning. 195 | v_bad_hints_per_object(i).line_number - 1, 196 | v_bad_hints_per_object(i).column_number, 197 | v_bad_hints_per_object(i).line_text 198 | ); 199 | end loop; 200 | end loop; 201 | 202 | --Return bad hints, if any. 203 | return v_bad_hints_per_schema; 204 | end get_misplaced_hints_in_schema; 205 | 206 | end; 207 | / 208 | -------------------------------------------------------------------------------- /packages/plsql_lexer.plsql: -------------------------------------------------------------------------------- 1 | create or replace package plsql_lexer is 2 | --Copyright (C) 2020 Jon Heller. This program is licensed under the LGPLv3. 3 | C_VERSION constant varchar2(10) := '2.0.1'; 4 | 5 | --Main functions: 6 | function lex(p_source in clob) return token_table; 7 | function concatenate(p_tokens in token_table) return clob; 8 | 9 | --Helper functions useful for some tools: 10 | function print_tokens(p_tokens token_table) return clob; 11 | function is_lexical_whitespace(p_char varchar2) return boolean; 12 | function get_varchar2_table_from_clob(p_clob clob) return varchar2_table; 13 | 14 | /* 15 | 16 | == Purpose == 17 | 18 | Tokenize a SQL or PL/SQL statement. 19 | 20 | Tokens may be one of these types: 21 | whitespace 22 | Characters 0,9,10,11,12,13,32,and unistr('\3000') (ideographic space) 23 | comment 24 | Single and multiline. Does not include newline at end of the single line comment 25 | text 26 | Includes quotation marks, alternative quote delimiters, "Q", "N", and "U". 27 | numeric 28 | Everything but initial + or -: ^([0-9]+\.[0-9]+|\.[0-9]+|[0-9]+)((e|E)(\+|-)?[0-9]+)?(f|F|d|D)? 29 | word 30 | May be a keyword, identifier, or (alphabetic) operator. 31 | The parser must distinguish between them because keywords are frequently not reserved. 32 | inquiry_directive 33 | PL/SQL preprocessor (conditional compilation) feature that is like: $$name 34 | preprocessor_control_token 35 | PL/SQL preprocessor (conditional compilation) feature that is like: $plsql_identifier 36 | ,}? 37 | 3-character punctuation operators (Row Pattern Quantifier). 38 | ~= != ^= <> := => >= <= ** || << >> {- -} *? +? ?? ,} }? {, .. 39 | 2-character punctuation operators. 40 | ! $ @ % ^ * ( ) - + = [ ] { } | : ; < , > . / ? 41 | 1-character punctuation operators. 42 | EOF 43 | End of File. 44 | unexpected 45 | Everything else. For example "&", a SQL*Plus character. 46 | 47 | 48 | == Output == 49 | 50 | The most important output is a Token type: 51 | 52 | create or replace type token is object 53 | ( 54 | type varchar2(4000), --String to represent token type. See the constants in PLSQL_LEXER. 55 | value clob, --The text of the token. 56 | line_number number, --The line number the token starts at - useful for printing warning and error information. 57 | column_number number, --The column number the token starts at - useful for printing warning and error information. 58 | first_char_position number, --First character position of token in the whole string - useful for inserting before a token. 59 | last_char_position number, --Last character position of token in the whole string - useful for inserting after a token. 60 | sqlcode number, --Error code of serious parsing problem. 61 | sqlerrm varchar2(4000) --Error message of serious parsing problem. 62 | ); 63 | 64 | 65 | == Requirements == 66 | 67 | - Only 11gR2 and above are supported. But this will likely work well in lower versions. 68 | - EBCDIC character set is not supported. 69 | 70 | 71 | == Example == 72 | 73 | begin 74 | dbms_output.put_line(plsql_lexer.print_tokens(plsql_lexer.lex( 75 | 'select * from dual;' 76 | ))); 77 | end; 78 | 79 | Results: word whitespace * whitespace word whitespace word ; EOF 80 | 81 | */ 82 | 83 | --Constants for token types. 84 | C_WHITESPACE constant varchar2(10) := 'whitespace'; 85 | C_COMMENT constant varchar2(7) := 'comment'; 86 | C_TEXT constant varchar2(4) := 'text'; 87 | C_NUMERIC constant varchar2(7) := 'numeric'; 88 | C_WORD constant varchar2(4) := 'word'; 89 | C_INQUIRY_DIRECTIVE constant varchar2(17) := 'inquiry_directive'; 90 | C_PREPROCESSOR_CONTROL_TOKEN constant varchar2(26) := 'preprocessor_control_token'; 91 | 92 | "C_,}?" constant varchar2(3) := '_,}'; 93 | 94 | "C_~=" constant varchar2(2) := '~='; 95 | "C_!=" constant varchar2(2) := '!='; 96 | "C_^=" constant varchar2(2) := '^='; 97 | "C_<>" constant varchar2(2) := '<>'; 98 | "C_:=" constant varchar2(2) := ':='; 99 | "C_=>" constant varchar2(2) := '=>'; 100 | "C_>=" constant varchar2(2) := '>='; 101 | "C_<=" constant varchar2(2) := '<='; 102 | "C_**" constant varchar2(2) := '**'; 103 | "C_||" constant varchar2(2) := '||'; 104 | "C_<<" constant varchar2(2) := '<<'; 105 | "C_>>" constant varchar2(2) := '>>'; 106 | "C_{-" constant varchar2(2) := '{-'; 107 | "C_-}" constant varchar2(2) := '-}'; 108 | "C_*?" constant varchar2(2) := '*?'; 109 | "C_+?" constant varchar2(2) := '+?'; 110 | "C_??" constant varchar2(2) := '??'; 111 | "C_,}" constant varchar2(2) := ',}'; 112 | "C_}?" constant varchar2(2) := '}?'; 113 | "C_{," constant varchar2(2) := '{,'; 114 | "C_.." constant varchar2(2) := '..'; 115 | 116 | "C_!" constant varchar2(1) := '!'; 117 | "C_@" constant varchar2(1) := '@'; 118 | "C_$" constant varchar2(1) := '$'; 119 | "C_%" constant varchar2(1) := '%'; 120 | "C_^" constant varchar2(1) := '^'; 121 | "C_*" constant varchar2(1) := '*'; 122 | "C_(" constant varchar2(1) := '('; 123 | "C_)" constant varchar2(1) := ')'; 124 | "C_-" constant varchar2(1) := '-'; 125 | "C_+" constant varchar2(1) := '+'; 126 | "C_=" constant varchar2(1) := '='; 127 | "C_[" constant varchar2(1) := '['; 128 | "C_]" constant varchar2(1) := ']'; 129 | "C_{" constant varchar2(1) := '{'; 130 | "C_}" constant varchar2(1) := '}'; 131 | "C_|" constant varchar2(1) := '|'; 132 | "C_:" constant varchar2(1) := ':'; 133 | "C_;" constant varchar2(1) := ';'; 134 | "C_<" constant varchar2(1) := '<'; 135 | "C_," constant varchar2(1) := ','; 136 | "C_>" constant varchar2(1) := '>'; 137 | "C_." constant varchar2(1) := '.'; 138 | "C_/" constant varchar2(1) := '/'; 139 | "C_?" constant varchar2(1) := '?'; 140 | 141 | C_EOF constant varchar2(26) := 'EOF'; 142 | C_unexpected constant varchar2(10) := 'unexpected'; 143 | 144 | /* 145 | Note: 146 | "#" is not included. 147 | The XMLSchema_spec clause in the manual implies that "#" is valid syntax but 148 | testing shows that the "#" must still be enclosed in double quotes. 149 | 150 | */ 151 | 152 | end; 153 | / 154 | create or replace package body plsql_lexer is 155 | 156 | --Globals 157 | 158 | g_chars varchar2_table := varchar2_table(); 159 | g_last_char varchar2(1 char); 160 | g_line_number number; 161 | g_column_number number; 162 | g_last_char_position number; 163 | 164 | --Last non-whitespace, non-comment token. 165 | g_last_concrete_token token; 166 | --Track when we're inside a MATCH_RECOGNIZE and a PATTERN to disambiguate "$". 167 | --"$" is a pattern row when inside, else it could be for conditional compilation 168 | --or an identifier name. 169 | g_match_recognize_paren_count number; 170 | g_pattern_paren_count number; 171 | 172 | 173 | -------------------------------------------------------------------------------- 174 | --Get and consume one character. 175 | function get_char return varchar2 is 176 | begin 177 | --Increment last character counter. 178 | g_last_char_position := g_last_char_position + 1; 179 | 180 | --Increment line and column counters. 181 | if g_last_char = chr(10) then 182 | g_line_number := g_line_number + 1; 183 | g_column_number := 1; 184 | else 185 | g_column_number := g_column_number + 1; 186 | end if; 187 | 188 | --Return character. 189 | if g_last_char_position > g_chars.count then 190 | return null; 191 | else 192 | return g_chars(g_last_char_position); 193 | end if; 194 | end; 195 | 196 | 197 | -------------------------------------------------------------------------------- 198 | --Get but do not consume next character. 199 | function look_ahead(p_offset number) return varchar2 is 200 | begin 201 | if g_last_char_position + p_offset > g_chars.count then 202 | return null; 203 | else 204 | return g_chars(g_last_char_position + p_offset); 205 | end if; 206 | end look_ahead; 207 | 208 | 209 | -------------------------------------------------------------------------------- 210 | --From the current position, return a string that contains all possibly numeric 211 | --characters. The real parsing will be done by a regular expression, but we 212 | --can at least filter out anything that's not one of 0-9,+,-,.,e,E,f,F,d,D 213 | --'^([0-9]+\.[0-9]+|\.[0-9]+|[0-9]+)((e|E)(\+|-)?[0-9]+)?(f|F|d|D)?'); 214 | function get_potential_numeric_string return varchar2 is 215 | v_string varchar2(32767); 216 | v_numeric_position number := g_last_char_position; 217 | begin 218 | loop 219 | exit when v_numeric_position > g_chars.count; 220 | exit when g_chars(v_numeric_position) not in 221 | ( 222 | '0','1','2','3','4','5','6','7','8','9', 223 | '+','-','.','e','E','f','F','d','D' 224 | ); 225 | 226 | v_string := v_string || g_chars(v_numeric_position); 227 | v_numeric_position := v_numeric_position + 1; 228 | end loop; 229 | 230 | return v_string; 231 | end get_potential_numeric_string; 232 | 233 | 234 | -------------------------------------------------------------------------------- 235 | --Is the character alphabetic, in any language. 236 | function is_alpha(p_char varchar2) return boolean is 237 | begin 238 | return regexp_like(p_char, '[[:alpha:]]'); 239 | end is_alpha; 240 | 241 | 242 | -------------------------------------------------------------------------------- 243 | --Is the character alphabetic (in any language), numeric, or one of "_", "#", or "$". 244 | function is_alpha_numeric_or__#$(p_char varchar2) return boolean is 245 | begin 246 | return regexp_like(p_char, '[[:alpha:]]|[0-9]|\_|#|\$'); 247 | end is_alpha_numeric_or__#$; 248 | 249 | 250 | -------------------------------------------------------------------------------- 251 | --Is the character alphabetic (in any language), numeric, or one of "_", or "#". 252 | function is_alpha_numeric_or__#(p_char varchar2) return boolean is 253 | begin 254 | return regexp_like(p_char, '[[:alpha:]]|[0-9]|\_|#'); 255 | end is_alpha_numeric_or__#; 256 | 257 | 258 | -------------------------------------------------------------------------------- 259 | --Track tokens to detect if inside a row pattern matching. 260 | --Row pattern matching introduces some ambiguity because the regular-expression 261 | --syntax conflicts with "$", "**", and "||". 262 | procedure track_row_pattern_matching(p_token token) is 263 | begin 264 | --Start counters. 265 | if p_token.type = '(' 266 | and g_last_concrete_token.type = c_word 267 | and lower(g_last_concrete_token.value) = 'pattern' 268 | and g_match_recognize_paren_count > 0 269 | and g_pattern_paren_count = 0 then 270 | g_pattern_paren_count := 1; 271 | elsif p_token.type = '(' 272 | and g_last_concrete_token.type = c_word 273 | and lower(g_last_concrete_token.value) = 'match_recognize' 274 | and g_match_recognize_paren_count = 0 then 275 | g_match_recognize_paren_count := 1; 276 | --Increment or decrement parentheses counters. 277 | elsif g_pattern_paren_count > 0 and p_token.type = '(' then 278 | g_pattern_paren_count := g_pattern_paren_count + 1; 279 | elsif g_pattern_paren_count > 0 and p_token.type = ')' then 280 | g_pattern_paren_count := g_pattern_paren_count - 1; 281 | elsif g_match_recognize_paren_count > 0 and p_token.type = '(' then 282 | g_match_recognize_paren_count := g_match_recognize_paren_count + 1; 283 | elsif g_match_recognize_paren_count > 0 and p_token.type = ')' then 284 | g_match_recognize_paren_count := g_match_recognize_paren_count - 1; 285 | end if; 286 | end track_row_pattern_matching; 287 | 288 | 289 | -------------------------------------------------------------------------------- 290 | --Return the next token from a string. 291 | --Type is one of: EOF, whitespace, comment, text, numeric, word, or special characters. 292 | --See the package specification for some information on the lexer. 293 | function get_token return token is 294 | v_quote_delimiter varchar2(1 char); 295 | 296 | --Ideally this would be a CLOB but VARCHAR2 performs much better. 297 | --It's extemely unlikely, but possible, for whitespace or text to be more than 32K. 298 | v_token_text varchar2(32767); 299 | --Some types, like multi-line comments, can realisitically be larger than 32k. 300 | v_token_clob clob; 301 | 302 | 303 | v_line_number number; 304 | v_column_number number; 305 | v_first_char_position number; 306 | begin 307 | --Load first character. 308 | if g_last_char_position = 0 then 309 | g_last_char := get_char; 310 | end if; 311 | 312 | --Record variables at the beginning of the token. 313 | v_line_number := g_line_number; 314 | v_column_number := g_column_number; 315 | v_first_char_position := g_last_char_position; 316 | 317 | --Out of characters. 318 | if g_last_char_position > g_chars.count or g_chars.count = 0 then 319 | return token(c_eof, null, v_line_number, v_column_number, v_first_char_position, g_last_char_position, null, null); 320 | end if; 321 | 322 | --Whitespace - don't throw it out, it may contain a hint or help with pretty printing. 323 | if is_lexical_whitespace(g_last_char) then 324 | v_token_text := g_last_char; 325 | loop 326 | g_last_char := get_char; 327 | exit when not is_lexical_whitespace(g_last_char); 328 | v_token_text := v_token_text || g_last_char; 329 | end loop; 330 | return token(c_whitespace, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 331 | end if; 332 | 333 | --Single line comment. 334 | if g_last_char = '-' and look_ahead(1) = '-' then 335 | v_token_text := g_last_char || get_char; 336 | loop 337 | g_last_char := get_char; 338 | --chr(13) by itself does not count. 339 | exit when g_last_char = chr(10) or g_last_char is null; 340 | v_token_text := v_token_text || g_last_char; 341 | end loop; 342 | return token(c_comment, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 343 | end if; 344 | 345 | --Multi-line comment. Use CLOB instead of VARCHAR2 to hold data. 346 | if g_last_char = '/' and look_ahead(1) = '*' then 347 | v_token_clob := g_last_char || get_char; 348 | loop 349 | g_last_char := get_char; 350 | if g_last_char = '*' and look_ahead(1) = '/' then 351 | v_token_clob := v_token_clob || g_last_char; 352 | g_last_char := get_char; 353 | v_token_clob := v_token_clob || g_last_char; 354 | g_last_char := get_char; 355 | exit; 356 | end if; 357 | if look_ahead(1) is null then 358 | v_token_clob := v_token_clob || g_last_char; 359 | g_last_char := get_char; 360 | return token(c_comment, v_token_clob, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, -01742, 'comment not terminated properly'); 361 | end if; 362 | v_token_clob := v_token_clob || g_last_char; 363 | end loop; 364 | return token(c_comment, v_token_clob, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 365 | end if; 366 | 367 | --Text. 368 | if g_last_char = '''' then 369 | v_token_text := g_last_char; 370 | loop 371 | g_last_char := get_char; 372 | --Ignore escaped strings. 373 | if g_last_char = '''' and look_ahead(1) = '''' then 374 | v_token_text := v_token_text || g_last_char; 375 | g_last_char := get_char; 376 | elsif g_last_char = '''' and (look_ahead(1) is null or look_ahead(1) <> '''') then 377 | v_token_text := v_token_text || g_last_char; 378 | g_last_char := get_char; 379 | exit; 380 | elsif look_ahead(1) is null then 381 | v_token_text := v_token_text || g_last_char; 382 | g_last_char := get_char; 383 | return token(c_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, -01756, 'quoted string not properly terminated'); 384 | end if; 385 | v_token_text := v_token_text || g_last_char; 386 | end loop; 387 | return token(c_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 388 | end if; 389 | 390 | --Nvarchar or Unicode text. 391 | if lower(g_last_char) in ('n', 'u') and look_ahead(1) = '''' then 392 | --Consume 2 characters: n and the quote. 393 | v_token_text := g_last_char; 394 | g_last_char := get_char; 395 | v_token_text := v_token_text||g_last_char; 396 | loop 397 | g_last_char := get_char; 398 | --Ignore escaped strings. 399 | if g_last_char = '''' and look_ahead(1) = '''' then 400 | v_token_text := v_token_text || g_last_char; 401 | g_last_char := get_char; 402 | elsif g_last_char = '''' and (look_ahead(1) is null or look_ahead(1) <> '''') then 403 | v_token_text := v_token_text || g_last_char; 404 | g_last_char := get_char; 405 | exit; 406 | elsif look_ahead(1) is null then 407 | v_token_text := v_token_text || g_last_char; 408 | g_last_char := get_char; 409 | return token(c_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, -01756, 'quoted string not properly terminated'); 410 | end if; 411 | v_token_text := v_token_text || g_last_char; 412 | end loop; 413 | return token(c_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 414 | end if; 415 | 416 | --Alternative quoting mechanism. 417 | if lower(g_last_char) = 'q' and look_ahead(1) = '''' then 418 | --Consume 3 characters: q, quote, and the quote delimiter. 419 | v_token_text := g_last_char; 420 | g_last_char := get_char; 421 | v_token_text := v_token_text||g_last_char; 422 | g_last_char := get_char; 423 | v_token_text := v_token_text||g_last_char; 424 | --The ending delimiter is different in a few cases. 425 | v_quote_delimiter := case g_last_char 426 | when '[' then ']' 427 | when '{' then '}' 428 | when '<' then '>' 429 | when '(' then ')' 430 | else g_last_char 431 | end; 432 | 433 | loop 434 | g_last_char := get_char; 435 | if g_last_char = v_quote_delimiter and look_ahead(1) = '''' then 436 | --"Alternative quotes (q'#...#') cannot use spaces, tabs, or carriage returns as delimiters". 437 | --(The error says carriage return, but testing indicates they really mean newlines) 438 | if g_last_char in (chr(9), chr(10), chr(32)) then 439 | v_token_text := v_token_text || g_last_char; 440 | g_last_char := get_char; 441 | v_token_text := v_token_text || g_last_char; 442 | g_last_char := get_char; 443 | return token(c_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, -00911, 'invalid character'); 444 | end if; 445 | 446 | v_token_text := v_token_text || g_last_char; 447 | g_last_char := get_char; 448 | v_token_text := v_token_text || g_last_char; 449 | g_last_char := get_char; 450 | exit; 451 | end if; 452 | if look_ahead(1) is null then 453 | v_token_text := v_token_text || g_last_char; 454 | g_last_char := get_char; 455 | return token(c_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, -01756, 'quoted string not properly terminated'); 456 | end if; 457 | v_token_text := v_token_text || g_last_char; 458 | end loop; 459 | return token(c_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 460 | end if; 461 | 462 | --Nvarchar or Unicode alternative quoting mechanism. 463 | if lower(g_last_char) in ('n', 'u') and lower(look_ahead(1)) = 'q' and look_ahead(2) = '''' then 464 | --Consume 4 characters: n, q, quote, and the quote delimiter. 465 | v_token_text := g_last_char; 466 | g_last_char := get_char; 467 | v_token_text := v_token_text||g_last_char; 468 | g_last_char := get_char; 469 | v_token_text := v_token_text||g_last_char; 470 | g_last_char := get_char; 471 | v_token_text := v_token_text||g_last_char; 472 | --The ending delimiter is different in a few cases. 473 | v_quote_delimiter := case g_last_char 474 | when '[' then ']' 475 | when '{' then '}' 476 | when '<' then '>' 477 | when '(' then ')' 478 | else g_last_char 479 | end; 480 | 481 | loop 482 | g_last_char := get_char; 483 | if g_last_char = v_quote_delimiter and look_ahead(1) = '''' then 484 | --"Alternative quotes (q'#...#') cannot use spaces, tabs, or carriage returns as delimiters". 485 | --(The error says carriage return, but also includes newlines) 486 | if g_last_char in (chr(9), chr(10), chr(32)) then 487 | v_token_text := v_token_text || g_last_char; 488 | g_last_char := get_char; 489 | v_token_text := v_token_text || g_last_char; 490 | g_last_char := get_char; 491 | return token(c_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, -00911, 'invalid character'); 492 | end if; 493 | 494 | v_token_text := v_token_text || g_last_char; 495 | g_last_char := get_char; 496 | v_token_text := v_token_text || g_last_char; 497 | g_last_char := get_char; 498 | exit; 499 | end if; 500 | if look_ahead(1) is null then 501 | v_token_text := v_token_text || g_last_char; 502 | g_last_char := get_char; 503 | return token(c_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, -01756, 'quoted string not properly terminated'); 504 | end if; 505 | v_token_text := v_token_text || g_last_char; 506 | end loop; 507 | return token(c_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 508 | end if; 509 | 510 | --Numeric. 511 | --This follows the BNF diagram, except it doesn't include leading + or -. 512 | --And note that the diagram incorrectly implies '3+3' is a number, 513 | --the (E|e)?(+|-)? is incorrect. 514 | --http://docs.oracle.com/database/121/SQLRF/img/number.gif 515 | if g_last_char between '0' and '9' or (g_last_char = '.' and look_ahead(1) between '0' and '9') then 516 | declare 517 | v_substring varchar2(32767) := get_potential_numeric_string(); 518 | begin 519 | --Note: Combining classes, anchors, and regexp_substr positions other than 1 do not always work. 520 | --Note: This won't work with numbers larger than 1K characters, 521 | --a ridiculous number that would cause a runtime error, but is theoretically valid. 522 | v_token_text := regexp_substr( 523 | v_substring, 524 | '^([0-9]+\.[0-9]+|\.[0-9]+|[0-9]+)((e|E)(\+|-)?[0-9]+)?(f|F|d|D)?'); 525 | end; 526 | 527 | --Advance the characters. 528 | --Regular "length" is fine here since numerics cannot be more than one code point. 529 | g_last_char_position := g_last_char_position + length(v_token_text) - 1; 530 | g_column_number := g_column_number + length(v_token_text) - 1; 531 | 532 | g_last_char := get_char; 533 | return token(c_numeric, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 534 | end if; 535 | 536 | --Word - quoted identifier. Note that quoted identifiers are not escaped. 537 | --Do *not* check for these errors in words: 538 | --"ORA-00972: identifier is too long" or "ORA-01741: illegal zero-length identifier". 539 | --Database links have different rules, like 128 bytes instead of 30, and we 540 | --won't know if it's a database link name until parse time. 541 | if g_last_char = '"' then 542 | v_token_text := g_last_char; 543 | loop 544 | g_last_char := get_char; 545 | if g_last_char = '"'then 546 | v_token_text := v_token_text || g_last_char; 547 | g_last_char := get_char; 548 | exit; 549 | end if; 550 | if look_ahead(1) is null then 551 | v_token_text := v_token_text || g_last_char; 552 | g_last_char := get_char; 553 | return token(c_word, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, -01740, 'missing double quote in identifier'); 554 | end if; 555 | v_token_text := v_token_text || g_last_char; 556 | end loop; 557 | return token(c_word, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 558 | end if; 559 | 560 | --Word. 561 | --Starts with alpha (in any language!), may contain number, "_", "$", and "#". 562 | if is_alpha(g_last_char) then 563 | v_token_text := g_last_char; 564 | loop 565 | g_last_char := get_char; 566 | 567 | --"$" does not count as part of the word when inside a row pattern match. 568 | if g_pattern_paren_count > 0 then 569 | if g_last_char is null or not is_alpha_numeric_or__#(g_last_char) then 570 | exit; 571 | end if; 572 | else 573 | if g_last_char is null or not is_alpha_numeric_or__#$(g_last_char) then 574 | exit; 575 | end if; 576 | end if; 577 | 578 | v_token_text := v_token_text || g_last_char; 579 | end loop; 580 | return token(c_word, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 581 | end if; 582 | 583 | --Inquiry Directive. 584 | --Starts with $$ alpha (in any language!), may contain number, "_", "$", and "#". 585 | if g_last_char = '$' and look_ahead(1) = '$' and is_alpha(look_ahead(2)) then 586 | v_token_text := g_last_char || get_char; 587 | v_token_text := v_token_text || get_char; 588 | loop 589 | g_last_char := get_char; 590 | if g_last_char is null or not is_alpha_numeric_or__#$(g_last_char) then 591 | exit; 592 | end if; 593 | v_token_text := v_token_text || g_last_char; 594 | end loop; 595 | return token(c_inquiry_directive, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 596 | end if; 597 | 598 | --Preprocessor Control Token. 599 | --Starts with $ alpha (in any language!), may contain number, "_", "$", and "#". 600 | if g_last_char = '$' and is_alpha(look_ahead(1)) then 601 | v_token_text := g_last_char || get_char; 602 | loop 603 | g_last_char := get_char; 604 | if g_last_char is null or not is_alpha_numeric_or__#$(g_last_char) then 605 | exit; 606 | end if; 607 | v_token_text := v_token_text || g_last_char; 608 | end loop; 609 | return token(c_preprocessor_control_token, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 610 | end if; 611 | 612 | --3-character punctuation operators. 613 | --12c Row Pattern Quantifiers introduced a lot of regular-expression operators. 614 | if g_last_char||look_ahead(1)||look_ahead(2) in (',}?') then 615 | v_token_text := g_last_char || get_char || get_char; 616 | g_last_char := get_char; 617 | return token(v_token_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 618 | end if; 619 | 620 | --2-character punctuation operators. 621 | --Ignore the IBM "not" character - it's in the manual but is only supported 622 | --on obsolete platforms: http://stackoverflow.com/q/9305925/409172 623 | if g_last_char||look_ahead(1) in ('~=','^=','<>',':=','=>','>=','<=','<<','>>','{-','-}','*?','+?','??',',}','}?','{,','..') then 624 | v_token_text := g_last_char || get_char; 625 | g_last_char := get_char; 626 | return token(v_token_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 627 | end if; 628 | 629 | --Ambiguity - "!=" usually means "not equals to", but the "!" can mean "the database calling the link". For example: 630 | -- select * from dual where sysdate@!=sysdate; Those characters should be separated - "@", "!", and "=". 631 | if g_last_char||look_ahead(1) in ('!=') then 632 | if g_last_concrete_token.type = '@' then 633 | null; 634 | else 635 | v_token_text := g_last_char || get_char; 636 | g_last_char := get_char; 637 | return token(v_token_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 638 | end if; 639 | end if; 640 | 641 | --Ambiguity - "**" and "||" are only 2-character operators outside of row pattern matching. 642 | if g_last_char||look_ahead(1) in ('**','||') and g_pattern_paren_count = 0 then 643 | v_token_text := g_last_char || get_char; 644 | g_last_char := get_char; 645 | return token(v_token_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 646 | end if; 647 | 648 | --1-character punctuation operators. 649 | if g_last_char in ('!', '@','%','^','*','(',')','-','+','=','[',']','{','}','|',':',';','<',',','>','.','/','?') then 650 | v_token_text := g_last_char; 651 | g_last_char := get_char; 652 | return token(v_token_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 653 | end if; 654 | 655 | --"$" only counts as "$" inside row pattern matching. 656 | if g_last_char = '$' and g_pattern_paren_count > 0 then 657 | v_token_text := g_last_char; 658 | g_last_char := get_char; 659 | return token(v_token_text, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 660 | end if; 661 | 662 | --Unexpected - everything else. 663 | v_token_text := g_last_char; 664 | g_last_char := get_char; 665 | return token(c_unexpected, v_token_text, v_line_number, v_column_number, v_first_char_position, g_last_char_position-1, null, null); 666 | end get_token; 667 | 668 | 669 | -------------------------------------------------------------------------------- 670 | --Convert a string into a VARRAY of tokens. 671 | function lex(p_source clob) return token_table is 672 | v_token token; 673 | v_tokens token_table := token_table(); 674 | begin 675 | --Initialize globals. 676 | g_chars := get_varchar2_table_from_clob(p_source); 677 | --set_g_chars(p_source); 678 | g_last_char_position := 0; 679 | g_line_number := 1; 680 | g_column_number := 0; 681 | g_last_concrete_token := token(null, null, null, null, null, null, null, null); 682 | g_match_recognize_paren_count := 0; 683 | g_pattern_paren_count := 0; 684 | 685 | --Get all the tokens. 686 | loop 687 | v_token := get_token; 688 | v_tokens.extend; 689 | v_tokens(v_tokens.count) := v_token; 690 | track_row_pattern_matching(v_token); 691 | if v_token.type not in (c_whitespace, c_comment, c_eof) then 692 | g_last_concrete_token := v_token; 693 | end if; 694 | exit when v_token.type = c_eof; 695 | end loop; 696 | 697 | --Return them. 698 | return v_tokens; 699 | end lex; 700 | 701 | 702 | -------------------------------------------------------------------------------- 703 | --Convert the tokens into an CLOB. 704 | function concatenate(p_tokens in token_table) return clob 705 | is 706 | v_clob clob; 707 | begin 708 | for i in 1 .. p_tokens.count loop 709 | v_clob := v_clob || p_tokens(i).value; 710 | end loop; 711 | 712 | return v_clob; 713 | end concatenate; 714 | 715 | 716 | -------------------------------------------------------------------------------- 717 | --Print tokens for debugging. 718 | function print_tokens(p_tokens token_table) return clob is 719 | v_output clob; 720 | begin 721 | for i in 1 .. p_tokens.count loop 722 | v_output := v_output||' '||p_tokens(i).type; 723 | end loop; 724 | 725 | return substr(v_output, 2); 726 | end print_tokens; 727 | 728 | 729 | -------------------------------------------------------------------------------- 730 | --Is the character white space. 731 | function is_lexical_whitespace(p_char varchar2) return boolean is 732 | begin 733 | /* 734 | --Find single-byte whitespaces. 735 | --ASSUMPTION: There are no 3 or 4 byte white space characters. 736 | declare 737 | c1 varchar2(1); c2 varchar2(1); c3 varchar2(1); c4 varchar2(1); 738 | v_string varchar2(10); 739 | v_throwaway number; 740 | begin 741 | for n1 in 0..15 loop c1 := trim(to_char(n1, 'XX')); 742 | for n2 in 0..15 loop c2 := trim(to_char(n2, 'XX')); 743 | for n3 in 0..15 loop c3 := trim(to_char(n3, 'XX')); 744 | for n4 in 0..15 loop c4 := trim(to_char(n4, 'XX')); 745 | v_string := unistr('\'||c1||c2||c3||c4); 746 | begin 747 | execute immediate 'select 1 a '||v_string||' from dual' into v_throwaway; 748 | dbms_output.put_line('Whitespace character: \'||c1||c2||c3||c4); 749 | exception when others then null; 750 | end; 751 | end loop; end loop; end loop; end loop; 752 | end; 753 | */ 754 | 755 | --These results are not the same as the regular expression "\s". 756 | --There are dozens of Unicode white space characters, but only these 757 | --are considered whitespace in PL/SQL or SQL. 758 | --For performance, list characters in order of popularity, and only use 759 | --UNISTR when necessary. 760 | if p_char in 761 | ( 762 | chr(32),chr(10),chr(9),chr(13),chr(0),chr(11),chr(12),unistr('\3000') 763 | ) then 764 | return true; 765 | else 766 | return false; 767 | end if; 768 | end is_lexical_whitespace; 769 | 770 | 771 | -------------------------------------------------------------------------------- 772 | --Create a nested table of characters. 773 | --This extra step takes care of non-trivial Unicode processing up front. 774 | --This cannot be simplified with SUBSTRC, that will not work for large CLOBs. 775 | --TODO: Is there an easier way to do this? 776 | function get_varchar2_table_from_clob(p_clob clob) return varchar2_table 777 | is 778 | v_varchar2 varchar2(32767 byte); 779 | 780 | v_chars varchar2_table := varchar2_table(); 781 | 782 | v_offset_not_on_char_boundary exception; 783 | pragma exception_init(v_offset_not_on_char_boundary, -22831); 784 | 785 | v_next_char_boundary number := 1; 786 | v_amount_to_read constant number := 8000; 787 | begin 788 | --Return empty collection is there's nothing. 789 | if p_clob is null then 790 | return v_chars; 791 | --Convert CLOB to VARCHAR2 the easy way if it's small enough. 792 | elsif dbms_lob.getLength(p_clob) <= 8191 then 793 | v_varchar2 := p_clob; 794 | for i in 1 .. lengthc(v_varchar2) loop 795 | v_chars.extend(); 796 | v_chars(v_chars.count) := substrc(v_varchar2, i, 1); 797 | end loop; 798 | --Convert CLOB to VARCHAR2 the hard way if it's too large. 799 | else 800 | --Convert multiple characters from CLOB to VARCHAR2 at once. 801 | --This is tricky because CLOBs use UCS and VARCHARs use UTF8. 802 | --Some single-characters in VARCHAR2 use 2 UCS code points. 803 | --They can be treated as 2 separate characters but must be selected together. 804 | --Oracle will not throw an error if SUBSTR reads half a character at the end. 805 | --But it does error if it starts at a bad character. 806 | --The code below finds the valid character boundary first, and then reads up to it. 807 | for i in 1 .. ceil(dbms_lob.getLength(p_clob)/v_amount_to_read) loop 808 | begin 809 | --Check if the next boundary is OK by trying to read a small amount. 810 | --TODO: Checking 2 bytes is as expensive as retrieving all data. Pre-fetch and use later if valid? 811 | v_varchar2 := dbms_lob.substr(lob_loc => p_clob, offset => v_next_char_boundary + v_amount_to_read, amount => 2); 812 | 813 | --If it's ok, grab the data and increment the character boundary. 814 | v_varchar2 := dbms_lob.substr(lob_loc => p_clob, offset => v_next_char_boundary, amount => v_amount_to_read); 815 | v_next_char_boundary := v_next_char_boundary + v_amount_to_read; 816 | 817 | --If it wasn't successful, grab one less character and set character boundary to one less. 818 | exception when v_offset_not_on_char_boundary then 819 | v_varchar2 := dbms_lob.substr(lob_loc => p_clob, offset => v_next_char_boundary, amount => v_amount_to_read - 1); 820 | v_next_char_boundary := v_next_char_boundary + v_amount_to_read - 1; 821 | end; 822 | 823 | --Loop through VARCHAR2 and convert it to array. 824 | for i in 1 .. lengthc(v_varchar2) loop 825 | v_chars.extend(); 826 | v_chars(v_chars.count) := substrc(v_varchar2, i, 1); 827 | end loop; 828 | end loop; 829 | end if; 830 | 831 | return v_chars; 832 | 833 | end get_varchar2_table_from_clob; 834 | 835 | end; 836 | / 837 | -------------------------------------------------------------------------------- /packages/statement_feedback.plsql: -------------------------------------------------------------------------------- 1 | create or replace package statement_feedback is 2 | --Copyright (C) 2020 Jon Heller. This program is licensed under the LGPLv3. 3 | 4 | procedure get_feedback_message( 5 | p_tokens in token_table, 6 | p_rowcount in number, 7 | p_success_message out varchar2, 8 | p_compile_warning_message out varchar2 9 | ); 10 | 11 | procedure get_feedback_message( 12 | p_command_name in varchar2, 13 | p_rowcount in number, 14 | p_success_message out varchar2, 15 | p_compile_warning_message out varchar2 16 | ); 17 | 18 | /* 19 | 20 | == Purpose == 21 | 22 | Generate a feedback message for a successful SQL or PL/SQL statement, similar to SQL*Plus. 23 | 24 | This can help when processing dynamic SQL and PL/SQL statements. Here are some examples: 25 | - Table created 26 | - Table altered. 27 | - Table dropped. 28 | - PL/SQL procedure successfully completed. 29 | - 5 rows inserted. 30 | - Warning: Package Body altered with compilation errors. 31 | - no rows selected 32 | 33 | 34 | == Example == 35 | 36 | --Test Statement_Feedback. 37 | declare 38 | v_statement varchar2(32767); 39 | v_success_message varchar2(100); 40 | v_compile_warning_message varchar2(100); 41 | v_has_compile_warning boolean := false; 42 | 43 | v_success_with_compilation_err exception; 44 | pragma exception_init(v_success_with_compilation_err, -24344); 45 | 46 | begin 47 | --Test statement. 48 | v_statement := 'create table some_test_table1(a number)'; 49 | 50 | --Execute the statement and catch compile warning errors. 51 | begin 52 | execute immediate v_statement; 53 | exception when v_success_with_compilation_err then 54 | v_has_compile_warning := true; 55 | end; 56 | 57 | --Get the feedback message. 58 | statement_feedback.get_feedback_message( 59 | p_tokens => plsql_lexer.lex(v_statement), 60 | p_rowcount => sql%rowcount, 61 | p_success_message => v_success_message, 62 | p_compile_warning_message => v_compile_warning_message 63 | ); 64 | 65 | --Display the success message or warning message 66 | if v_has_compile_warning then 67 | dbms_output.put_line(v_compile_warning_message); 68 | else 69 | dbms_output.put_line(v_success_message); 70 | end if; 71 | end; 72 | 73 | 74 | == Parameters == 75 | 76 | p_statement - The SQL or PL/SQL statement that was executed successfully. 77 | Most of the messages are obvious. Only the SELECT message is 78 | unusual - this package will not display the results, only a 79 | message like "no rows selected". 80 | OR 81 | p_command_name - The V$SQLCOMMAND.COMMAND_NAME of the statement. This value 82 | can be retrieved from statement_classifier.classify. 83 | 84 | p_rowcount - The number of rows modified by the statement. 85 | If it does not apply, pass in NULL. 86 | p_success_message - The message SQL*Plus would display if the statement was successful. 87 | p_compile_warning_message - The message SQL*Plus would display if a PL/SQL object compiled with errors. 88 | Catch "ORA-24344: success with compilation error" to detect this situation. 89 | 90 | 91 | */ 92 | 93 | end; 94 | / 95 | create or replace package body statement_feedback is 96 | 97 | -------------------------------------------------------------------------------- 98 | procedure get_feedback_message( 99 | p_command_name in varchar2, 100 | p_rowcount in number, 101 | p_success_message out varchar2, 102 | p_compile_warning_message out varchar2 103 | ) is 104 | begin 105 | --If classification failed then return NULLs. 106 | if p_command_name is null then 107 | null; 108 | --If classification succeeded, set the outputs. 109 | else 110 | --These are one-offs and exceptions. Most commands will be handled by the 111 | -- "standard" ELSIFs at the end of this statement. 112 | --Note that some of these seem to have extra spaces because the command names 113 | -- do not always perfectly line up with the real syntax. 114 | 115 | if p_command_name = 'ADMINISTER KEY MANAGEMENT' then 116 | p_success_message := 'keystore altered.'; 117 | elsif p_command_name = 'ALTER DISK GROUP' then 118 | p_success_message := 'Diskgroup altered.'; 119 | elsif p_command_name = 'ALTER INMEMORY JOIN GROUP' then 120 | p_success_message := 'Join group altered.'; 121 | elsif p_command_name = 'ALTER LOCKDOWN PROFILE' then 122 | p_success_message := 'Lockdown Profile altered.'; 123 | elsif p_command_name = 'ALTER MATERIALIZED VIEW ' then 124 | p_success_message := 'Materialized view altered.'; 125 | elsif p_command_name = 'ALTER MLE ENV' then 126 | p_success_message := 'MLE env altered.'; 127 | elsif p_command_name = 'ALTER MLE MODULE' then 128 | p_success_message := 'MLE module altered.'; 129 | elsif p_command_name = 'ALTER PMEM FILESTORE' then 130 | --TODO: I'm not 100% sure about this. 131 | p_success_message := 'PMEM filestore altered.'; 132 | elsif p_command_name = 'ALTER PROPERTY GRAPH' then 133 | p_success_message := 'Property graph altered.'; 134 | elsif p_command_name = 'ALTER TABLESPACE SET' then 135 | --TODO: I'm not 100% sure about this. 136 | p_success_message := 'Tablespace altered.'; 137 | elsif p_command_name = 'ANALYZE CLUSTER' then 138 | p_success_message := 'Cluster analyzed.'; 139 | elsif p_command_name = 'ANALYZE INDEX' then 140 | p_success_message := 'Index analyzed.'; 141 | elsif p_command_name = 'ANALYZE TABLE' then 142 | p_success_message := 'Table analyzed.'; 143 | elsif p_command_name = 'ASSOCIATE STATISTICS' then 144 | p_success_message := 'Statistics associated.'; 145 | elsif p_command_name = 'AUDIT OBJECT' then 146 | p_success_message := 'Audit succeeded.'; 147 | elsif p_command_name = 'CALL METHOD' then 148 | p_success_message := 'Call completed.'; 149 | elsif p_command_name = 'COMMENT' then 150 | p_success_message := 'Comment created.'; 151 | elsif p_command_name = 'COMMIT' then 152 | p_success_message := 'Commit complete.'; 153 | elsif p_command_name = 'CREATE DISK GROUP' then 154 | p_success_message := 'Diskgroup created.'; 155 | elsif p_command_name = 'CREATE INMEMORY JOIN GROUP' then 156 | p_success_message := 'Join group created.'; 157 | elsif p_command_name = 'CREATE LOCKDOWN PROFILE' then 158 | p_success_message := 'Lockdown Profile created.'; 159 | elsif p_command_name = 'CREATE MATERIALIZED VIEW ' then 160 | p_success_message := 'Materialized view created.'; 161 | elsif p_command_name = 'CREATE MLE ENV' then 162 | p_success_message := 'MLE env created.'; 163 | elsif p_command_name = 'CREATE MLE MODULE' then 164 | p_success_message := 'MLE module created.'; 165 | elsif p_command_name = 'CREATE PFILE' then 166 | p_success_message := 'File created.'; 167 | elsif p_command_name = 'CREATE PMEM FILESTORE' then 168 | --TODO: I'm not 100% sure about this. 169 | p_success_message := 'PMEM filestore created.'; 170 | elsif p_command_name = 'CREATE PROPERTY GRAPH' then 171 | p_success_message := 'Property graph created.'; 172 | elsif p_command_name = 'CREATE SPFILE' then 173 | p_success_message := 'File created.'; 174 | elsif p_command_name = 'CREATE TABLESPACE SET' then 175 | p_success_message := 'Tablespace created.'; 176 | elsif p_command_name = 'DELETE' then 177 | if p_rowcount is null then 178 | p_success_message := 'ERROR: Unknown number of rows deleted.'; 179 | elsif p_rowcount = 1 then 180 | p_success_message := '1 row deleted.'; 181 | else 182 | p_success_message := p_rowcount||' rows deleted.'; 183 | end if; 184 | elsif p_command_name = 'DISASSOCIATE STATISTICS' then 185 | p_success_message := 'Statistics disassociated.'; 186 | elsif p_command_name = 'DROP AUDIT POLICY' then 187 | p_success_message := 'Audit Policy dropped.'; 188 | elsif p_command_name = 'DROP DISK GROUP' then 189 | p_success_message := 'Diskgroup dropped.'; 190 | elsif p_command_name = 'DROP INMEMORY JOIN GROUP' then 191 | p_success_message := 'Join group deleted.'; 192 | elsif p_command_name = 'DROP LOCKDOWN PROFILE' then 193 | p_success_message := 'Lockdown Profile dropped.'; 194 | elsif p_command_name = 'DROP MATERIALIZED VIEW LOG' then 195 | p_success_message := 'Materialized view log dropped.'; 196 | elsif p_command_name = 'DROP MATERIALIZED VIEW ' then 197 | p_success_message := 'Materialized view dropped.'; 198 | elsif p_command_name = 'DROP MLE ENV' then 199 | p_success_message := 'MLE env dropped.'; 200 | elsif p_command_name = 'DROP MLE MODULE' then 201 | p_success_message := 'MLE module dropped.'; 202 | elsif p_command_name = 'DROP PMEM FILESTORE' then 203 | --TODO: I'm not 100% sure about this. 204 | p_success_message := 'PMEM filestore dropped.'; 205 | elsif p_command_name = 'DROP PROPERTY GRAPH' then 206 | p_success_message := 'Property graph dropped.'; 207 | elsif p_command_name = 'DROP TABLESPACE SET' then 208 | --TODO: I'm not 100% sure about this. 209 | p_success_message := 'Tablespace dropped.'; 210 | elsif p_command_name = 'EXPLAIN' then 211 | p_success_message := 'Explained.'; 212 | elsif p_command_name = 'FLASHBACK DATABASE' then 213 | p_success_message := 'Flashback complete.'; 214 | elsif p_command_name = 'FLASHBACK TABLE' then 215 | p_success_message := 'Flashback complete.'; 216 | elsif p_command_name = 'GRANT OBJECT' then 217 | p_success_message := 'Grant succeeded.'; 218 | elsif p_command_name = 'INSERT' then 219 | if p_rowcount is null then 220 | p_success_message := 'ERROR: Unknown number of rows created.'; 221 | elsif p_rowcount = 1 then 222 | p_success_message := '1 row created.'; 223 | else 224 | p_success_message := p_rowcount||' rows created.'; 225 | end if; 226 | elsif p_command_name = 'LOCK TABLE' then 227 | p_success_message := 'Table(s) Locked.'; 228 | elsif p_command_name = 'NOAUDIT OBJECT' then 229 | p_success_message := 'Noaudit succeeded.'; 230 | elsif p_command_name = 'PL/SQL EXECUTE' then 231 | p_success_message := 'PL/SQL procedure successfully completed.'; 232 | elsif p_command_name = 'PURGE DBA RECYCLEBIN' then 233 | p_success_message := 'DBA Recyclebin purged.'; 234 | elsif p_command_name = 'PURGE INDEX' then 235 | p_success_message := 'Index purged.'; 236 | elsif p_command_name = 'PURGE TABLE' then 237 | p_success_message := 'Table purged.'; 238 | elsif p_command_name = 'PURGE TABLESPACE' then 239 | p_success_message := 'Tablespace purged.'; 240 | elsif p_command_name = 'PURGE TABLESPACE SET' then 241 | --TODO: I'm not 100% sure about this. 242 | p_success_message := 'Tablespace purged.'; 243 | elsif p_command_name = 'PURGE USER RECYCLEBIN' then 244 | p_success_message := 'Recyclebin purged.'; 245 | elsif p_command_name = 'RENAME' then 246 | p_success_message := 'Table renamed.'; 247 | elsif p_command_name = 'REVOKE OBJECT' then 248 | p_success_message := 'Revoke succeeded.'; 249 | elsif p_command_name = 'ROLLBACK' then 250 | p_success_message := 'Rollback complete.'; 251 | elsif p_command_name = 'SAVEPOINT' then 252 | p_success_message := 'Savepoint created.'; 253 | elsif p_command_name = 'SELECT' then 254 | if p_rowcount is null then 255 | p_success_message := 'ERROR: Unknown number of rows selected.'; 256 | elsif p_rowcount = 0 then 257 | p_success_message := 'no rows selected'; 258 | elsif p_rowcount = 1 then 259 | p_success_message := '1 row selected.'; 260 | else 261 | p_success_message := p_rowcount||' rows selected.'; 262 | end if; 263 | elsif p_command_name = 'SET CONSTRAINTS' then 264 | p_success_message := 'Constraint set.'; 265 | elsif p_command_name = 'SET ROLE' then 266 | p_success_message := 'Role set.'; 267 | elsif p_command_name = 'SET TRANSACTION' then 268 | p_success_message := 'Transaction set.'; 269 | elsif p_command_name = 'TRUNCATE CLUSTER' then 270 | p_success_message := 'Cluster truncated.'; 271 | elsif p_command_name = 'TRUNCATE TABLE' then 272 | p_success_message := 'Table truncated.'; 273 | elsif p_command_name = 'UPDATE' then 274 | if p_rowcount is null then 275 | p_success_message := 'ERROR: Unknown number of rows updated.'; 276 | elsif p_rowcount = 1 then 277 | p_success_message := '1 row updated.'; 278 | else 279 | p_success_message := p_rowcount||' rows updated.'; 280 | end if; 281 | elsif p_command_name = 'UPSERT' then 282 | if p_rowcount is null then 283 | p_success_message := 'ERROR: Unknown number of rows merged.'; 284 | elsif p_rowcount = 1 then 285 | p_success_message := '1 row merged.'; 286 | else 287 | p_success_message := p_rowcount||' rows merged.'; 288 | end if; 289 | 290 | --Standard "ALTER", "CREATE", and "DROP". 291 | --Remove first word, change to lower case, initialize first letter, add verb. 292 | elsif p_command_name like 'ALTER %' then 293 | p_success_message := lower(replace(p_command_name, 'ALTER '))||' altered.'; 294 | p_success_message := upper(substr(p_success_message, 1, 1))||substr(p_success_message, 2); 295 | elsif p_command_name like 'CREATE %' then 296 | p_success_message := lower(replace(p_command_name, 'CREATE '))||' created.'; 297 | p_success_message := upper(substr(p_success_message, 1, 1))||substr(p_success_message, 2); 298 | elsif p_command_name like 'DROP %' then 299 | p_success_message := lower(replace(p_command_name, 'DROP '))||' dropped.'; 300 | p_success_message := upper(substr(p_success_message, 1, 1))||substr(p_success_message, 2); 301 | 302 | --Print error message if statement type could not be determined. 303 | else 304 | p_success_message := 'ERROR: Cannot determine statement type.'; 305 | end if; 306 | 307 | --Get compile warning message for PL/SQL objects 308 | if p_command_name = 'ALTER ANALYTIC VIEW' then 309 | p_compile_warning_message := 'Warning: Analytic view altered with compilation errors.'; 310 | elsif p_command_name = 'ALTER ATTRIBUTE DIMENSION' then 311 | p_compile_warning_message := 'Warning: Attribute dimension altered with compilation errors.'; 312 | elsif p_command_name like 'ALTER%' 313 | and 314 | ( 315 | p_command_name like '%ASSEMBLY' or 316 | p_command_name like '%DIMENSION' or 317 | p_command_name like '%FUNCTION' or 318 | p_command_name like '%HIERARCHY' or 319 | p_command_name like '%JAVA' or 320 | p_command_name like '%LIBRARY' or 321 | p_command_name like '%PACKAGE' or 322 | p_command_name like '%PACKAGE BODY' or 323 | p_command_name like '%PROCEDURE' or 324 | p_command_name like '%TRIGGER' or 325 | (p_command_name like '%TYPE' and p_command_name not like '%INDEXTYPE') or 326 | p_command_name like '%TYPE BODY' or 327 | p_command_name like '%VIEW' 328 | ) then 329 | p_compile_warning_message := 'Warning: '||initcap(replace(p_command_name, 'ALTER ')) 330 | ||' altered with compilation errors.'; 331 | elsif p_command_name = 'CREATE ANALYTIC VIEW' then 332 | p_compile_warning_message := 'Warning: Analytic view created with compilation errors.'; 333 | elsif p_command_name = 'CREATE ATTRIBUTE DIMENSION' then 334 | p_compile_warning_message := 'Warning: Attribute dimension created with compilation errors.'; 335 | elsif p_command_name like 'CREATE%' 336 | and 337 | ( 338 | p_command_name like '%ASSEMBLY' or 339 | --I don't think a dimension can be created with a compilation error. 340 | --But it is possible to ALTER them with a warning. 341 | --For example if a column was changed since it was created. 342 | --p_command_name like '%DIMENSION' or 343 | p_command_name like '%FUNCTION' or 344 | p_command_name like '%HIERARCHY' or 345 | p_command_name like '%JAVA' or 346 | p_command_name like '%LIBRARY' or 347 | p_command_name like '%PACKAGE' or 348 | p_command_name like '%PACKAGE BODY' or 349 | p_command_name like '%PROCEDURE' or 350 | p_command_name like '%TRIGGER' or 351 | (p_command_name like '%TYPE' and p_command_name not like '%INDEXTYPE') or 352 | p_command_name like '%TYPE BODY' or 353 | p_command_name like '%VIEW' 354 | ) then 355 | p_compile_warning_message := 'Warning: '||initcap(replace(p_command_name, 'CREATE ')) 356 | ||' created with compilation errors.'; 357 | end if; 358 | end if; 359 | 360 | end get_feedback_message; 361 | 362 | 363 | -------------------------------------------------------------------------------- 364 | procedure get_feedback_message( 365 | p_tokens in token_table, 366 | p_rowcount in number, 367 | p_success_message out varchar2, 368 | p_compile_warning_message out varchar2 369 | ) is 370 | v_category varchar2(100); 371 | v_statement_type varchar2(100); 372 | v_command_name varchar2(64); 373 | v_command_type number; 374 | v_lex_sqlcode number; 375 | v_lex_sqlerrm varchar2(4000); 376 | begin 377 | --Classify the statement. 378 | statement_classifier.classify(p_tokens, 379 | v_category,v_statement_type,v_command_name,v_command_type,v_lex_sqlcode,v_lex_sqlerrm 380 | ); 381 | 382 | get_feedback_message(v_command_name, p_rowcount, p_success_message, p_compile_warning_message); 383 | 384 | end get_feedback_message; 385 | 386 | end; 387 | / 388 | -------------------------------------------------------------------------------- /packages/statement_splitter.plsql: -------------------------------------------------------------------------------- 1 | create or replace package statement_splitter is 2 | --Copyright (C) 2015 Jon Heller. This program is licensed under the LGPLv3. 3 | 4 | function split_by_semicolon(p_tokens in token_table) return token_table_table; 5 | function split_by_sqlplus_delimiter(p_statements in clob, p_sqlplus_delimiter in varchar2 default '/') return clob_table; 6 | function split_by_sqlplus_del_and_semi(p_statements in clob, p_sqlplus_delimiter in varchar2 default '/') return token_table_table; 7 | 8 | /* 9 | 10 | == Purpose == 11 | 12 | Split a string of SQL and PL/SQL statements into individual statements. 13 | 14 | SPLIT_BY_SEMICOLON - Use semicolons for all terminators, even for PL/SQL 15 | statements. This mode is useful for IDEs where a "/" in strings causes problems. 16 | 17 | SPLIT_BY_SQLPLUS_DELIMITER - Uses a delimiter the way SQL*Plus does - it must 18 | be on a line with only whitespace. 19 | 20 | SPLIT_BY_SQLPLUS_DEL_AND_SEMI - Combines the above two. 21 | 22 | == Example == 23 | 24 | SPLIT_BY_SEMICOLON: 25 | 26 | select rownum, plsql_lexer.concatenate(column_value) statement 27 | from table( 28 | statement_splitter.split_by_semicolon( 29 | plsql_lexer.lex('begin null; end;select * from test2;') 30 | ) 31 | ); 32 | 33 | Results: 34 | * ROWNUM STATEMENT 35 | * ------ --------- 36 | * 1 begin null; end; 37 | * 2 select * from test2; 38 | 39 | 40 | SPLIT_BY_SQLPLUS_DELIMITER: 41 | 42 | select rownum, column_value statement 43 | from table( 44 | statement_splitter.split_by_sqlplus_delimiter( 45 | 'begin null; end;'||chr(10)|| 46 | '/'||chr(10)|| 47 | 'select * from test2' 48 | ) 49 | ); 50 | 51 | Results: 52 | * ROWNUM STATEMENT 53 | * ------ --------- 54 | * 1 begin null; end; 55 | * / 56 | * 2 select * from test2; 57 | 58 | */ 59 | 60 | end; 61 | / 62 | create or replace package body statement_splitter is 63 | 64 | C_TERMINATOR_SEMI constant number := 1; 65 | C_TERMINATOR_PLSQL_DECLARATION constant number := 2; 66 | C_TERMINATOR_PLSQL constant number := 3; 67 | C_TERMINATOR_EOF constant number := 4; 68 | 69 | 70 | 71 | 72 | 73 | -------------------------------------------------------------------------------- 74 | procedure add_statement_consume_tokens( 75 | p_split_tokens in out nocopy token_table_table, 76 | p_parse_tree in token_table, 77 | p_terminator number, 78 | p_parse_tree_index in out number, 79 | p_command_name in varchar2 80 | ) is 81 | /* 82 | This is a recursive descent parser for PL/SQL. 83 | This link has a good introduction to recursive descent parsers: https://www.cis.upenn.edu/~matuszek/General/recursive-descent-parsing.html) 84 | 85 | The functions roughly follow the same order as the "Block" chapater in the 12c PL/SQL Langauge Reference: 86 | http://docs.oracle.com/database/121/LNPLS/block.htm#LNPLS01303 87 | 88 | The splitter only needs to know when the statement ends and does not consume 89 | every token in a meaningful way, like a real parser would. For example, 90 | there are many times when tokens can be skipped until the next semicolon. 91 | 92 | If Oracle ever allows PLSQL_DECLARATIONS inside PL/SQL code this code will need to 93 | be much more complicated. 94 | */ 95 | 96 | ------------------------------------------------------------------------------- 97 | --Globals 98 | ------------------------------------------------------------------------------- 99 | --v_code clob := 'declare procedure p1 is begin null; end; begin null; end;select * from dual;'; 100 | --v_code clob := '<>declare a number; procedure p1 is begin null; end; begin null; end;select * from dual;'; 101 | 102 | --Cursors can have lots of parentheses, and even an "IS" inside them. 103 | --v_code clob := 'declare cursor c(a number default case when (((1 is null))) then 1 else 0 end) is select 1 a from dual; begin null; end;select * from dual;'; 104 | --v_code clob := '<>begin null; end;'; 105 | 106 | --SELECT test. 107 | --v_code clob := 'declare a number; select 1 into a from dual; end;'; 108 | 109 | 110 | type string_table is table of varchar2(32767); 111 | type number_table is table of number; 112 | 113 | g_debug_lines string_table := string_table(); 114 | g_ast_index number := 1; 115 | 116 | v_abstract_syntax_tree token_table := token_table(); 117 | v_map_between_parse_and_ast number_table := number_table(); 118 | 119 | --Holds return value of optional functions. 120 | g_optional boolean; 121 | 122 | 123 | ------------------------------------------------------------------------------- 124 | --Forward declarations so that functions can be in the same order as the documentation. 125 | ------------------------------------------------------------------------------- 126 | function anything_(p_value varchar2) return boolean; 127 | function anything_before_begin return boolean; 128 | function anything_in_parentheses return boolean; 129 | function anything_up_to_may_include_(p_value varchar2) return boolean; 130 | function anything_up_to_must_include_(p_value varchar2) return boolean; 131 | function basic_loop_statement return boolean; 132 | function body return boolean; 133 | function case_statement return boolean; 134 | function create_procedure return boolean; 135 | function create_function return boolean; 136 | function create_package return boolean; 137 | function create_type_body return boolean; 138 | function create_trigger return boolean; 139 | function cursor_for_loop_statement return boolean; 140 | function declare_section return boolean; 141 | function exception_handler return boolean; 142 | function expression_case_when_then return boolean; 143 | function initialize_section return boolean; 144 | function for_loop_statement return boolean; 145 | function for_each_row return boolean; 146 | function function_definition return boolean; 147 | function if_statement return boolean; 148 | function label return boolean; 149 | function name return boolean; 150 | function name_maybe_schema return boolean; 151 | function nested_table_nt_column_of return boolean; 152 | function p_end return boolean; 153 | function plsql_block return boolean; 154 | function procedure_definition return boolean; 155 | function referencing_clause return boolean; 156 | function statement_or_inline_pragma return boolean; 157 | function trigger_edition_clause return boolean; 158 | function trigger_ordering_clause return boolean; 159 | function when_condition return boolean; 160 | 161 | ------------------------------------------------------------------------------- 162 | --Helper functions 163 | ------------------------------------------------------------------------------- 164 | procedure push(p_line varchar2) is 165 | begin 166 | g_debug_lines.extend; 167 | g_debug_lines(g_debug_lines.count) := p_line; 168 | end; 169 | 170 | function pop(p_local_ast_before number default null, p_local_lines_before string_table default null) return boolean is 171 | begin 172 | if p_local_ast_before is null then 173 | g_debug_lines.trim; 174 | else 175 | g_ast_index := p_local_ast_before; 176 | g_debug_lines := p_local_lines_before; 177 | end if; 178 | return false; 179 | end; 180 | 181 | procedure pop is 182 | begin 183 | g_debug_lines.trim; 184 | end; 185 | 186 | procedure increment(p_increment number default 1) is begin 187 | g_ast_index := g_ast_index + p_increment; 188 | end; 189 | 190 | function get_next_(p_value varchar2) return number is begin 191 | for i in g_ast_index .. v_abstract_syntax_tree.count loop 192 | if upper(v_abstract_syntax_tree(i).value) = p_value then 193 | return i; 194 | end if; 195 | end loop; 196 | return null; 197 | end; 198 | 199 | function current_value return clob is begin 200 | return upper(v_abstract_syntax_tree(g_ast_index).value); 201 | end; 202 | 203 | procedure parse_error(p_syntax_type varchar2) is begin 204 | raise_application_error(-20002, 'Fatal parse error in '||p_syntax_type||' around line #'|| 205 | v_abstract_syntax_tree(g_ast_index).line_number||', column #'|| 206 | v_abstract_syntax_tree(g_ast_index).column_number||' of the original string.'); 207 | 208 | end; 209 | 210 | function next_value(p_increment number default 1) return clob is begin 211 | begin 212 | return upper(v_abstract_syntax_tree(g_ast_index+p_increment).value); 213 | exception when subscript_beyond_count then 214 | null; 215 | end; 216 | end; 217 | 218 | function previous_value(p_decrement number) return clob is begin 219 | begin 220 | if g_ast_index - p_decrement <= 0 then 221 | return null; 222 | else 223 | return upper(v_abstract_syntax_tree(g_ast_index - p_decrement).value); 224 | end if; 225 | exception when subscript_beyond_count then 226 | null; 227 | end; 228 | end; 229 | 230 | function current_type return varchar2 is begin 231 | return v_abstract_syntax_tree(g_ast_index).type; 232 | end; 233 | 234 | function anything_(p_value varchar2) return boolean is begin 235 | push(p_value); 236 | if current_value = p_value then 237 | increment; 238 | return true; 239 | else 240 | return pop; 241 | end if; 242 | end; 243 | 244 | function anything_up_to_may_include_(p_value varchar2) return boolean is begin 245 | push('ANYTHING_UP_TO_MAY_INCLUDE_'||p_value); 246 | begin 247 | loop 248 | if current_value = p_value then 249 | increment; 250 | return true; 251 | end if; 252 | increment; 253 | end loop; 254 | exception when subscript_beyond_count then return true; 255 | end; 256 | end; 257 | 258 | function anything_up_to_must_include_(p_value varchar2) return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 259 | push('ANYTHING_UP_TO_MUST_INCLUDE_'||p_value); 260 | begin 261 | loop 262 | if current_value = p_value then 263 | increment; 264 | return true; 265 | end if; 266 | increment; 267 | end loop; 268 | exception when subscript_beyond_count then null; 269 | end; 270 | 271 | return pop(v_local_ast_before, v_local_lines_before); 272 | end; 273 | 274 | function anything_before_begin return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 275 | push('ANYTHING_BUT_BEGIN'); 276 | begin 277 | loop 278 | if current_value = 'BEGIN' then 279 | return true; 280 | end if; 281 | increment; 282 | end loop; 283 | exception when subscript_beyond_count then null; 284 | end; 285 | return pop(v_local_ast_before, v_local_lines_before); 286 | end; 287 | 288 | function anything_in_parentheses return boolean is v_paren_counter number; begin 289 | push('ANYTHING_IN_PARENTHESES'); 290 | if anything_('(') then 291 | v_paren_counter := 1; 292 | while v_paren_counter >= 1 loop 293 | if current_value = '(' then 294 | v_paren_counter := v_paren_counter + 1; 295 | elsif current_value = ')' then 296 | v_paren_counter := v_paren_counter - 1; 297 | end if; 298 | increment; 299 | end loop; 300 | return true; 301 | end if; 302 | return pop; 303 | end; 304 | 305 | ------------------------------------------------------------------------------- 306 | --Production rules that consume tokens and return true or false if rule was found. 307 | ------------------------------------------------------------------------------- 308 | function plsql_block return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 309 | push('PLSQL_BLOCK'); 310 | 311 | g_optional := label; 312 | if anything_('DECLARE') then 313 | g_optional := declare_section; 314 | if body then 315 | return true; 316 | else 317 | return pop(v_local_ast_before, v_local_lines_before); 318 | end if; 319 | elsif body then 320 | return true; 321 | else 322 | return pop(v_local_ast_before, v_local_lines_before); 323 | end if; 324 | end; 325 | 326 | function label return boolean is begin 327 | push('LABEL'); 328 | if current_value = '<<' then 329 | loop 330 | increment; 331 | if current_value = '>>' then 332 | increment; 333 | return true; 334 | end if; 335 | end loop; 336 | end if; 337 | return pop; 338 | end; 339 | 340 | function declare_section return boolean is begin 341 | push('DECLARE_SECTION'); 342 | if current_value in ('BEGIN', 'END') then 343 | return pop; 344 | else 345 | loop 346 | if current_value in ('BEGIN', 'END') then 347 | return true; 348 | end if; 349 | 350 | --Of the items in ITEM_LIST_1 and ITEM_LIST_2, only 351 | --these two require any special processing. 352 | if procedure_definition then null; 353 | elsif function_definition then null; 354 | elsif anything_up_to_may_include_(';') then null; 355 | end if; 356 | end loop; 357 | end if; 358 | end; 359 | 360 | function body return boolean is begin 361 | push('BODY'); 362 | if anything_('BEGIN') then 363 | g_optional := statement_or_inline_pragma; 364 | while statement_or_inline_pragma loop null; end loop; 365 | if anything_('EXCEPTION') then 366 | while exception_handler loop null; end loop; 367 | end if; 368 | g_optional := p_end; 369 | return true; 370 | end if; 371 | return pop; 372 | end; 373 | 374 | function initialize_section return boolean is begin 375 | push('BODY'); 376 | if anything_('BEGIN') then 377 | g_optional := statement_or_inline_pragma; 378 | while statement_or_inline_pragma loop null; end loop; 379 | if anything_('EXCEPTION') then 380 | while exception_handler loop null; end loop; 381 | end if; 382 | return true; 383 | end if; 384 | return pop; 385 | end; 386 | 387 | function procedure_definition return boolean is begin 388 | push('PROCEDURE_DEFINITION'); 389 | --Exclude CTE queries that create a table expression named "PROCEDURE". 390 | if current_value = 'PROCEDURE' and next_value not in ('AS', '(') then 391 | g_optional := anything_before_begin; --Don't need the header information. 392 | return body; 393 | end if; 394 | return pop; 395 | end; 396 | 397 | function function_definition return boolean is begin 398 | push('FUNCTION_DEFINITION'); 399 | --Exclude CTE queries that create a table expression named "FUNCTION". 400 | if current_value = 'FUNCTION' and next_value not in ('AS', '(') then 401 | g_optional := anything_before_begin; --Don't need the header information. 402 | return body; 403 | end if; 404 | return pop; 405 | end; 406 | 407 | function name return boolean is begin 408 | push('NAME'); 409 | if current_type = plsql_lexer.c_word then 410 | increment; 411 | return true; 412 | end if; 413 | return pop; 414 | end; 415 | 416 | function name_maybe_schema return boolean is begin 417 | push('NAME_MAYBE_SCHEMA'); 418 | if name then 419 | if anything_('.') then 420 | g_optional := name; 421 | end if; 422 | return true; 423 | end if; 424 | return pop; 425 | end; 426 | 427 | function statement_or_inline_pragma return boolean is begin 428 | push('STATEMENT_OR_INLINE_PRAGMA'); 429 | if label then return true; 430 | --Types that might have more statements: 431 | elsif basic_loop_statement then return true; 432 | elsif case_statement then return true; 433 | elsif for_loop_statement then return true; 434 | elsif cursor_for_loop_statement then return true; 435 | elsif if_statement then return true; 436 | elsif plsql_block then return true; 437 | --Anything else 438 | elsif current_value not in ('EXCEPTION', 'END', 'ELSE', 'ELSIF') then 439 | return anything_up_to_may_include_(';'); 440 | end if; 441 | return pop; 442 | end; 443 | 444 | function p_end return boolean is begin 445 | push('P_END'); 446 | if current_value = 'END' then 447 | increment; 448 | g_optional := name; 449 | if current_type = ';' then 450 | increment; 451 | end if; 452 | return true; 453 | end if; 454 | return pop; 455 | end; 456 | 457 | function exception_handler return boolean is begin 458 | push('EXCEPTION_HANDLER'); 459 | if current_value = 'WHEN' then 460 | g_optional := anything_up_to_must_include_('THEN'); 461 | while statement_or_inline_pragma loop null; end loop; 462 | return true; 463 | end if; 464 | return pop; 465 | end; 466 | 467 | function basic_loop_statement return boolean is begin 468 | push('BASIC_LOOP_STATEMENT'); 469 | if current_value = 'LOOP' then 470 | increment; 471 | while statement_or_inline_pragma loop null; end loop; 472 | if current_value = 'END' then 473 | increment; 474 | if current_value = 'LOOP' then 475 | increment; 476 | g_optional := name; 477 | if current_value = ';' then 478 | increment; 479 | return true; 480 | end if; 481 | end if; 482 | end if; 483 | parse_error('BASIC_LOOP_STATEMENT'); 484 | end if; 485 | return pop; 486 | end; 487 | 488 | function for_loop_statement return boolean is begin 489 | push('FOR_LOOP_STATEMENT'); 490 | if current_value = 'FOR' and get_next_('..') < get_next_(';') then 491 | g_optional := anything_up_to_must_include_('LOOP'); 492 | while statement_or_inline_pragma loop null; end loop; 493 | if current_value = 'END' then 494 | increment; 495 | if current_value = 'LOOP' then 496 | increment; 497 | g_optional := name; 498 | if current_value = ';' then 499 | increment; 500 | return true; 501 | end if; 502 | end if; 503 | end if; 504 | parse_error('FOR_LOOP_STATEMENT'); 505 | else 506 | return pop; 507 | end if; 508 | end; 509 | 510 | function cursor_for_loop_statement return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 511 | push('CURSOR_FOR_LOOP_STATEMENT'); 512 | if current_value = 'FOR' then 513 | increment; 514 | if name then 515 | if current_value = 'IN' then 516 | increment; 517 | g_optional := name; 518 | if current_value = '(' then 519 | g_optional := anything_in_parentheses; 520 | if current_value = 'LOOP' then 521 | increment; 522 | while statement_or_inline_pragma loop null; end loop; 523 | if current_value = 'END' then 524 | increment; 525 | if current_value = 'LOOP' then 526 | increment; 527 | g_optional := name; 528 | if current_value = ';' then 529 | increment; 530 | return true; 531 | end if; 532 | end if; 533 | end if; 534 | end if; 535 | end if; 536 | end if; 537 | end if; 538 | parse_error('CURSOR_FOR_LOOP_STATEMENT'); 539 | else 540 | return pop(v_local_ast_before, v_local_lines_before); 541 | end if; 542 | end; 543 | 544 | procedure case_expression is begin 545 | push('CASE_EXPRESSION'); 546 | loop 547 | if anything_('CASE') then 548 | case_expression; 549 | return; 550 | elsif anything_('END') then 551 | return; 552 | else 553 | increment; 554 | end if; 555 | end loop; 556 | pop; 557 | end; 558 | 559 | function expression_case_when_then return boolean is begin 560 | push('EXPRESSION_CASE_WHEN_THEN'); 561 | loop 562 | if current_value = 'CASE' then 563 | case_expression; 564 | elsif current_value = 'WHEN' or current_value = 'THEN' then 565 | return true; 566 | else 567 | increment; 568 | end if; 569 | end loop; 570 | return pop; 571 | end; 572 | 573 | function case_statement return boolean is begin 574 | push('CASE_STATEMENT'); 575 | if anything_('CASE') then 576 | --Searched case. 577 | if current_value = 'WHEN' then 578 | while anything_('WHEN') and expression_case_when_then and anything_('THEN') loop 579 | while statement_or_inline_pragma loop null; end loop; 580 | end loop; 581 | if anything_('ELSE') then 582 | while statement_or_inline_pragma loop null; end loop; 583 | end if; 584 | if anything_('END') and anything_('CASE') and (name or not name) and anything_(';') then 585 | return true; 586 | end if; 587 | parse_error('SEARCHED_CASE_STATEMENT'); 588 | --Simple case. 589 | else 590 | if expression_case_when_then then 591 | while anything_('WHEN') and expression_case_when_then and anything_('THEN') loop 592 | while statement_or_inline_pragma loop null; end loop; 593 | end loop; 594 | if anything_('ELSE') then 595 | while statement_or_inline_pragma loop null; end loop; 596 | end if; 597 | if anything_('END') and anything_('CASE') and (name or not name) and anything_(';') then 598 | return true; 599 | end if; 600 | end if; 601 | parse_error('SIMPLE_CASE_STATEMENT'); 602 | end if; 603 | else 604 | return pop; 605 | end if; 606 | end; 607 | 608 | function if_statement return boolean is begin 609 | push('IF_STATEMENT'); 610 | if anything_('IF') then 611 | if expression_case_when_then and anything_('THEN') then 612 | while statement_or_inline_pragma loop null; end loop; 613 | while anything_('ELSIF') and expression_case_when_then and anything_('THEN') loop 614 | while statement_or_inline_pragma loop null; end loop; 615 | end loop; 616 | if anything_('ELSE') then 617 | while statement_or_inline_pragma loop null; end loop; 618 | end if; 619 | if anything_('END') and anything_('IF') and anything_(';') then 620 | return true; 621 | end if; 622 | end if; 623 | parse_error('IF_STATEMENT'); 624 | end if; 625 | return pop; 626 | end; 627 | 628 | function create_or_replace_edition return boolean is begin 629 | push('CREATE_OR_REPLACE_EDITION'); 630 | if anything_('CREATE') then 631 | g_optional := anything_('OR'); 632 | g_optional := anything_('REPLACE'); 633 | g_optional := anything_('EDITIONABLE'); 634 | g_optional := anything_('NONEDITIONABLE'); 635 | return true; 636 | end if; 637 | return pop; 638 | end; 639 | 640 | function create_procedure return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 641 | push('CREATE_PROCEDURE'); 642 | if create_or_replace_edition and anything_('PROCEDURE') and name_maybe_schema then 643 | g_optional := anything_in_parentheses; 644 | if anything_up_to_must_include_('IS') or anything_up_to_must_include_('AS') then 645 | if anything_('EXTERNAL') or anything_('LANGUAGE') then 646 | g_optional := anything_up_to_may_include_(';'); 647 | return true; 648 | elsif plsql_block then 649 | return true; 650 | end if; 651 | end if; 652 | parse_error('CREATE_PROCEDURE'); 653 | end if; 654 | return pop(v_local_ast_before, v_local_lines_before); 655 | end; 656 | 657 | function create_function return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 658 | push('CREATE_FUNCTION'); 659 | if create_or_replace_edition and anything_('FUNCTION') and name_maybe_schema then 660 | --Consume everything between the function name and either AGGREGATE|PIPELINED USING 661 | --or the last IS/AS. 662 | --This is necessary to exclude some options that may include another IS, such as 663 | --expressions in the PARALLEL_ENABLE_CLAUSE. 664 | loop 665 | if current_value in ('AGGREGATE', 'PIPELINED') and next_value = 'USING' then 666 | --This one is simple, return true. 667 | increment(2); 668 | g_optional := anything_up_to_may_include_(';'); 669 | return true; 670 | elsif current_value = '(' then 671 | g_optional := anything_in_parentheses; 672 | elsif current_value in ('IS', 'AS') then 673 | increment; 674 | exit; 675 | else 676 | increment; 677 | end if; 678 | end loop; 679 | --There must have been an IS or AS to get here: 680 | if anything_('EXTERNAL') then 681 | g_optional := anything_up_to_may_include_(';'); 682 | return true; 683 | elsif anything_('LANGUAGE') then 684 | g_optional := anything_up_to_may_include_(';'); 685 | return true; 686 | else 687 | return plsql_block; 688 | end if; 689 | parse_error('CREATE_FUNCTION'); 690 | end if; 691 | return pop(v_local_ast_before, v_local_lines_before); 692 | end; 693 | 694 | function create_package return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 695 | push('CREATE_PACKAGE'); 696 | if create_or_replace_edition and anything_('PACKAGE') and name_maybe_schema then 697 | g_optional := anything_in_parentheses; 698 | if anything_up_to_must_include_('IS') or anything_up_to_must_include_('AS') then 699 | loop 700 | if anything_('END') then 701 | g_optional := name; 702 | g_optional := anything_(';'); 703 | return true; 704 | else 705 | g_optional := anything_up_to_may_include_(';'); 706 | end if; 707 | end loop; 708 | end if; 709 | end if; 710 | return pop(v_local_ast_before, v_local_lines_before); 711 | end; 712 | 713 | function create_package_body return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 714 | push('CREATE_PACKAGE_BODY'); 715 | if create_or_replace_edition and anything_('PACKAGE') and anything_('BODY') and name_maybe_schema then 716 | if anything_('IS') or anything_('AS') then 717 | g_optional := declare_section; 718 | g_optional := initialize_section; 719 | if anything_('END') then 720 | g_optional := name; 721 | g_optional := anything_(';'); 722 | return true; 723 | end if; 724 | end if; 725 | end if; 726 | return pop(v_local_ast_before, v_local_lines_before); 727 | end; 728 | 729 | function create_type_body return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 730 | push('CREATE_TYPE_BODY'); 731 | if create_or_replace_edition and anything_('TYPE') and anything_('BODY') and name_maybe_schema then 732 | g_optional := anything_in_parentheses; 733 | if anything_up_to_must_include_('IS') or anything_up_to_must_include_('AS') then 734 | loop 735 | if anything_('END') and anything_(';') then 736 | return true; 737 | elsif current_value in ('MAP', 'ORDER', 'MEMBER') then 738 | g_optional := anything_('MAP'); 739 | g_optional := anything_('ORDER'); 740 | g_optional := anything_('MEMBER'); 741 | if procedure_definition or function_definition then 742 | null; 743 | end if; 744 | elsif current_value in ('FINAL', 'INSTANTIABLE', 'CONSTRUCTOR') then 745 | g_optional := anything_('FINAL'); 746 | g_optional := anything_('INSTANTIABLE'); 747 | g_optional := anything_('CONSTRUCTOR'); 748 | g_optional := function_definition; 749 | else 750 | g_optional := anything_up_to_may_include_(';'); 751 | end if; 752 | end loop; 753 | end if; 754 | parse_error('CREATE_TYPE_BODY'); 755 | end if; 756 | return pop(v_local_ast_before, v_local_lines_before); 757 | end; 758 | 759 | function dml_event_clause return boolean is 760 | function update_of_column return boolean is begin 761 | if anything_('UPDATE') then 762 | if anything_('OF') and name then 763 | while anything_(',') and name loop null; end loop; 764 | return true; 765 | else 766 | return true; 767 | end if; 768 | end if; 769 | return false; 770 | end; 771 | begin 772 | push('DML_EVENT_CLAUSE'); 773 | if anything_('DELETE') or anything_('INSERT') or update_of_column then 774 | while anything_('OR') and (anything_('DELETE') or anything_('INSERT') or update_of_column) loop null; end loop; 775 | if anything_('ON') and name_maybe_schema then 776 | return true; 777 | end if; 778 | parse_error('DML_EVENT_CLAUSE'); 779 | end if; 780 | return pop; 781 | end; 782 | 783 | function referencing_clause return boolean is begin 784 | push('REFERENCING_CLAUSE'); 785 | if anything_('REFERENCING') then 786 | if anything_('OLD') or anything_('NEW') or anything_('PARENT') then 787 | g_optional := anything_('AS'); 788 | g_optional := name; 789 | while anything_('OLD') or anything_('NEW') or anything_('PARENT') loop 790 | g_optional := anything_('AS'); 791 | g_optional := name; 792 | end loop; 793 | return true; 794 | end if; 795 | parse_error('REFERENCING_CLAUSE'); 796 | end if; 797 | return pop; 798 | end; 799 | 800 | function for_each_row return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 801 | push('FOR_EACH_ROW'); 802 | if anything_('FOR') and anything_('EACH') and anything_('ROW') then 803 | return true; 804 | end if; 805 | return pop(v_local_ast_before, v_local_lines_before); 806 | end; 807 | 808 | function trigger_edition_clause return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 809 | push('TRIGGER_EDITION_CLAUSE'); 810 | if anything_('FORWARD') or anything_('REVERSE') then 811 | null; 812 | end if; 813 | if anything_('CROSSEDITION') then 814 | return true; 815 | end if; 816 | return pop(v_local_ast_before, v_local_lines_before); 817 | end; 818 | 819 | function trigger_ordering_clause return boolean is begin 820 | push('TRIGGER_ORDERING_CLAUSE'); 821 | if anything_('FOLLOWS') or anything_('PRECEDES') then 822 | if name_maybe_schema then 823 | while anything_(',') and name_maybe_schema loop null; end loop; 824 | return true; 825 | end if; 826 | parse_error('TRIGGER_ORDERING_CLAUSE'); 827 | end if; 828 | return pop; 829 | end; 830 | 831 | function when_condition return boolean is begin 832 | push('WHEN_CONDITION'); 833 | if anything_('WHEN') then 834 | if anything_in_parentheses then 835 | return true; 836 | end if; 837 | parse_error('WHEN_CONDITION'); 838 | end if; 839 | return pop; 840 | end; 841 | 842 | function trigger_body return boolean is begin 843 | push('TRIGGER_BODY'); 844 | if anything_('CALL') then 845 | g_optional := anything_up_to_may_include_(';'); 846 | return true; 847 | elsif plsql_block then return true; 848 | end if; 849 | return pop; 850 | end; 851 | 852 | function delete_insert_update_or return boolean is begin 853 | push('DELETE_INSERT_UPDATE_OR'); 854 | if anything_('DELETE') or anything_('INSERT') or anything_('UPDATE') then 855 | while anything_('OR') and (anything_('DELETE') or anything_('INSERT') or anything_('UPDATE')) loop null; end loop; 856 | return true; 857 | end if; 858 | return pop; 859 | end; 860 | 861 | function nested_table_nt_column_of return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 862 | push('NESTED_TABLE_NT_COLUMN_OF'); 863 | if anything_('NESTED') and anything_('TABLE') and name and anything_('OF') then 864 | return true; 865 | end if; 866 | return pop(v_local_ast_before, v_local_lines_before); 867 | end; 868 | 869 | function timing_point return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 870 | push('TIMING_POINT'); 871 | if current_value = 'BEFORE' and next_value = 'STATEMENT' then 872 | increment(2); 873 | return true; 874 | elsif current_value = 'BEFORE' and next_value = 'EACH' and next_value(2) = 'ROW' then 875 | increment(3); 876 | return true; 877 | elsif current_value = 'AFTER' and next_value = 'STATEMENT' then 878 | increment(2); 879 | return true; 880 | elsif current_value = 'AFTER' and next_value = 'EACH' and next_value(2) = 'ROW' then 881 | increment(3); 882 | return true; 883 | elsif current_value = 'INSTEAD' and next_value = 'OF' and next_value(2) = 'EACH' and next_value(3) = 'ROW' then 884 | increment(4); 885 | return true; 886 | end if; 887 | return pop(v_local_ast_before, v_local_lines_before); 888 | end; 889 | 890 | function tps_body return boolean is begin 891 | push('TPS_BODY'); 892 | if statement_or_inline_pragma then 893 | while statement_or_inline_pragma loop null; end loop; 894 | if anything_('EXCEPTION') then 895 | while exception_handler loop null; end loop; 896 | end if; 897 | return true; 898 | end if; 899 | return pop; 900 | end; 901 | 902 | function timing_point_section return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 903 | push('TIMING_POINT_SECTION'); 904 | if timing_point and anything_('IS') and anything_('BEGIN') and tps_body and anything_('END') and timing_point and anything_(';') then 905 | return true; 906 | end if; 907 | return pop(v_local_ast_before, v_local_lines_before); 908 | end; 909 | 910 | function compound_trigger_block return boolean is 911 | --Similar to the regular DECLARE_SECTION but also stops at timing point keywords. 912 | function declare_section return boolean is begin 913 | push('DECLARE_SECTION'); 914 | if current_value in ('BEGIN', 'END', 'BEFORE', 'AFTER', 'INSTEAD') then 915 | return pop; 916 | else 917 | loop 918 | if current_value in ('BEGIN', 'END', 'BEFORE', 'AFTER', 'INSTEAD') then 919 | return true; 920 | end if; 921 | 922 | --Of the items in ITEM_LIST_1 and ITEM_LIST_2, only 923 | --these two require any special processing. 924 | if procedure_definition then null; 925 | elsif function_definition then null; 926 | elsif anything_up_to_may_include_(';') then null; 927 | end if; 928 | end loop; 929 | end if; 930 | end; 931 | begin 932 | push('COMPOUND_TRIGGER_BLOCK'); 933 | if anything_('COMPOUND') and anything_('TRIGGER') then 934 | g_optional := declare_section; 935 | if timing_point_section then 936 | while timing_point_section loop null; end loop; 937 | if anything_('END') then 938 | g_optional := name; 939 | if anything_(';') then 940 | return true; 941 | end if; 942 | end if; 943 | end if; 944 | parse_error('COMPOUND_TRIGGER_BLOCK'); 945 | end if; 946 | return pop; 947 | end; 948 | 949 | function ddl_or_database_event return boolean is begin 950 | push('DDL_OR_DATABASE_EVENT'); 951 | if current_value in 952 | ( 953 | 'ALTER', 'ANALYZE', 'AUDIT', 'COMMENT', 'CREATE', 'DROP', 'GRANT', 'NOAUDIT', 954 | 'RENAME', 'REVOKE', 'TRUNCATE', 'DDL', 'STARTUP', 'SHUTDOWN', 'DB_ROLE_CHANGE', 955 | 'SERVERERROR', 'LOGON', 'LOGOFF', 'SUSPEND', 'CLONE', 'UNPLUG' 956 | ) then 957 | increment; 958 | return true; 959 | elsif current_value||' '|| next_value in 960 | ( 961 | 'ASSOCIATE STATISTICS', 'DISASSOCIATE STATISTICS', 'SET CONTAINER' 962 | ) then 963 | increment(2); 964 | return true; 965 | end if; 966 | return pop; 967 | end; 968 | 969 | function simple_dml_trigger return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 970 | push('SIMPLE_DML_TRIGGER'); 971 | if (anything_('BEFORE') or anything_('AFTER')) and dml_event_clause then 972 | g_optional := referencing_clause; 973 | g_optional := for_each_row; 974 | g_optional := trigger_edition_clause; 975 | g_optional := trigger_ordering_clause; 976 | if anything_('ENABLE') or anything_('DISABLE') then 977 | null; 978 | end if; 979 | g_optional := when_condition; 980 | if trigger_body then 981 | return true; 982 | end if; 983 | parse_error('SIMPLE_DML_TRIGGER'); 984 | end if; 985 | return pop(v_local_ast_before, v_local_lines_before); 986 | end; 987 | 988 | function instead_of_dml_trigger return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 989 | push('INSTEAD_OF_DML_TRIGGER'); 990 | if anything_('INSTEAD') and anything_('OF') and delete_insert_update_or then 991 | if anything_('ON') then 992 | g_optional := nested_table_nt_column_of; 993 | if name_maybe_schema then 994 | g_optional := referencing_clause; 995 | g_optional := for_each_row; 996 | g_optional := trigger_edition_clause; 997 | g_optional := trigger_ordering_clause; 998 | if anything_('ENABLE') or anything_('DISABLE') then 999 | null; 1000 | end if; 1001 | if trigger_body then 1002 | return true; 1003 | end if; 1004 | end if; 1005 | parse_error('INSTEAD_OF_DML_TRIGGER'); 1006 | end if; 1007 | end if; 1008 | return pop(v_local_ast_before, v_local_lines_before); 1009 | end; 1010 | 1011 | function compound_trigger return boolean is begin 1012 | push('COMPOUND_TRIGGER'); 1013 | if anything_('FOR') then 1014 | if dml_event_clause then 1015 | g_optional := referencing_clause; 1016 | g_optional := trigger_edition_clause; 1017 | g_optional := trigger_ordering_clause; 1018 | if anything_('ENABLE') or anything_('DISABLE') then 1019 | null; 1020 | end if; 1021 | g_optional := when_condition; 1022 | if compound_trigger_block then 1023 | return true; 1024 | end if; 1025 | end if; 1026 | parse_error('COMPOUND_TRIGGER'); 1027 | end if; 1028 | return pop; 1029 | end; 1030 | 1031 | function system_trigger return boolean is v_local_ast_before number := g_ast_index; v_local_lines_before string_table := g_debug_lines; begin 1032 | push('SYSTEM_TRIGGER'); 1033 | if (anything_('BEFORE') or anything_('AFTER') or (anything_('INSTEAD') and anything_('OF'))) and ddl_or_database_event then 1034 | while anything_('OR') and ddl_or_database_event loop null; end loop; 1035 | if anything_('ON') then 1036 | if anything_('DATABASE') or (anything_('PLUGGABLE') and anything_('DATABASE')) or anything_('SCHEMA') or (name and anything_('.') and anything_('SCHEMA')) then 1037 | g_optional := trigger_ordering_clause; 1038 | --The manual is missing the last part of SYSTEM_TRIGGER - ENABLE|DISABLE, WHEN (CONDITION) and TRIGGER_BODY. 1039 | if anything_('ENABLE') or anything_('DISABLE') then 1040 | null; 1041 | end if; 1042 | g_optional := when_condition; 1043 | if trigger_body then 1044 | return true; 1045 | end if; 1046 | end if; 1047 | end if; 1048 | parse_error('SYSTEM_TRIGGER'); 1049 | end if; 1050 | return pop(v_local_ast_before, v_local_lines_before); 1051 | end; 1052 | 1053 | function create_trigger return boolean is begin 1054 | push('CREATE_TRIGGER'); 1055 | if create_or_replace_edition and anything_('TRIGGER') and name_maybe_schema then 1056 | if simple_dml_trigger then return true; 1057 | elsif instead_of_dml_trigger then return true; 1058 | elsif compound_trigger then return true; 1059 | elsif system_trigger then return true; 1060 | end if; 1061 | parse_error('CREATE_TRIGGER'); 1062 | end if; 1063 | return pop; 1064 | end; 1065 | 1066 | 1067 | begin 1068 | --Convert parse tree into abstract syntax tree by removing whitespace, comment, and EOF. 1069 | --Also create a map between the two. 1070 | for i in p_parse_tree_index .. p_parse_tree.count loop 1071 | if p_parse_tree(i).type not in (plsql_lexer.c_whitespace, plsql_lexer.c_comment, plsql_lexer.c_eof) then 1072 | v_abstract_syntax_tree.extend; 1073 | v_abstract_syntax_tree(v_abstract_syntax_tree.count) := p_parse_tree(i); 1074 | 1075 | v_map_between_parse_and_ast.extend; 1076 | v_map_between_parse_and_ast(v_map_between_parse_and_ast.count) := i; 1077 | end if; 1078 | end loop; 1079 | 1080 | --Find the last AST token index. 1081 | -- 1082 | begin 1083 | --Consume everything 1084 | if p_terminator = C_TERMINATOR_EOF then 1085 | g_ast_index := v_abstract_syntax_tree.count + 1; 1086 | 1087 | --Look for a ';' anywhere. 1088 | elsif p_terminator = C_TERMINATOR_SEMI then 1089 | --Loop through all tokens, exit if a semicolon found. 1090 | for i in 1 .. v_abstract_syntax_tree.count loop 1091 | if v_abstract_syntax_tree(i).type = ';' then 1092 | g_ast_index := i + 1; 1093 | exit; 1094 | end if; 1095 | g_ast_index := i + 1; 1096 | end loop; 1097 | 1098 | --Match BEGIN and END for a PLSQL_DECLARATION. 1099 | elsif p_terminator = C_TERMINATOR_PLSQL_DECLARATION then 1100 | /* 1101 | PL/SQL Declarations must have this pattern before the first ";": 1102 | (null or not "START") "WITH" ("FUNCTION"|"PROCEDURE") (neither "(" nor "AS") 1103 | 1104 | This was discovered by analyzing all "with" strings in the Oracle documentation 1105 | text descriptions. That is, download the library and run a command like this: 1106 | C:\E50529_01\SQLRF\img_text> findstr /s /i "with" *.* 1107 | 1108 | SQL has mnay ambiguities, simply looking for "with function" would incorrectly catch these: 1109 | 1. Hierarchical queries. Exclude them by looking for "start" before "with". 1110 | select * from (select 1 function from dual) connect by function = 1 start with function = 1; 1111 | 2. Subquery factoring that uses "function" as a name. Stupid, but possible. 1112 | with function as (select 1 a from dual) select * from function; 1113 | with function(a) as (select 1 a from dual) select * from function; 1114 | Note: "start" cannot be the name of a table, no need to worry about DML 1115 | statements like `insert into start with ...`. 1116 | */ 1117 | for i in 1 .. v_abstract_syntax_tree.count loop 1118 | if 1119 | ( 1120 | (previous_value(2) is null or previous_value(2) <> 'START') 1121 | and previous_value(1) = 'WITH' 1122 | and current_value in ('FUNCTION', 'PROCEDURE') 1123 | and (next_value is null or next_value not in ('(', 'AS')) 1124 | ) then 1125 | if current_value in ('FUNCTION', 'PROCEDURE') then 1126 | while function_definition or procedure_definition loop null; end loop; 1127 | end if; 1128 | elsif v_abstract_syntax_tree(g_ast_index).type = ';' then 1129 | g_ast_index := g_ast_index + 1; 1130 | exit; 1131 | else 1132 | g_ast_index := g_ast_index + 1; 1133 | end if; 1134 | end loop; 1135 | --Match BEGIN and END for a common PL/SQL block. 1136 | elsif p_terminator = C_TERMINATOR_PLSQL then 1137 | if plsql_block then null; 1138 | elsif create_procedure then null; 1139 | elsif create_function then null; 1140 | elsif create_package_body then null; 1141 | elsif create_package then null; 1142 | elsif create_type_body then null; 1143 | elsif create_trigger then null; 1144 | else 1145 | parse_error(p_command_name); 1146 | end if; 1147 | end if; 1148 | exception when subscript_beyond_count then 1149 | --If a token was expected but not found just return everything up to that point. 1150 | null; 1151 | end; 1152 | 1153 | --Helpful for debugging: 1154 | --for i in 1 .. g_debug_lines.count loop 1155 | -- dbms_output.put_line(g_debug_lines(i)); 1156 | --end loop; 1157 | 1158 | --Create a new parse tree with the new tokens. 1159 | declare 1160 | v_new_parse_tree token_table := token_table(); 1161 | v_has_abstract_token boolean := false; 1162 | begin 1163 | --Special case if there are no abstract syntax tokens - add everything. 1164 | if g_ast_index = 1 then 1165 | --Create new parse tree. 1166 | for i in p_parse_tree_index .. p_parse_tree.count loop 1167 | v_new_parse_tree.extend; 1168 | v_new_parse_tree(v_new_parse_tree.count) := p_parse_tree(i); 1169 | end loop; 1170 | 1171 | --Add new parse tree. 1172 | p_split_tokens.extend; 1173 | p_split_tokens(p_split_tokens.count) := v_new_parse_tree; 1174 | 1175 | --Set the parse tree index to the end, plus one to stop loop. 1176 | p_parse_tree_index := p_parse_tree.count + 1; 1177 | 1178 | --Else iterate up to the last abstract syntax token and maybe some extra whitespace. 1179 | else 1180 | --Iterate selected parse tree tokens, add them to collection. 1181 | for i in p_parse_tree_index .. v_map_between_parse_and_ast(g_ast_index-1) loop 1182 | v_new_parse_tree.extend; 1183 | v_new_parse_tree(v_new_parse_tree.count) := p_parse_tree(i); 1184 | end loop; 1185 | 1186 | --Are any of the remaining tokens abstract? 1187 | for i in v_map_between_parse_and_ast(g_ast_index-1) + 1 .. p_parse_tree.count loop 1188 | if p_parse_tree(i).type not in (plsql_lexer.c_whitespace, plsql_lexer.c_comment, plsql_lexer.c_eof) then 1189 | v_has_abstract_token := true; 1190 | exit; 1191 | end if; 1192 | end loop; 1193 | 1194 | --If no remaining tokens are abstract, add them to the new parse tree. 1195 | --Whitespace and comments after the last statement belong to that statement, not a new one. 1196 | if not v_has_abstract_token then 1197 | for i in v_map_between_parse_and_ast(g_ast_index-1) + 1 .. p_parse_tree.count loop 1198 | v_new_parse_tree.extend; 1199 | v_new_parse_tree(v_new_parse_tree.count) := p_parse_tree(i); 1200 | end loop; 1201 | 1202 | --Set the parse tree index to the end, plus one to stop loop. 1203 | p_parse_tree_index := p_parse_tree.count + 1; 1204 | else 1205 | --Set the parse tree index based on the last AST index. 1206 | p_parse_tree_index := v_map_between_parse_and_ast(g_ast_index-1) + 1; 1207 | end if; 1208 | 1209 | --Add new tree to collection of trees. 1210 | p_split_tokens.extend; 1211 | p_split_tokens(p_split_tokens.count) := v_new_parse_tree; 1212 | end if; 1213 | end; 1214 | 1215 | end add_statement_consume_tokens; 1216 | 1217 | 1218 | -------------------------------------------------------------------------------- 1219 | --Fix line_number, column_number, first_char_position and last_char_position. 1220 | function adjust_metadata(p_split_tokens in token_table_table) return token_table_table is 1221 | v_new_split_tokens token_table_table := token_table_table(); 1222 | v_new_tokens token_table := token_table(); 1223 | v_line_number_difference number; 1224 | v_column_number_difference number; 1225 | v_first_char_position_diff number; 1226 | v_last_char_position_diff number; 1227 | begin 1228 | --Loop through split tokens. 1229 | for i in 1 .. p_split_tokens.count loop 1230 | v_new_split_tokens.extend; 1231 | --Keep the first token collection the same. 1232 | if i = 1 then 1233 | v_new_split_tokens(i) := p_split_tokens(i); 1234 | --Shift numbers for other token tables. 1235 | else 1236 | --Reset token table. 1237 | v_new_tokens := token_table(); 1238 | 1239 | --Get differences based on the first token. 1240 | v_line_number_difference := p_split_tokens(i)(1).line_number - 1; 1241 | v_column_number_difference := p_split_tokens(i)(1).column_number - 1; 1242 | v_first_char_position_diff := p_split_tokens(i)(1).first_char_position - 1; 1243 | v_last_char_position_diff := p_split_tokens(i)(1).first_char_position - 1; 1244 | 1245 | --Loop through tokens and create new adjusted values. 1246 | for token_index in 1 .. p_split_tokens(i).count loop 1247 | --Create new token with adjusted values. 1248 | v_new_tokens.extend; 1249 | v_new_tokens(v_new_tokens.count) := token( 1250 | p_split_tokens(i)(token_index).type, 1251 | p_split_tokens(i)(token_index).value, 1252 | p_split_tokens(i)(token_index).line_number - v_line_number_difference, 1253 | p_split_tokens(i)(token_index).column_number - v_column_number_difference, 1254 | p_split_tokens(i)(token_index).first_char_position - v_first_char_position_diff, 1255 | p_split_tokens(i)(token_index).last_char_position - v_last_char_position_diff, 1256 | p_split_tokens(i)(token_index).sqlcode, 1257 | p_split_tokens(i)(token_index).sqlerrm 1258 | ); 1259 | end loop; 1260 | 1261 | --Add new token collection. 1262 | v_new_split_tokens(i) := v_new_tokens; 1263 | end if; 1264 | end loop; 1265 | 1266 | return v_new_split_tokens; 1267 | end adjust_metadata; 1268 | 1269 | 1270 | -------------------------------------------------------------------------------- 1271 | --Split a token stream into statements by ";". 1272 | function split_by_semicolon(p_tokens in token_table) 1273 | return token_table_table is 1274 | v_split_tokens token_table_table := token_table_table(); 1275 | v_command_name varchar2(4000); 1276 | v_parse_tree_index number := 1; 1277 | begin 1278 | --Split into statements. 1279 | loop 1280 | --Classify. 1281 | declare 1282 | v_throwaway_number number; 1283 | v_throwaway_string varchar2(32767); 1284 | begin 1285 | statement_classifier.classify( 1286 | p_tokens => p_tokens, 1287 | p_category => v_throwaway_string, 1288 | p_statement_type => v_throwaway_string, 1289 | p_command_name => v_command_name, 1290 | p_command_type => v_throwaway_number, 1291 | p_lex_sqlcode => v_throwaway_number, 1292 | p_lex_sqlerrm => v_throwaway_string, 1293 | p_start_index => v_parse_tree_index 1294 | ); 1295 | end; 1296 | 1297 | --Find a terminating token based on the classification. 1298 | -- 1299 | --TODO: CREATE OUTLINE, CREATE SCHEMA, and some others may also differ depending on presence of PLSQL_DECLARATION. 1300 | -- 1301 | --#1: Return everything with no splitting if the statement is Invalid or Nothing. 1302 | -- These are probably errors but the application must decide how to handle them. 1303 | if v_command_name in ('Invalid', 'Nothing') then 1304 | add_statement_consume_tokens(v_split_tokens, p_tokens, C_TERMINATOR_EOF, v_parse_tree_index, v_command_name); 1305 | 1306 | --#2: Match "}" for Java code. 1307 | /* 1308 | 'CREATE JAVA', if "{" is found before first ";" 1309 | Note: Single-line comments are different, "//". Exclude any "", "", or "" after a 1310 | Create java_partial_tokenizer to lex Java statements (Based on: https://docs.oracle.com/javase/specs/jls/se7/html/jls-3.html), just need: 1311 | - multi-line comment 1312 | - single-line comment - Note Lines are terminated by the ASCII characters CR, or LF, or CR LF. 1313 | - character literal - don't count \' 1314 | - string literal - don't count \" 1315 | - { 1316 | - } 1317 | - other 1318 | - Must all files end with }? What about packages only, or annotation only file? 1319 | 1320 | CREATE JAVA CLASS USING BFILE (java_dir, 'Agent.class') 1321 | CREATE JAVA SOURCE NAMED "Welcome" AS public class Welcome { public static String welcome() { return "Welcome World"; } } 1322 | CREATE JAVA RESOURCE NAMED "appText" USING BFILE (java_dir, 'textBundle.dat') 1323 | 1324 | TODO: More examples using lexical structures. 1325 | */ 1326 | elsif v_command_name in ('CREATE JAVA') then 1327 | --TODO 1328 | raise_application_error(-29999, 'CREATE JAVA is not yet supported.'); 1329 | 1330 | --#3: Match PLSQL_DECLARATION BEGIN and END. 1331 | elsif v_command_name in 1332 | ( 1333 | 'CREATE MATERIALIZED VIEW ', 'CREATE SCHEMA', 'CREATE TABLE', 'CREATE VIEW', 1334 | 'DELETE', 'EXPLAIN', 'INSERT', 'SELECT', 'UPDATE', 'UPSERT' 1335 | ) then 1336 | add_statement_consume_tokens(v_split_tokens, p_tokens, C_TERMINATOR_PLSQL_DECLARATION, v_parse_tree_index, v_command_name); 1337 | 1338 | --#4: Match PL/SQL BEGIN and END. 1339 | elsif v_command_name in 1340 | ( 1341 | 'PL/SQL EXECUTE', 'CREATE FUNCTION','CREATE PROCEDURE', 'CREATE PACKAGE', 1342 | 'CREATE PACKAGE BODY', 'CREATE TYPE BODY', 'CREATE TRIGGER' 1343 | ) then 1344 | add_statement_consume_tokens(v_split_tokens, p_tokens, C_TERMINATOR_PLSQL, v_parse_tree_index, v_command_name); 1345 | 1346 | --#5: Stop at first ";" for everything else. 1347 | else 1348 | add_statement_consume_tokens(v_split_tokens, p_tokens, C_TERMINATOR_SEMI, v_parse_tree_index, v_command_name); 1349 | end if; 1350 | 1351 | --Quit when there are no more tokens. 1352 | exit when v_parse_tree_index > p_tokens.count; 1353 | end loop; 1354 | 1355 | --Fix line_number, column_number, first_char_position and last_char_position. 1356 | v_split_tokens := adjust_metadata(v_split_tokens); 1357 | 1358 | return v_split_tokens; 1359 | end split_by_semicolon; 1360 | 1361 | 1362 | -------------------------------------------------------------------------------- 1363 | --Split a string into separate strings by an optional delmiter, usually "/". 1364 | --This follows the SQL*Plus rules - the delimiter must be on a line by itself, 1365 | --although the line may contain whitespace before and after the delimiter. 1366 | --The delimiter and whitespace on the same line are included with the first statement. 1367 | function split_by_sqlplus_delimiter(p_statements in clob, p_sqlplus_delimiter in varchar2 default '/') return clob_table is 1368 | v_chars varchar2_table := plsql_lexer.get_varchar2_table_from_clob(p_statements); 1369 | v_delimiter_size number := nvl(lengthc(p_sqlplus_delimiter), 0); 1370 | v_char_index number := 0; 1371 | v_string clob; 1372 | v_is_empty_line boolean := true; 1373 | 1374 | v_strings clob_table := clob_table(); 1375 | 1376 | --Get N chars for comparing with multi-character delimiter. 1377 | function get_next_n_chars(p_n number) return varchar2 is 1378 | v_next_n_chars varchar2(32767); 1379 | begin 1380 | for i in v_char_index .. least(v_char_index + p_n - 1, v_chars.count) loop 1381 | v_next_n_chars := v_next_n_chars || v_chars(i); 1382 | end loop; 1383 | 1384 | return v_next_n_chars; 1385 | end get_next_n_chars; 1386 | 1387 | --Check if there are only whitespace characters before the next newline 1388 | function only_ws_before_next_newline return boolean is 1389 | begin 1390 | --Loop through the characters. 1391 | for i in v_char_index + v_delimiter_size .. v_chars.count loop 1392 | --TRUE if a newline is found. 1393 | if v_chars(i) = chr(10) then 1394 | return true; 1395 | --False if non-whitespace is found. 1396 | elsif not plsql_lexer.is_lexical_whitespace(v_chars(i)) then 1397 | return false; 1398 | end if; 1399 | end loop; 1400 | 1401 | --True if neither a newline or a non-whitespace was found. 1402 | return true; 1403 | end only_ws_before_next_newline; 1404 | begin 1405 | --Special cases. 1406 | -- 1407 | --Throw an error if the delimiter is null. 1408 | if p_sqlplus_delimiter is null then 1409 | raise_application_error(-20000, 'The SQL*Plus delimiter cannot be NULL.'); 1410 | end if; 1411 | --Throw an error if the delimiter contains whitespace. 1412 | for i in 1 .. lengthc(p_sqlplus_delimiter) loop 1413 | if plsql_lexer.is_lexical_whitespace(substrc(p_sqlplus_delimiter, i, 1)) then 1414 | raise_application_error(-20001, 'The SQL*Plus delimiter cannot contain whitespace.'); 1415 | end if; 1416 | end loop; 1417 | --Return an empty string if the string is NULL. 1418 | if p_statements is null then 1419 | v_strings.extend; 1420 | v_strings(v_strings.count) := p_statements; 1421 | return v_strings; 1422 | end if; 1423 | 1424 | --Loop through characters and build strings. 1425 | loop 1426 | v_char_index := v_char_index + 1; 1427 | 1428 | --Look for delimiter if it's on an empty line. 1429 | if v_is_empty_line then 1430 | --Add char, push, and exit if it's the last character. 1431 | if v_char_index = v_chars.count then 1432 | v_string := v_string || v_chars(v_char_index); 1433 | v_strings.extend; 1434 | v_strings(v_strings.count) := v_string; 1435 | exit; 1436 | --Continue if it's still whitespace. 1437 | elsif plsql_lexer.is_lexical_whitespace(v_chars(v_char_index)) then 1438 | v_string := v_string || v_chars(v_char_index); 1439 | --Split string if delimiter is found. 1440 | elsif get_next_n_chars(v_delimiter_size) = p_sqlplus_delimiter and only_ws_before_next_newline then 1441 | --Consume delimiter. 1442 | for i in 1 .. v_delimiter_size loop 1443 | v_string := v_string || v_chars(v_char_index); 1444 | v_char_index := v_char_index + 1; 1445 | end loop; 1446 | 1447 | --Consume all tokens until either end of string or next character is non-whitespace. 1448 | loop 1449 | v_string := v_string || v_chars(v_char_index); 1450 | v_char_index := v_char_index + 1; 1451 | exit when v_char_index = v_chars.count or not plsql_lexer.is_lexical_whitespace(v_chars(v_char_index)); 1452 | end loop; 1453 | 1454 | --Remove extra increment. 1455 | v_char_index := v_char_index - 1; 1456 | 1457 | --Add string and start over. 1458 | v_strings.extend; 1459 | v_strings(v_strings.count) := v_string; 1460 | v_string := null; 1461 | v_is_empty_line := false; 1462 | --It's no longer an empty line otherwise. 1463 | else 1464 | v_string := v_string || v_chars(v_char_index); 1465 | v_is_empty_line := false; 1466 | end if; 1467 | --Add the string after the last character. 1468 | elsif v_char_index >= v_chars.count then 1469 | v_string := v_string || v_chars(v_char_index); 1470 | v_strings.extend; 1471 | v_strings(v_strings.count) := v_string; 1472 | exit; 1473 | --Look for newlines. 1474 | elsif v_chars(v_char_index) = chr(10) then 1475 | v_string := v_string || v_chars(v_char_index); 1476 | v_is_empty_line := true; 1477 | --Else just add the character. 1478 | else 1479 | v_string := v_string || v_chars(v_char_index); 1480 | end if; 1481 | end loop; 1482 | 1483 | return v_strings; 1484 | end split_by_sqlplus_delimiter; 1485 | 1486 | 1487 | -------------------------------------------------------------------------------- 1488 | --Split a string of separate SQL and PL/SQL statements terminated by ";" and 1489 | --some secondary terminator, usually "/". 1490 | function split_by_sqlplus_del_and_semi(p_statements in clob, p_sqlplus_delimiter in varchar2 default '/') 1491 | return token_table_table is 1492 | v_split_statements clob_table := clob_table(); 1493 | v_split_token_tables token_table_table := token_table_table(); 1494 | begin 1495 | --First split by SQL*Plus delimiter. 1496 | v_split_statements := split_by_sqlplus_delimiter(p_statements, p_sqlplus_delimiter); 1497 | 1498 | --Split each string further by the primary terminator, ";". 1499 | for i in 1 .. v_split_statements.count loop 1500 | v_split_token_tables := 1501 | v_split_token_tables 1502 | multiset union 1503 | split_by_semicolon(plsql_lexer.lex(v_split_statements(i))); 1504 | end loop; 1505 | 1506 | --Return the statements. 1507 | return v_split_token_tables; 1508 | end split_by_sqlplus_del_and_semi; 1509 | 1510 | 1511 | end; 1512 | / 1513 | -------------------------------------------------------------------------------- /packages/statement_terminator.plsql: -------------------------------------------------------------------------------- 1 | create or replace package statement_terminator is 2 | --Copyright (C) 2015 Jon Heller. This program is licensed under the LGPLv3. 3 | 4 | function remove_semicolon( 5 | p_tokens in token_table 6 | ) return token_table; 7 | 8 | function remove_sqlplus_delimiter( 9 | p_tokens in token_table, 10 | p_sqlplus_delimiter in varchar2 default '/' 11 | ) return token_table; 12 | 13 | function remove_sqlplus_del_and_semi( 14 | p_tokens in token_table, 15 | p_sqlplus_delimiter in varchar2 default '/' 16 | ) return token_table; 17 | 18 | /* 19 | 20 | == PURPOSE == 21 | 22 | Statement Terminator removes terminating semicolons and SQL*Plus delimiters from 23 | the end of a statement. This is helpful when the statement will be executed as 24 | dynamic SQL. 25 | 26 | Dynamic SQL requires some commands must include a terminating semicolon and 27 | other commands must not include a semicolon. For example, "create table ..." 28 | must not have a semicolon, but "create procedure ..." must end with a semicolon. 29 | 30 | Only the last semicolon is removed. Just like with SQL*Plus, statements 31 | that end with two semicolons will not work correctly. 32 | 33 | Semicolons may not be removed if the statement has a serious parsing error, like 34 | an unclosed comment. 35 | 36 | 37 | == EXAMPLE == 38 | 39 | select statement_semicolon_remover.remove(plsql_lexer.lex('select * from dual;')) 40 | from dual; 41 | 42 | Results: 43 | 44 | select * from dual 45 | 46 | 47 | == PARAMETERS == 48 | 49 | - p_tokens (IN): Tokens for a statement, probably generated by PLSQL_LEXER. 50 | - p_statement (IN): A SQL statement. 51 | - p_sqlplus_delimiter (IN): A SQL*Plus delimiter, usually "/". Remember that 52 | SQL*Plus delimiters must be on a line with only 53 | whitespace. 54 | */ 55 | 56 | end; 57 | / 58 | create or replace package body statement_terminator is 59 | 60 | -------------------------------------------------------------------------------- 61 | --Build the statement excluding the last semicolon, if any. 62 | function build_statement_wo_semicolon(p_abstract_tokens token_table) 63 | return token_table is 64 | v_tokens token_table := token_table(); 65 | v_semicolon_index number := -1; 66 | v_semicolon_line_number number; 67 | begin 68 | --Find the index of the last semicolon token. 69 | --Only count it if it's the last concrete token. 70 | for i in reverse 1 .. p_abstract_tokens.count loop 71 | --Record index if it's a semicolon. 72 | if p_abstract_tokens(i).type = ';' then 73 | v_semicolon_index := i; 74 | v_semicolon_line_number := p_abstract_tokens(i).line_number; 75 | --Quit the loop if another concrete token is found. 76 | elsif p_abstract_tokens(i).type not in (plsql_lexer.c_comment, plsql_lexer.c_whitespace, plsql_lexer.c_eof) then 77 | exit; 78 | end if; 79 | end loop; 80 | 81 | --Put together string, excluding the semicolon. 82 | for i in 1 .. p_abstract_tokens.count loop 83 | --Concatenate two whitespaces if it was after the removed semicolon. 84 | if i = v_semicolon_index + 1 and p_abstract_tokens(i).type = plsql_lexer.c_whitespace then 85 | --Concatenate values. 86 | v_tokens(i-2).value := v_tokens(i-2).value || p_abstract_tokens(i).value; 87 | --Adjust metadata. 88 | v_tokens(i-2).last_char_position := p_abstract_tokens(i).last_char_position - 1; 89 | --Add token if it's not the semicolon. 90 | elsif i <> v_semicolon_index then 91 | v_tokens.extend; 92 | v_tokens(v_tokens.count) := p_abstract_tokens(i); 93 | end if; 94 | end loop; 95 | 96 | --Fix metadata by going through all tokens on or after it's old spot. 97 | --LINE_NUMBER - nothing to fix 98 | --COLUMN_NUMBER - Shrink by 1 if after semicolon but on same line. 99 | --FIRST_CHAR_POSITION - Shrink by 1 if after semicolon. 100 | --LAST_CHAR_POSITION - Shrink by 1 if after semicolon 101 | if v_semicolon_index <> -1 then 102 | for i in v_semicolon_index .. v_tokens.count loop 103 | if v_tokens(i).line_number = v_semicolon_line_number then 104 | v_tokens(i).column_number := v_tokens(i).column_number - 1; 105 | end if; 106 | v_tokens(i).first_char_position := v_tokens(i).first_char_position - 1; 107 | v_tokens(i).last_char_position := v_tokens(i).last_char_position - 1; 108 | end loop; 109 | end if; 110 | 111 | return v_tokens; 112 | end build_statement_wo_semicolon; 113 | 114 | 115 | -------------------------------------------------------------------------------- 116 | --Remove extra semicolons, if any, to prepare for dynamic execution. 117 | function remove_semicolon(p_tokens in token_table) return token_table is 118 | v_command_name varchar2(4000); 119 | v_lex_sqlcode number; 120 | v_lex_sqlerrm varchar2(4000); 121 | v_throwaway varchar2(4000); 122 | begin 123 | --Classify the tokens/statement. 124 | statement_classifier.classify( 125 | p_tokens => p_tokens, 126 | p_category => v_throwaway, 127 | p_statement_type => v_throwaway, 128 | p_command_name => v_command_name, 129 | p_command_type => v_throwaway, 130 | p_lex_sqlcode => v_lex_sqlcode, 131 | p_lex_sqlerrm => v_lex_sqlerrm 132 | ); 133 | 134 | --Do nothing if there's a serious parsing error: 135 | if v_lex_sqlcode is not null or v_lex_sqlerrm is not null then 136 | return p_tokens; 137 | --Triggers sometimes need semicolons and sometimes do not. 138 | elsif v_command_name = 'CREATE TRIGGER' then 139 | declare 140 | v_not_needed number; 141 | v_trigger_type number; 142 | begin 143 | --Get trigger type. 144 | statement_classifier.get_trigger_type_body_index(p_tokens, p_trigger_type => v_trigger_type, p_trigger_body_start_index => v_not_needed); 145 | --CALL triggers need semicolons removed. 146 | if v_trigger_type = statement_classifier.C_TRIGGER_TYPE_CALL then 147 | return build_statement_wo_semicolon(p_tokens); 148 | --All other triggers need to keep the semicolon. 149 | else 150 | return p_tokens; 151 | end if; 152 | end; 153 | --Remove semicolons from these: 154 | elsif v_command_name in ( 155 | 'ADMINISTER KEY MANAGEMENT','ALTER ASSEMBLY','ALTER AUDIT POLICY','ALTER CLUSTER','ALTER DATABASE', 156 | 'ALTER DATABASE LINK','ALTER DIMENSION','ALTER DISK GROUP','ALTER DOMAIN', 'ALTER EDITION','ALTER FLASHBACK ARCHIVE', 157 | 'ALTER FUNCTION','ALTER INDEX','ALTER INDEXTYPE','ALTER JAVA','ALTER LIBRARY','ALTER MATERIALIZED VIEW ', 158 | 'ALTER MATERIALIZED VIEW LOG','ALTER MATERIALIZED ZONEMAP','ALTER MLE ENV','ALTER MLE MODULE','ALTER OPERATOR','ALTER OUTLINE', 159 | 'ALTER PACKAGE','ALTER PACKAGE BODY','ALTER PLUGGABLE DATABASE','ALTER PMEM FILESTORE','ALTER PROCEDURE','ALTER PROFILE', 160 | 'ALTER PROPERTY GRAPH','ALTER RESOURCE COST',/*'ALTER REWRITE EQUIVALENCE',*/'ALTER ROLE','ALTER ROLLBACK SEGMENT', 161 | 'ALTER SEQUENCE','ALTER SESSION',/*'ALTER SUMMARY',*/'ALTER SYNONYM','ALTER SYSTEM','ALTER TABLE', 162 | 'ALTER TABLESPACE','ALTER TRACING','ALTER TRIGGER','ALTER TYPE','ALTER TYPE BODY','ALTER USER', 163 | 'ALTER VIEW','ANALYZE CLUSTER','ANALYZE INDEX','ANALYZE TABLE','ASSOCIATE STATISTICS','AUDIT OBJECT', 164 | 'CALL METHOD',/*'CHANGE PASSWORD',*/'COMMENT','COMMIT',/*'CREATE ASSEMBLY',*/'CREATE AUDIT POLICY', 165 | /*'CREATE BITMAPFILE',*/'CREATE CLUSTER','CREATE CONTEXT','CREATE CONTROL FILE','CREATE DATABASE', 166 | 'CREATE DATABASE LINK','CREATE DIMENSION','CREATE DIRECTORY','CREATE DISK GROUP','CREATE DOMAIN', 'CREATE EDITION', 167 | 'CREATE FLASHBACK ARCHIVE',/*'CREATE FUNCTION',*/'CREATE INDEX','CREATE INDEXTYPE',/*'CREATE JAVA',*/ 168 | /*'CREATE LIBRARY',*/'CREATE MATERIALIZED VIEW ','CREATE MATERIALIZED VIEW LOG','CREATE MATERIALIZED ZONEMAP', 169 | 'CREATE MLE ENV',/*'CREATE MLE MODULE',*/'CREATE OPERATOR','CREATE OUTLINE',/*'CREATE PACKAGE',*//*'CREATE PACKAGE BODY',*/'CREATE PFILE', 170 | 'CREATE PLUGGABLE DATABASE','CREATE PMEM FILESTORE',/*'CREATE PROCEDURE',*/'CREATE PROFILE','CREATE PROPERTY GRAPH','CREATE RESTORE POINT','CREATE ROLE', 171 | 'CREATE ROLLBACK SEGMENT','CREATE SCHEMA','CREATE SCHEMA SYNONYM','CREATE SEQUENCE','CREATE SPFILE', 172 | /*'CREATE SUMMARY',*/'CREATE SYNONYM','CREATE TABLE','CREATE TABLESPACE',/*'CREATE TRIGGER',*//*'CREATE TYPE',*/ 173 | /*'CREATE TYPE BODY',*/'CREATE USER','CREATE VIEW',/*'DECLARE REWRITE EQUIVALENCE',*/'DELETE', 174 | 'DISASSOCIATE STATISTICS','DROP ASSEMBLY','DROP AUDIT POLICY',/*'DROP BITMAPFILE',*/'DROP CLUSTER', 175 | 'DROP CONTEXT','DROP DATABASE','DROP DATABASE LINK','DROP DIMENSION','DROP DIRECTORY','DROP DISK GROUP', 176 | 'DROP DOMAIN', 'DROP EDITION','DROP FLASHBACK ARCHIVE','DROP FUNCTION','DROP INDEX','DROP INDEXTYPE','DROP JAVA', 177 | 'DROP LIBRARY','DROP MATERIALIZED VIEW ','DROP MATERIALIZED VIEW LOG','DROP MATERIALIZED ZONEMAP', 178 | 'DROP MLE ENV','DROP MLE MODULE','DROP OPERATOR','DROP OUTLINE','DROP PACKAGE','DROP PACKAGE BODY','DROP PLUGGABLE DATABASE', 179 | 'DROP PMEM FILESTORE','DROP PROCEDURE','DROP PROFILE','DROP PROPERTY GRAPH','DROP RESTORE POINT',/*'DROP REWRITE EQUIVALENCE',*/'DROP ROLE', 180 | 'DROP ROLLBACK SEGMENT','DROP SCHEMA SYNONYM','DROP SEQUENCE',/*'DROP SUMMARY',*/'DROP SYNONYM', 181 | 'DROP TABLE','DROP TABLESPACE','DROP TRIGGER','DROP TYPE','DROP TYPE BODY','DROP USER','DROP VIEW', 182 | /*'Do not use 184',*//*'Do not use 185',*//*'Do not use 186',*/'EXPLAIN','FLASHBACK DATABASE', 183 | 'FLASHBACK TABLE','GRANT OBJECT','INSERT','LOCK TABLE',/*'NO-OP',*/'NOAUDIT OBJECT',/*'PL/SQL EXECUTE',*/ 184 | 'PURGE DBA RECYCLEBIN','PURGE INDEX','PURGE TABLE','PURGE TABLESPACE','PURGE USER RECYCLEBIN','RENAME', 185 | 'REVOKE OBJECT','ROLLBACK','SAVEPOINT','SELECT','SET CONSTRAINTS','SET ROLE','SET TRANSACTION', 186 | 'TRUNCATE CLUSTER','TRUNCATE TABLE',/*'UNDROP OBJECT',*/'UPDATE',/*'UPDATE INDEXES',*/ 187 | /*'UPDATE JOIN INDEX',*/'UPSERT'/*'VALIDATE INDEX',*/ 188 | ) then 189 | return build_statement_wo_semicolon(p_tokens); 190 | --Do nothing for these, they can end with a semicolon: 191 | elsif v_command_name in ( 192 | 'CREATE ASSEMBLY', 193 | 'CREATE FUNCTION', 194 | 'CREATE JAVA', 195 | 'CREATE LIBRARY', 196 | -- MLE Module is unusual - it works both with and without a comma in SQL. 197 | -- However, since SQL*Plus needs the slash, it seems safer to include the last semicolon. 198 | -- For example, the same command runs in the below PL/SQL block both with and without the semicolon. 199 | --begin 200 | -- execute immediate 'create or replace mle module test_module language JAVASCRIPT as ''asdf asdf'''; 201 | -- execute immediate 'create or replace mle module test_module language JAVASCRIPT as ''asdf asdf'';'; 202 | --end; 203 | 'CREATE MLE MODULE', 204 | 'CREATE PACKAGE', 205 | 'CREATE PACKAGE BODY', 206 | 'CREATE PROCEDURE', 207 | 'CREATE TYPE', 208 | 'CREATE TYPE BODY', 209 | 'PL/SQL EXECUTE', 210 | 'Invalid', 211 | 'Nothing' 212 | ) then 213 | return p_tokens; 214 | else 215 | raise_application_error(-20000, 'Cannot determine if statement needs a semicolon.'|| 216 | ' The command name "'||v_command_name||'" is not recognized.'); 217 | end if; 218 | end remove_semicolon; 219 | 220 | 221 | -------------------------------------------------------------------------------- 222 | function remove_sqlplus_delimiter( 223 | p_tokens in token_table, 224 | p_sqlplus_delimiter in varchar2 default '/' 225 | ) return token_table 226 | is 227 | v_delimiter_begin_index number; 228 | v_delimiter_end_index number; 229 | 230 | v_2_token_before_delimiter token; 231 | v_1_token_before_delimiter token; 232 | v_potential_delimiter clob; 233 | v_1_token_after_delimiter token; 234 | v_2_token_after_delimiter token; 235 | 236 | v_tokens_without_delimiter token_table := token_table(); 237 | begin 238 | --Special cases. 239 | -- 240 | --Throw an error if the delimiter is null. 241 | if p_sqlplus_delimiter is null then 242 | raise_application_error(-20000, 'The SQL*Plus delimiter cannot be NULL.'); 243 | end if; 244 | --Throw an error if the delimiter contains whitespace. 245 | for i in 1 .. lengthc(p_sqlplus_delimiter) loop 246 | if plsql_lexer.is_lexical_whitespace(substrc(p_sqlplus_delimiter, i, 1)) then 247 | raise_application_error(-20001, 'The SQL*Plus delimiter cannot contain whitespace.'); 248 | end if; 249 | end loop; 250 | --Return an empty string if the string is NULL. 251 | if p_tokens is null then 252 | return null; 253 | end if; 254 | 255 | --Gather tokens before and after, and delimiter. 256 | -- 257 | --Loop through all tokens in reverse order. 258 | for token_index in reverse 1 .. p_tokens.count loop 259 | --Look for the last non-whitespace/comment/EOF 260 | if p_tokens(token_index).type not in (plsql_lexer.c_whitespace, plsql_lexer.c_comment, plsql_lexer.c_eof) then 261 | v_delimiter_end_index := token_index; 262 | 263 | --Get tokens after delimiter. 264 | v_1_token_after_delimiter := p_tokens(token_index + 1); 265 | if token_index + 2 <= p_tokens.count then 266 | v_2_token_after_delimiter := p_tokens(token_index + 2); 267 | end if; 268 | 269 | --Get potential delimiter - go until whitespace or comment found. 270 | for delimiter_index in reverse 1 .. token_index loop 271 | --Build delimiter. 272 | if p_tokens(delimiter_index).type not in (plsql_lexer.c_whitespace, plsql_lexer.c_comment) then 273 | v_delimiter_begin_index := delimiter_index; 274 | v_potential_delimiter := p_tokens(delimiter_index).value || v_potential_delimiter; 275 | --If something else found, get tokens before delimiter and quit. 276 | else 277 | v_delimiter_begin_index := delimiter_index + 1; 278 | v_1_token_before_delimiter := p_tokens(delimiter_index); 279 | if delimiter_index - 1 >= 1 then 280 | v_2_token_before_delimiter := p_tokens(delimiter_index - 1); 281 | end if; 282 | exit; 283 | end if; 284 | end loop; 285 | 286 | --Quit outer loop. 287 | exit; 288 | end if; 289 | end loop; 290 | 291 | --Return the original statement if these conditions do not match: 292 | if 293 | --Delimiters must match. 294 | (p_sqlplus_delimiter = v_potential_delimiter) and 295 | --Before the delimiter, if anything, must be whitespace. 296 | (v_1_token_before_delimiter is null or v_1_token_before_delimiter.type = plsql_lexer.c_whitespace) and 297 | --If there are two tokens before then the first token before must have a newline. 298 | (v_2_token_before_delimiter is null or instr(v_1_token_before_delimiter.value, chr(10)) >= 1) and 299 | --After the delimiter, if anything, must be whitespace or EOF. 300 | (v_1_token_after_delimiter is null or v_1_token_after_delimiter.type in (plsql_lexer.c_whitespace, plsql_lexer.c_eof)) and 301 | --There is only one token after, or the second token after is EOF, or the first token after has a newline. 302 | (v_2_token_after_delimiter is null or v_2_token_after_delimiter.type = plsql_lexer.c_eof 303 | or 304 | ( 305 | instr(v_1_token_after_delimiter.value, chr(10)) >= 1 306 | ) 307 | ) 308 | then 309 | null; 310 | else 311 | return p_tokens; 312 | end if; 313 | 314 | --Put the string back together without the delimiter. 315 | if v_delimiter_begin_index is null then 316 | v_tokens_without_delimiter := p_tokens; 317 | else 318 | for i in 1 .. p_tokens.count loop 319 | if i not between v_delimiter_begin_index and v_delimiter_end_index then 320 | v_tokens_without_delimiter.extend; 321 | v_tokens_without_delimiter(v_tokens_without_delimiter.count) := p_tokens(i); 322 | end if; 323 | end loop; 324 | end if; 325 | 326 | return v_tokens_without_delimiter; 327 | end remove_sqlplus_delimiter; 328 | 329 | 330 | -------------------------------------------------------------------------------- 331 | function remove_sqlplus_del_and_semi( 332 | p_tokens in token_table, 333 | p_sqlplus_delimiter in varchar2 default '/' 334 | ) return token_table 335 | is 336 | begin 337 | return remove_semicolon(remove_sqlplus_delimiter(p_tokens, p_sqlplus_delimiter)); 338 | end remove_sqlplus_del_and_semi; 339 | 340 | end; 341 | / 342 | -------------------------------------------------------------------------------- /packages/syntax_tree.plsql: -------------------------------------------------------------------------------- 1 | create or replace package syntax_tree is 2 | --Copyright (C) 2016 Jon Heller. This program is licensed under the LGPLv3. 3 | 4 | -- _____ ____ _ _ ____ _______ _ _ _____ ______ __ ________ _______ 5 | -- | __ \ / __ \ | \ | |/ __ \__ __| | | | |/ ____| ____| \ \ / / ____|__ __| 6 | -- | | | | | | | | \| | | | | | | | | | | (___ | |__ \ \_/ /| |__ | | 7 | -- | | | | | | | | . ` | | | | | | | | | |\___ \| __| \ / | __| | | 8 | -- | |__| | |__| | | |\ | |__| | | | | |__| |____) | |____ | | | |____ | | 9 | -- |_____/ \____/ |_| \_|\____/ |_| \____/|_____/|______| |_| |______| |_| 10 | -- 11 | --This package is experimental and does not work yet. 12 | 13 | 14 | procedure add_child_ids(p_nodes in out node_table); 15 | function get_child_node_by_type(p_nodes node_table, p_node_index number, p_node_type varchar2, p_occurrence number default 1) return node; 16 | function get_children_node_by_type(p_nodes node_table, p_node_index number, p_node_type varchar2) return node_table; 17 | function get_first_ancest_node_by_type(p_nodes node_table, p_node_index number, p_node_type varchar2) return node; 18 | 19 | function are_names_equal(p_name1 varchar2, p_name2 varchar2) return boolean; 20 | function get_data_dictionary_case(p_name varchar2) return varchar2; 21 | 22 | /* 23 | 24 | == Purpose == 25 | 26 | Contains functions and procedures for managing node tables - walking, converting, etc. 27 | 28 | == Example == 29 | 30 | TODO 31 | 32 | 33 | */ 34 | end; 35 | / 36 | create or replace package body syntax_tree is 37 | --Copyright (C) 2016 Jon Heller. This program is licensed under the LGPLv3. 38 | 39 | -- _____ ____ _ _ ____ _______ _ _ _____ ______ __ ________ _______ 40 | -- | __ \ / __ \ | \ | |/ __ \__ __| | | | |/ ____| ____| \ \ / / ____|__ __| 41 | -- | | | | | | | | \| | | | | | | | | | | (___ | |__ \ \_/ /| |__ | | 42 | -- | | | | | | | | . ` | | | | | | | | | |\___ \| __| \ / | __| | | 43 | -- | |__| | |__| | | |\ | |__| | | | | |__| |____) | |____ | | | |____ | | 44 | -- |_____/ \____/ |_| \_|\____/ |_| \____/|_____/|______| |_| |______| |_| 45 | -- 46 | --This package is experimental and does not work yet. 47 | 48 | --TODO: Am I re-inventing an XML wheel here? 49 | 50 | --Purpose: Set all the CHILD_IDs of a node_table based on the parent_id. 51 | --ASSUMPTIONS: p_nodes is dense, all child_ids are NULL, all parent_ids are set correctly, 52 | -- nodes are added in tree order so a child node will always have an ID after the parent. 53 | procedure add_child_ids(p_nodes in out node_table) is 54 | v_child_ids number_table; 55 | begin 56 | --Loop through each node, look for nodes that refer to it. 57 | for i in 1 .. p_nodes.count loop 58 | v_child_ids := number_table(); 59 | 60 | --Gather child nodes. 61 | for j in i .. p_nodes.count loop 62 | if p_nodes(j).parent_id = i then 63 | v_child_ids.extend; 64 | v_child_ids(v_child_ids.count) := j; 65 | end if; 66 | end loop; 67 | 68 | --Set it if it's not null 69 | if v_child_ids.count > 0 then 70 | p_nodes(i).child_ids := v_child_ids; 71 | end if; 72 | 73 | end loop; 74 | end; 75 | 76 | 77 | function get_child_node_by_type(p_nodes node_table, p_node_index number, p_node_type varchar2, p_occurrence number default 1) return node is 78 | v_counter number := 0; 79 | begin 80 | --TODO: Verify p_occurance 81 | 82 | for i in 1 .. p_nodes(p_node_index).child_ids.count loop 83 | if p_nodes(p_nodes(p_node_index).child_ids(i)).type = p_node_type then 84 | v_counter := v_counter + 1; 85 | if v_counter = p_occurrence then 86 | return p_nodes(p_nodes(p_node_index).child_ids(i)); 87 | end if; 88 | end if; 89 | end loop; 90 | 91 | return null; 92 | end get_child_node_by_type; 93 | 94 | 95 | function get_children_node_by_type(p_nodes node_table, p_node_index number, p_node_type varchar2) return node_table is 96 | v_nodes node_table := node_table(); 97 | begin 98 | for i in 1 .. p_nodes(p_node_index).child_ids.count loop 99 | if p_nodes(p_nodes(p_node_index).child_ids(i)).type = p_node_type then 100 | v_nodes.extend; 101 | v_nodes(v_nodes.count) := p_nodes(p_nodes(p_node_index).child_ids(i)); 102 | end if; 103 | end loop; 104 | 105 | return v_nodes; 106 | end get_children_node_by_type; 107 | 108 | 109 | function get_first_ancest_node_by_type(p_nodes node_table, p_node_index number, p_node_type varchar2) return node is 110 | v_parent_id number; 111 | begin 112 | --Special case if already at top, return null. 113 | if p_nodes(p_node_index) is null then 114 | return null; 115 | end if; 116 | 117 | v_parent_id := p_nodes(p_node_index).parent_id; 118 | 119 | --Climb up tree until correct node found. 120 | loop 121 | --Nothing left to serach for, return NULL. 122 | if v_parent_id is null then 123 | return null; 124 | --Node found, return it. 125 | elsif p_nodes(v_parent_id).type = p_node_type then 126 | return p_nodes(v_parent_id); 127 | --Nothing found, go to next parent 128 | else 129 | v_parent_id := p_nodes(v_parent_id).parent_id; 130 | end if; 131 | end loop; 132 | 133 | end get_first_ancest_node_by_type; 134 | 135 | 136 | --Purpose: Compare names using the Oracle double-quote rules. 137 | --Object names are case-insensitive *unless* they use double-quotes, except that 138 | --double-quotes with all upper-case are really case-insensitive. 139 | --Assumes: Names do not have leading or trailing whitespace, and are real names. 140 | function are_names_equal(p_name1 varchar2, p_name2 varchar2) return boolean is 141 | is_case_sensitive boolean := false; 142 | begin 143 | --Comparison is case sensitive if either name is case-sensitive. 144 | if 145 | ( 146 | (p_name1 like '"%"' and p_name1 <> upper(p_name1)) 147 | or 148 | (p_name2 like '"%"' and p_name2 <> upper(p_name2)) 149 | ) 150 | then 151 | is_case_sensitive := true; 152 | end if; 153 | 154 | --Compare them as-is if case sensitive. 155 | if is_case_sensitive then 156 | return p_name1 = p_name2; 157 | --Trim double-quotes and compare in same case if case insensitive. 158 | else 159 | return 160 | upper(trim('"' from p_name1)) = upper(trim('"' from p_name2)); 161 | end if; 162 | 163 | return null; 164 | end are_names_equal; 165 | 166 | 167 | --Convert a name string to the case needed to match the data dictionary. 168 | --Examples: 169 | --asdf --> ASDF 170 | --"asdf" --> asdf 171 | --"ASDF" --> ASDF 172 | function get_data_dictionary_case(p_name varchar2) return varchar2 is 173 | begin 174 | if p_name like '"%"' then 175 | return trim('"' from p_name); 176 | else 177 | return upper(p_name); 178 | end if; 179 | end get_data_dictionary_case; 180 | 181 | 182 | end; 183 | / 184 | -------------------------------------------------------------------------------- /tests/misplaced_hints_test.plsql: -------------------------------------------------------------------------------- 1 | create or replace package misplaced_hints_test authid current_user is 2 | /* 3 | == Purpose == 4 | 5 | Unit tests for MISPLACED_HINTS. 6 | 7 | 8 | == Example == 9 | 10 | begin 11 | misplaced_hints_test.run; 12 | end; 13 | 14 | */ 15 | pragma serially_reusable; 16 | 17 | --Globals to select which test suites to run. 18 | c_test_code constant number := power(2, 1); 19 | c_test_schema constant number := power(2, 2); 20 | 21 | --Default option is to run all static test suites. 22 | c_static_tests constant number := c_test_code+c_test_schema; 23 | 24 | --Run the unit tests and display the results in dbms output. 25 | procedure run(p_tests number default c_static_tests); 26 | 27 | end; 28 | / 29 | create or replace package body misplaced_hints_test is 30 | pragma serially_reusable; 31 | 32 | --Global counters. 33 | g_test_count number := 0; 34 | g_passed_count number := 0; 35 | g_failed_count number := 0; 36 | 37 | --Helper procedures. 38 | -------------------------------------------------------------------------------- 39 | procedure assert_equals(p_test varchar2, p_expected varchar2, p_actual varchar2) is 40 | begin 41 | g_test_count := g_test_count + 1; 42 | 43 | if p_expected = p_actual or p_expected is null and p_actual is null then 44 | g_passed_count := g_passed_count + 1; 45 | else 46 | g_failed_count := g_failed_count + 1; 47 | dbms_output.put_line('Failure with: '||p_test); 48 | dbms_output.put_line('Expected: '||p_expected); 49 | dbms_output.put_line('Actual : '||p_actual); 50 | end if; 51 | end assert_equals; 52 | 53 | 54 | --Test Suites 55 | -------------------------------------------------------------------------------- 56 | procedure test_code is 57 | v_bad_hints misplaced_hints_code_table; 58 | begin 59 | --Empty. 60 | v_bad_hints := misplaced_hints.get_misplaced_hints_in_code(null); 61 | assert_equals('Empty 1', 0, v_bad_hints.count); 62 | 63 | v_bad_hints := misplaced_hints.get_misplaced_hints_in_code('select * from dual'); 64 | assert_equals('Empty 2', 0, v_bad_hints.count); 65 | 66 | --SELECT, one line. 67 | v_bad_hints := misplaced_hints.get_misplaced_hints_in_code('select * /*+ parallel*/ from dual'); 68 | assert_equals('SQL hint 1, count', 1, v_bad_hints.count); 69 | assert_equals('SQL hint 1, line number', 1, v_bad_hints(1).line_number); 70 | assert_equals('SQL hint 1, column number', 10, v_bad_hints(1).column_number); 71 | assert_equals('SQL hint 1, lin etext', 'select * /*+ parallel*/ from dual', v_bad_hints(1).line_text); 72 | 73 | --INSERT, multiple lines. 74 | v_bad_hints := misplaced_hints.get_misplaced_hints_in_code('insert into '||chr(10)||'/*+ parallel*/'||chr(10)||'some_table ...'); 75 | assert_equals('SQL hint 2, count', 1, v_bad_hints.count); 76 | assert_equals('SQL hint 2, line number', 2, v_bad_hints(1).line_number); 77 | assert_equals('SQL hint 2, column number', 1, v_bad_hints(1).column_number); 78 | assert_equals('SQL hint 2, lin etext', '/*+ parallel*/', v_bad_hints(1).line_text); 79 | 80 | --MERGE, "--+" syntax. 81 | v_bad_hints := misplaced_hints.get_misplaced_hints_in_code('merge into --+parallel'||chr(10)||'some_table...'); 82 | assert_equals('SQL hint 3, count', 1, v_bad_hints.count); 83 | assert_equals('SQL hint 3, line number', 1, v_bad_hints(1).line_number); 84 | assert_equals('SQL hint 3, column number', 12, v_bad_hints(1).column_number); 85 | assert_equals('SQL hint 3, lin etext', 'merge into --+parallel', v_bad_hints(1).line_text); 86 | 87 | --Multiple hints, works in PL/SQL. 88 | v_bad_hints := misplaced_hints.get_misplaced_hints_in_code('begin '||chr(10)||'delete from /*+a*/ test1; delete from '||chr(10)||'/*+b*/'||chr(10)||'test2; end;'); 89 | assert_equals('SQL hint 4, count', 2, v_bad_hints.count); 90 | assert_equals('SQL hint 4, line number 1', 2, v_bad_hints(1).line_number); 91 | assert_equals('SQL hint 4, column number 1', 13, v_bad_hints(1).column_number); 92 | assert_equals('SQL hint 4, lin etext 1', 'delete from /*+a*/ test1; delete from ', v_bad_hints(1).line_text); 93 | 94 | assert_equals('SQL hint 4, line number 2', 3, v_bad_hints(2).line_number); 95 | assert_equals('SQL hint 4, column number 2', 1, v_bad_hints(2).column_number); 96 | assert_equals('SQL hint 4, lin etext 2', '/*+b*/', v_bad_hints(2).line_text); 97 | 98 | --Ignore SELECT with correct hint. 99 | v_bad_hints := misplaced_hints.get_misplaced_hints_in_code('select /*+ parallel */ * from dual'); 100 | assert_equals('SQL hint 5, count', 0, v_bad_hints.count); 101 | 102 | --Ignore INSERT with correct hint. 103 | v_bad_hints := misplaced_hints.get_misplaced_hints_in_code('insert --+ parallel ...'); 104 | assert_equals('SQL hint 6, count', 0, v_bad_hints.count); 105 | 106 | --Ignore UPDATE with correct hint. 107 | v_bad_hints := misplaced_hints.get_misplaced_hints_in_code('update /*+ full(t) */ ...'); 108 | assert_equals('SQL hint 7, count', 0, v_bad_hints.count); 109 | 110 | --Ignore DELETE with correct hint. 111 | v_bad_hints := misplaced_hints.get_misplaced_hints_in_code('delete /*+ parallel */ table1'); 112 | assert_equals('SQL hint 8, count', 0, v_bad_hints.count); 113 | 114 | --Ignore MERGE with correct hint. 115 | v_bad_hints := misplaced_hints.get_misplaced_hints_in_code('merge /*+ asdf */ into ...'); 116 | assert_equals('SQL hint 9, count', 0, v_bad_hints.count); 117 | end test_code; 118 | 119 | 120 | -------------------------------------------------------------------------------- 121 | procedure test_schema is 122 | begin 123 | --TODO - how do I test for an entire schema without a huge setup and teardown? 124 | null; 125 | end test_schema; 126 | 127 | 128 | -------------------------------------------------------------------------------- 129 | procedure run(p_tests number default c_static_tests) is 130 | begin 131 | --Reset counters. 132 | g_test_count := 0; 133 | g_passed_count := 0; 134 | g_failed_count := 0; 135 | 136 | --Print header. 137 | dbms_output.put_line(null); 138 | dbms_output.put_line('----------------------------------------'); 139 | dbms_output.put_line('Misplaced Hints Test Summary'); 140 | dbms_output.put_line('----------------------------------------'); 141 | 142 | --Run the chosen tests. 143 | if bitand(p_tests, c_test_code) > 0 then test_code; end if; 144 | if bitand(p_tests, c_test_schema) > 0 then test_schema; end if; 145 | 146 | --Print summary of results. 147 | dbms_output.put_line(null); 148 | dbms_output.put_line('Total : '||g_test_count); 149 | dbms_output.put_line('Passed: '||g_passed_count); 150 | dbms_output.put_line('Failed: '||g_failed_count); 151 | 152 | --Print easy to read pass or fail message. 153 | if g_failed_count = 0 then 154 | dbms_output.put_line(unit_tests.C_PASS_MESSAGE); 155 | else 156 | dbms_output.put_line(unit_tests.C_FAIL_MESSAGE); 157 | end if; 158 | end run; 159 | 160 | end; 161 | / 162 | -------------------------------------------------------------------------------- /tests/unit_tests.bdy: -------------------------------------------------------------------------------- 1 | create or replace package body unit_tests is 2 | --Copyright (C) 2015 Jon Heller. This program is licensed under the LGPLv3. 3 | 4 | -------------------------------------------------------------------------------- 5 | --Run all dynamic tests. 6 | --This should be fairly quick and does about 95% of the testing. 7 | procedure run_static_tests is 8 | begin 9 | misplaced_hints_test.run(p_tests => misplaced_hints_test.c_static_tests); 10 | statement_classifier_test.run(p_tests => statement_classifier_test.c_static_tests); 11 | statement_feedback_test.run(p_tests => statement_feedback_test.c_static_tests); 12 | statement_splitter_test.run(p_tests => statement_splitter_test.c_static_tests); 13 | statement_terminator_test.run(p_tests => statement_terminator_test.c_static_tests); 14 | plsql_lexer_test.run(p_tests => plsql_lexer_test.c_static_tests); 15 | end; 16 | 17 | -------------------------------------------------------------------------------- 18 | --Run all dynamic tests. 19 | --This may take a long time and provides only a little extra value. 20 | procedure run_dynamic_tests is 21 | begin 22 | statement_classifier_test.run(p_tests => statement_classifier_test.c_dynamic_tests); 23 | --Statement feedback does not have any dynamic tests. 24 | --statement_feedback_test.run(p_tests => statement_feedback_test.c_dynamic_tests); 25 | statement_splitter_test.run(p_tests => statement_splitter_test.c_dynamic_tests); 26 | statement_terminator_test.run(p_tests => statement_terminator_test.c_dynamic_tests); 27 | plsql_lexer_test.run(p_tests => plsql_lexer_test.c_dynamic_tests); 28 | end; 29 | 30 | -------------------------------------------------------------------------------- 31 | --Run all tests for all packages. This may take a long time. 32 | procedure run_all_tests is 33 | begin 34 | run_static_tests; 35 | run_dynamic_tests; 36 | end; 37 | 38 | end; 39 | / 40 | -------------------------------------------------------------------------------- /tests/unit_tests.spc: -------------------------------------------------------------------------------- 1 | create or replace package unit_tests is 2 | --Copyright (C) 2015 Jon Heller. This program is licensed under the LGPLv3. 3 | 4 | /* 5 | == Purpose == 6 | 7 | Store constants used by multiple packages for PLSQL_LEXER unit tests, and 8 | procedures that call multiple tests at once. 9 | */ 10 | 11 | C_PASS_MESSAGE varchar2(200) := ' 12 | _____ _____ _____ 13 | | __ \ /\ / ____/ ____| 14 | | |__) / \ | (___| (___ 15 | | ___/ /\ \ \___ \\___ \ 16 | | | / ____ \ ____) |___) | 17 | |_| /_/ \_\_____/_____/'; 18 | 19 | C_FAIL_MESSAGE varchar2(200) := ' 20 | ______ _____ _ 21 | | ____/\ |_ _| | 22 | | |__ / \ | | | | 23 | | __/ /\ \ | | | | 24 | | | / ____ \ _| |_| |____ 25 | |_|/_/ \_\_____|______|'; 26 | 27 | procedure run_static_tests; 28 | procedure run_dynamic_tests; 29 | procedure run_all_tests; 30 | 31 | end; 32 | / 33 | -------------------------------------------------------------------------------- /types.sql: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------- 2 | -- Used by PLSQL_LEXER 3 | -------------------------------------------------------------------------------- 4 | create or replace type clob_table is table of clob; 5 | / 6 | create or replace type varchar2_table is table of varchar2(1 char); 7 | / 8 | create or replace type token is object 9 | ( 10 | type varchar2(4000), --String to represent token type. See the constants in PLSQL_LEXER. 11 | value clob, --The text of the token. 12 | line_number number, --The line number the token starts at - useful for printing warning and error information. 13 | column_number number, --The column number the token starts at - useful for printing warning and error information. 14 | first_char_position number, --First character position of token in the whole string - useful for inserting before a token. 15 | last_char_position number, --Last character position of token in the whole string - useful for inserting after a token. 16 | sqlcode number, --Error code of serious parsing problem. 17 | sqlerrm varchar2(4000) --Error message of serious parsing problem. 18 | ); 19 | / 20 | --Use VARRAY because it is guaranteed to maintain order. 21 | create or replace type token_table is varray(2147483647) of token; 22 | / 23 | --Use TABLE here to avoid an ORA-7445 error. 24 | --TODO: Can I use a varray of a smaller size to avoid the error? 25 | create or replace type token_table_table is table of token_table; 26 | / 27 | 28 | 29 | -------------------------------------------------------------------------------- 30 | -- Used by PLSQL_PARSER (EXPERIMENTAL - DO NOT DEPEND ON THESE YET!) 31 | -------------------------------------------------------------------------------- 32 | --create or replace type number_table is table of number 33 | --/ 34 | --create or replace type node is object 35 | --( 36 | -- id number, --Unique identifier for the node. 37 | -- type varchar2(4000), --String to represent the node type. See the constants in PLSQL_PARSER. 38 | -- parent_id number, --Unique identifier of the node's parent. 39 | -- lexer_token token, --Token information. 40 | -- child_ids number_table --Unique identifiers of node's children. 41 | --); 42 | --/ 43 | --create or replace type node_table is table of node 44 | --/ 45 | 46 | 47 | -------------------------------------------------------------------------------- 48 | -- Used by MISPLACED_HINTS 49 | -------------------------------------------------------------------------------- 50 | create or replace type misplaced_hints_code_type is object 51 | ( 52 | line_number number, 53 | column_number number, 54 | line_text varchar2(4000) 55 | ); 56 | / 57 | create or replace type misplaced_hints_code_table is table of misplaced_hints_code_type; 58 | / 59 | create or replace type misplaced_hints_schema_type is object 60 | ( 61 | object_name varchar2(128), 62 | object_type varchar2(23), 63 | line_number number, 64 | column_number number, 65 | line_text varchar2(4000) 66 | ); 67 | / 68 | create or replace type misplaced_hints_schema_table is table of misplaced_hints_schema_type; 69 | / 70 | -------------------------------------------------------------------------------- /uninstall.sql: -------------------------------------------------------------------------------- 1 | --Purpose: Uninstall PLSQL_LEXER. 2 | --How to run: 3 | -- alter session set current_schema=&schema_name; 4 | -- @uninstall 5 | 6 | --#1: Stop the script at first error, make the uninstall less noisy. 7 | whenever sqlerror exit failure 8 | whenever oserror exit failure 9 | set feedback off 10 | 11 | 12 | --#2: Uninstallation banner 13 | prompt 14 | prompt ============================== 15 | prompt = PLSQL_LEXER Uninstallation = 16 | prompt ============================== 17 | prompt 18 | 19 | 20 | --#3: Drop objects. 21 | prompt Dropping types and packages... 22 | --Drop types without displaying errors if they do not exist. 23 | declare 24 | v_object_does_not_exist exception; 25 | pragma exception_init(v_object_does_not_exist, -04043); 26 | 27 | procedure drop_object_ignore_dne_error(p_drop_sql in varchar2) is 28 | begin 29 | execute immediate p_drop_sql; 30 | exception 31 | when v_object_does_not_exist then null; 32 | when others then 33 | raise_application_error(-20000, 'Error with this drop statement: '||p_drop_sql||chr(10)|| 34 | sqlerrm||chr(10)||dbms_utility.format_call_stack); 35 | end drop_object_ignore_dne_error; 36 | begin 37 | --Drop types, in reverse order so dependent objects are dropped first. 38 | drop_object_ignore_dne_error('drop type misplaced_hints_schema_table'); 39 | drop_object_ignore_dne_error('drop type misplaced_hints_schema_type'); 40 | drop_object_ignore_dne_error('drop type misplaced_hints_code_table'); 41 | drop_object_ignore_dne_error('drop type misplaced_hints_code_type'); 42 | 43 | --Parser objects not ready yet: 44 | -- drop_object_ignore_dne_error('drop type node_table'); 45 | -- drop_object_ignore_dne_error('drop type node'); 46 | -- drop_object_ignore_dne_error('drop type number_table'); 47 | 48 | drop_object_ignore_dne_error('drop type clob_table'); 49 | drop_object_ignore_dne_error('drop type varchar2_table'); 50 | drop_object_ignore_dne_error('drop type token_table_table'); 51 | drop_object_ignore_dne_error('drop type token_table'); 52 | drop_object_ignore_dne_error('drop type token'); 53 | 54 | --Drop regular packages. 55 | --Parser objects not ready yet: 56 | -- drop_object_ignore_dne_error('drop package plsql_parser'); 57 | -- drop_object_ignore_dne_error('drop package syntax_tree'); 58 | drop_object_ignore_dne_error('drop package plsql_lexer'); 59 | drop_object_ignore_dne_error('drop package statement_classifier'); 60 | drop_object_ignore_dne_error('drop package statement_splitter'); 61 | drop_object_ignore_dne_error('drop package statement_feedback'); 62 | drop_object_ignore_dne_error('drop package statement_terminator'); 63 | drop_object_ignore_dne_error('drop package misplaced_hints'); 64 | 65 | --Drop unit test packages. 66 | drop_object_ignore_dne_error('drop package plsql_lexer_test'); 67 | drop_object_ignore_dne_error('drop package statement_classifier_test'); 68 | drop_object_ignore_dne_error('drop package statement_feedback_test'); 69 | drop_object_ignore_dne_error('drop package statement_splitter_test'); 70 | drop_object_ignore_dne_error('drop package statement_terminator_test'); 71 | drop_object_ignore_dne_error('drop package plsql_lexer_test'); 72 | drop_object_ignore_dne_error('drop package misplaced_hints_test'); 73 | end; 74 | / 75 | 76 | 77 | --#4: Print success message. 78 | prompt 79 | prompt Uninstallation successful. 80 | 81 | 82 | --#5: Return SQL*Plus to normal environment. 83 | whenever sqlerror continue 84 | whenever oserror continue 85 | set feedback on 86 | --------------------------------------------------------------------------------