Skip to content

Commit

Permalink
SqlScriptLexer/SqlScriptParser: Enhance to properly deal with BEGIN..…
Browse files Browse the repository at this point in the history
….END blocks in sql scripts

Add JUnit test testOracleScriptWithBeginEndBlock

Add test script received by bug reporter (amended)

Clarify JavaDoc

Fixes jdbi#2021

Incorporate pr feedback by Steven Schlansker
  • Loading branch information
spannm committed Jun 28, 2022
1 parent 653bc61 commit c777949
Show file tree
Hide file tree
Showing 5 changed files with 130 additions and 19 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,8 @@

lexer grammar SqlScriptLexer;

options { caseInsensitive = true; }

COMMENT
: '--' ~('\r' | '\n')* |
'//' ~('\r' | '\n')* |
Expand All @@ -33,10 +35,22 @@ fragment NEWLINE
: ('\r' | '\n')
;

fragment WHITESPACE
: (' ' | '\t' | NEWLINE)
;

QUOTED_TEXT
: ('\'' (ESCAPE_SEQUENCE | ~'\'')* '\'')
;

BLOCK_BEGIN
: 'BEGIN' WHITESPACE+
;

BLOCK_END
: 'END' WHITESPACE+
;

fragment ESCAPE_SEQUENCE
: '\\' '\''
;
Expand All @@ -46,7 +60,7 @@ SEMICOLON
;

LITERAL
: ('a'..'z'|'A'..'Z'|' '|'\t'|'0'..'9'|
: ('A'..'Z'|' '|'\t'|'0'..'9'|
','|'*'|'.'|'@'|'_'|'!'|'='|'('|')'|'['|']')+
;

Expand Down
39 changes: 30 additions & 9 deletions core/src/main/java/org/jdbi/v3/core/internal/SqlScriptParser.java
Original file line number Diff line number Diff line change
Expand Up @@ -18,6 +18,16 @@
import org.jdbi.v3.core.internal.lexer.SqlScriptLexer;
import org.jdbi.v3.core.statement.internal.ErrorListener;

import static org.jdbi.v3.core.internal.lexer.SqlScriptLexer.BLOCK_BEGIN;
import static org.jdbi.v3.core.internal.lexer.SqlScriptLexer.BLOCK_END;
import static org.jdbi.v3.core.internal.lexer.SqlScriptLexer.COMMENT;
import static org.jdbi.v3.core.internal.lexer.SqlScriptLexer.LITERAL;
import static org.jdbi.v3.core.internal.lexer.SqlScriptLexer.MULTI_LINE_COMMENT;
import static org.jdbi.v3.core.internal.lexer.SqlScriptLexer.NEWLINES;
import static org.jdbi.v3.core.internal.lexer.SqlScriptLexer.OTHER;
import static org.jdbi.v3.core.internal.lexer.SqlScriptLexer.QUOTED_TEXT;
import static org.jdbi.v3.core.internal.lexer.SqlScriptLexer.SEMICOLON;

/**
* An SQL script parser.
*
Expand All @@ -37,26 +47,37 @@ public String parse(CharStream charStream) {
SqlScriptLexer lexer = new SqlScriptLexer(charStream);
lexer.addErrorListener(new ErrorListener());
boolean endOfFile = false;
int blockLevel = 0;
while (!endOfFile) {
Token t = lexer.nextToken();
switch (t.getType()) {
case Token.EOF:
endOfFile = true;
break;
case SqlScriptLexer.SEMICOLON:
semicolonHandler.handle(t, sb);
case SEMICOLON:
if (blockLevel == 0) {
semicolonHandler.handle(t, sb);
} else {
// preserve semicolons within begin/end block
sb.append(t.getText());
}
break;
case BLOCK_BEGIN:
case BLOCK_END:
blockLevel += BLOCK_BEGIN == t.getType() ? +1 : -1;
sb.append(t.getText());
break;
case SqlScriptLexer.COMMENT:
case SqlScriptLexer.MULTI_LINE_COMMENT:
case COMMENT:
case MULTI_LINE_COMMENT:
break;
case SqlScriptLexer.NEWLINES:
case NEWLINES:
if (sb.length() > 0) {
sb.append(' ');
sb.append('\n');
}
break;
case SqlScriptLexer.QUOTED_TEXT:
case SqlScriptLexer.LITERAL:
case SqlScriptLexer.OTHER:
case QUOTED_TEXT:
case LITERAL:
case OTHER:
sb.append(t.getText());
break;
default:
Expand Down
2 changes: 1 addition & 1 deletion core/src/main/java/org/jdbi/v3/core/statement/Script.java
Original file line number Diff line number Diff line change
Expand Up @@ -21,7 +21,7 @@
import org.jdbi.v3.core.internal.SqlScriptParser;

/**
* Represents a number of SQL statements which will be executed in a batch statement.
* Represents a number of SQL statements delimited by semicolon which will be executed in order in a batch statement.
*/
public class Script extends SqlStatement<Script> {
private final Handle handle;
Expand Down
52 changes: 44 additions & 8 deletions core/src/test/java/org/jdbi/v3/core/statement/TestScript.java
Original file line number Diff line number Diff line change
Expand Up @@ -13,23 +13,25 @@
*/
package org.jdbi.v3.core.statement;

import java.sql.SQLException;
import java.util.List;
import java.util.Map;

import com.google.common.collect.ImmutableList;
import com.google.common.collect.ImmutableMap;
import de.softwareforge.testing.postgres.junit5.EmbeddedPgExtension;
import de.softwareforge.testing.postgres.junit5.MultiDatabaseBuilder;
import org.assertj.core.api.Condition;
import org.jdbi.v3.core.Handle;
import org.jdbi.v3.core.HandleAccess;
import org.jdbi.v3.core.junit5.H2DatabaseExtension;
import org.jdbi.v3.core.junit5.PgDatabaseExtension;
import org.jdbi.v3.core.locator.ClasspathSqlLocator;
import org.junit.jupiter.api.Test;
import org.junit.jupiter.api.extension.RegisterExtension;

import static org.assertj.core.api.Assertions.assertThat;
import static org.assertj.core.api.Assertions.assertThatExceptionOfType;
import static org.jdbi.v3.core.locator.ClasspathSqlLocator.findSqlOnClasspath;
import static org.jdbi.v3.core.locator.ClasspathSqlLocator.getResourceOnClasspath;

public class TestScript {

Expand All @@ -45,7 +47,7 @@ public class TestScript {
@Test
public void testScriptStuff() {
Handle h = h2Extension.openHandle();
Script s = h.createScript(findSqlOnClasspath("default-data"));
Script s = h.createScript(getClasspathSqlLocator().locate("default-data"));
s.execute();

assertThat(h.select("select * from something").mapToMap()).hasSize(2);
Expand All @@ -54,7 +56,7 @@ public void testScriptStuff() {
@Test
public void testScriptWithComments() {
Handle h = h2Extension.openHandle();
Script script = h.createScript(getResourceOnClasspath("script/insert-script-with-comments.sql"));
Script script = h.createScript(getClasspathSqlLocator().getResource("script/insert-script-with-comments.sql"));
script.execute();

assertThat(h.select("select * from something").mapToMap()).hasSize(3);
Expand All @@ -63,7 +65,7 @@ public void testScriptWithComments() {
@Test
public void testScriptWithStringSemicolon() {
Handle h = h2Extension.openHandle();
Script script = h.createScript(getResourceOnClasspath("script/insert-with-string-semicolons.sql"));
Script script = h.createScript(getClasspathSqlLocator().getResource("script/insert-with-string-semicolons.sql"));
script.execute();

assertThat(h.select("select * from something").mapToMap()).hasSize(3);
Expand All @@ -72,7 +74,7 @@ public void testScriptWithStringSemicolon() {
@Test
public void testFuzzyScript() {
Handle h = h2Extension.openHandle();
Script script = h.createScript(getResourceOnClasspath("script/fuzzy-script.sql"));
Script script = h.createScript(getClasspathSqlLocator().getResource("script/fuzzy-script.sql"));
script.executeAsSeparateStatements();

List<Map<String, Object>> rows = h.select("select id, name from something order by id").mapToMap().list();
Expand All @@ -88,7 +90,7 @@ public void testScriptAsSetOfSeparateStatements() {
assertThatExceptionOfType(StatementException.class)
.isThrownBy(() -> {
Handle h = h2Extension.openHandle();
Script script = h.createScript(getResourceOnClasspath("script/malformed-sql-script.sql"));
Script script = h.createScript(getClasspathSqlLocator().getResource("script/malformed-sql-script.sql"));
script.executeAsSeparateStatements();
})
.satisfies(e -> assertThat(e.getStatementContext().getRawSql().trim())
Expand All @@ -98,9 +100,43 @@ public void testScriptAsSetOfSeparateStatements() {
@Test
public void testPostgresJsonExtractTextOperator() {
Handle h = pgExtension.openHandle();
Script script = h.createScript(getResourceOnClasspath("script/postgres-json-operator.sql"));
Script script = h.createScript(getClasspathSqlLocator().getResource("script/postgres-json-operator.sql"));
script.execute();

assertThat(h.select("select * from something").mapToMap()).hasSize(1);
}

/**
* <p>
* Test for correct handling of semicolons in sql containing begin/end blocks.
* </p>
* <p>
* Class {@link Script} splits sql scripts into lists of statements by semicolon ({@code ;}) and then batch-executes them.<br>
* Statements may contain {@code BEGIN...END} blocks containing subordinated statements (also ending in semicolons).<br>
* Only semicolons on the highest level (i.e. outside any block) actually signal the end of an sql statement.
* </p>
* @author Markus Spann
* @throws SQLException on failure to create the database handle
*/
@Test
public void testOracleScriptWithBeginEndBlock() throws SQLException {
String sql = getClasspathSqlLocator().getResource("script/oracle-with-begin-end-blocks.sql");
try (Script script = new Script(HandleAccess.createHandle(), sql)) {

List<String> statements = script.getStatements();

assertThat(statements).hasSize(3);

String lastStmt = statements.get(2);
assertThat(lastStmt).startsWith("CREATE OR REPLACE TRIGGER EXAMPLE_TRIGGER");
assertThat(lastStmt).endsWith("END;");
assertThat(lastStmt).hasLineCount(15);
assertThat(lastStmt).has(new Condition<>(s -> 7 == s.chars().filter(ch -> ch == ';').count(), "count semicolons"));

}
}

private ClasspathSqlLocator getClasspathSqlLocator() {
return ClasspathSqlLocator.removingComments();
}
}
40 changes: 40 additions & 0 deletions core/src/test/resources/script/oracle-with-begin-end-blocks.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,40 @@
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
--

CREATE TABLE EXAMPLE
(
ID NUMBER PRIMARY KEY,
USERNAME VARCHAR2(128) NOT NULL,
CREATED_AT TIMESTAMP WITH TIME ZONE NOT NULL
);

CREATE SEQUENCE EXAMPLE_ID_SEQUENCE
START WITH 1
INCREMENT BY 1;

CREATE OR REPLACE TRIGGER EXAMPLE_TRIGGER
BEFORE INSERT
ON EXAMPLE
FOR EACH ROW
BEGIN
SELECT sys_context('USERENV', 'SESSION_USER') INTO :new.USERNAME FROM DUAL; -- JDBI STOPS HERE!
IF :new.USERNAME = 'something' THEN
raise_application_error(-20000, 'Some error');
END IF;
BEGIN -- a comment that includes BEGIN
SELECT EXAMPLE_ID_SEQUENCE.nextval INTO :new.ID FROM DUAL;
SELECT CURRENT_TIMESTAMP INTO :new.CREATED_AT FROM DUAL;
SELECT CURRENT_TIMESTAMP INTO :new.UPDATED_AT FROM DUAL;
END -- another comment that includes END and end in lower-case as well ;)
END;

0 comments on commit c777949

Please sign in to comment.