diff --git a/java/jdbc/SessionlessTransactions/src/main/java/com/oracle/jdbc/samples/sessionlesstxns/service/BookingService.java b/java/jdbc/SessionlessTransactions/src/main/java/com/oracle/jdbc/samples/sessionlesstxns/service/BookingService.java index be0feb0f..2fddd8e6 100644 --- a/java/jdbc/SessionlessTransactions/src/main/java/com/oracle/jdbc/samples/sessionlesstxns/service/BookingService.java +++ b/java/jdbc/SessionlessTransactions/src/main/java/com/oracle/jdbc/samples/sessionlesstxns/service/BookingService.java @@ -20,9 +20,13 @@ import com.oracle.jdbc.samples.sessionlesstxns.util.Util; import oracle.jdbc.OracleConnection; import oracle.jdbc.OraclePreparedStatement; +import oracle.jdbc.OracleTypes; import org.springframework.stereotype.Service; import javax.sql.DataSource; +import java.math.BigDecimal; +import java.sql.Array; +import java.sql.CallableStatement; import java.sql.Connection; import java.sql.PreparedStatement; import java.sql.ResultSet; @@ -30,6 +34,7 @@ import java.sql.Savepoint; import java.sql.Timestamp; import java.util.ArrayList; +import java.util.Arrays; import java.util.List; @Service @@ -175,7 +180,7 @@ private List lockAndBookSeats(OracleConnection conn, long bookingId, long private void saveReceipt(OracleConnection conn, String receiptNumber, double sum, long bookingId, long paymentMethodId) throws SQLException { final String saveReceiptDML = """ - INSERT INTO receipts (created_at, receipt_number, total, booking_id, payment_method_id) values (?, ?, ?, ?, ?); + INSERT INTO receipts (created_at, receipt_number, total, booking_id, payment_method_id) values (?, ?, ?, ?, ?) """; try (OraclePreparedStatement stmt = (OraclePreparedStatement) conn.prepareStatement(saveReceiptDML)) { @@ -243,20 +248,24 @@ private void removeTicket(OracleConnection conn, long seatId, long bookingId) * availability of the tickets in the database. */ private List getFreeSeats(OracleConnection conn, long flightId, int count) throws SQLException { - final String getFreeSeatsQuery = """ - SELECT id FROM seats - WHERE available = true AND flight_id = ? - FETCH FIRST ? ROW ONLY - FOR UPDATE SKIP LOCKED;"""; + final String procedureCall = "{call fetch_seats(?, ?, ?)}"; + List seats = null; - List seats = new ArrayList<>(); - - try(PreparedStatement stmt = conn.prepareStatement(getFreeSeatsQuery);) { + try (CallableStatement stmt = conn.prepareCall(procedureCall)) { + // Set input parameters stmt.setLong(1, flightId); stmt.setInt(2, count); - ResultSet rs = stmt.executeQuery(); - while (rs.next()) { - seats.add(rs.getLong(1)); + // Register the OUT parameter (Oracle NUMBER_TABLE) + stmt.registerOutParameter(3, OracleTypes.ARRAY, "DBMS_SQL.NUMBER_TABLE"); + // Execute the procedure + stmt.execute(); + + // Retrieve the results + Array resultArray = stmt.getArray(3); + + if (resultArray != null) { + seats = Arrays.stream((BigDecimal[]) resultArray.getArray()).map(BigDecimal::longValue).toList(); + resultArray.free(); } } diff --git a/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestApis.java b/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestApis.java index 527cceaf..9e5f36b6 100644 --- a/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestApis.java +++ b/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestApis.java @@ -144,10 +144,10 @@ void thirdScenario() { } private void loadData() { - runSQLScript("dataLoader.sql"); + runSQLScript("dataLoader.sql", ";"); } private void cleanTables() { - runSQLScript("dataCleaner.sql"); + runSQLScript("dataCleaner.sql", ";"); } } diff --git a/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestBase.java b/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestBase.java index 308c9a9b..8eba61b1 100644 --- a/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestBase.java +++ b/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestBase.java @@ -25,6 +25,10 @@ import org.springframework.test.context.ActiveProfiles; import java.io.InputStream; +import java.sql.Connection; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; import java.util.List; import java.util.Scanner; @@ -54,10 +58,10 @@ void tearDown() { dropSchema(); } - public void runSQLScript(String fileName) { + public void runSQLScript(String fileName, String delimiter) { InputStream inputStream = TestBase.class.getClassLoader().getResourceAsStream(fileName); - List instructions = new Scanner(inputStream).useDelimiter(";").tokens().toList(); - jdbcTemplate.batchUpdate(instructions.toArray(new String[0])); + List instructions = new Scanner(inputStream).useDelimiter(delimiter).tokens().toList(); + jdbcTemplate.batchUpdate(instructions.toArray(new String[0])); } public static StartTransactionResponse testAPIStartTransaction(int timeout, long flightId, int count, HttpStatus expectedStatus) { @@ -149,10 +153,10 @@ public void testAPICancelBooking(String transactionId, HttpStatus expectedStatus } private void createSchema() { - runSQLScript("createSchema.sql"); + runSQLScript("createSchema.sql", ";/"); } private void dropSchema() { - runSQLScript("dropSchema.sql"); + runSQLScript("dropSchema.sql", ";"); } } diff --git a/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestConcurrency.java b/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestConcurrency.java index 65851144..6dbc112d 100644 --- a/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestConcurrency.java +++ b/java/jdbc/SessionlessTransactions/src/test/java/com/oracle/jdbc/samples/sessionlesstxns/TestConcurrency.java @@ -16,8 +16,12 @@ import org.springframework.context.annotation.Primary; import org.springframework.http.HttpStatus; +import java.util.ArrayList; +import java.util.List; +import java.util.concurrent.ExecutionException; import java.util.concurrent.ExecutorService; import java.util.concurrent.Executors; +import java.util.concurrent.Future; public class TestConcurrency extends TestBase { @@ -62,10 +66,20 @@ void testNormalScenario() { final int numberOfExecutions = 50; try (ExecutorService exService = Executors.newFixedThreadPool(numberOfExecutions)) { - for (int i=0; i> futures = new ArrayList<>(); + for (int i = 0; i < numberOfExecutions; i++) { + futures.add(exService.submit(test)); + } + // Wait for all tasks to complete + for (Future future : futures) { + try { + future.get(); // This blocks until the task completes + } catch (InterruptedException | ExecutionException e) { + logger.error("Task execution failed", e); + } } } + logger.info("Execution time: {} s", (System.currentTimeMillis() - start) / 1_000); } @@ -79,7 +93,7 @@ void testScenario() throws InterruptedException { Assertions.assertEquals(REQUESTED_SEATS1, startTransaction.seatIds().size()); Thread.sleep(1000); - final int REQUESTED_SEATS2 = 2; + final int REQUESTED_SEATS2 = 1; var requestTickets = testAPIRequestTickets( startTransaction.transactionId(), FLIGHT1_ID, REQUESTED_SEATS2, startTransaction.bookingId(), HttpStatus.CREATED); @@ -102,10 +116,10 @@ void testScenario() throws InterruptedException { } private void loadData() { - runSQLScript("hundredsSeats.sql"); + runSQLScript("hundredsSeats.sql", ";"); } private void cleanTables() { - runSQLScript("dataCleaner.sql"); + runSQLScript("dataCleaner.sql", ";"); } } diff --git a/java/jdbc/SessionlessTransactions/src/test/resources/application.properties b/java/jdbc/SessionlessTransactions/src/test/resources/application.properties index 4ca5ec01..b0960c3f 100644 --- a/java/jdbc/SessionlessTransactions/src/test/resources/application.properties +++ b/java/jdbc/SessionlessTransactions/src/test/resources/application.properties @@ -14,4 +14,5 @@ spring.datasource.oracleucp.sql-for-validate-connection=select * from dual spring.datasource.oracleucp.connection-pool-name=connectionPool-${random.uuid} spring.datasource.oracleucp.initial-pool-size=5 spring.datasource.oracleucp.min-pool-size=1 -spring.datasource.oracleucp.max-pool-size=10 \ No newline at end of file +spring.datasource.oracleucp.max-pool-size=10 +spring.datasource.oracleucp.connection-wait-timeout=120 \ No newline at end of file diff --git a/java/jdbc/SessionlessTransactions/src/test/resources/createSchema.sql b/java/jdbc/SessionlessTransactions/src/test/resources/createSchema.sql index 47ea77a8..09b2614f 100644 --- a/java/jdbc/SessionlessTransactions/src/test/resources/createSchema.sql +++ b/java/jdbc/SessionlessTransactions/src/test/resources/createSchema.sql @@ -7,7 +7,7 @@ CREATE TABLE bookings ( id NUMBER GENERATED ALWAYS AS IDENTITY, created_at DATE, CONSTRAINT BOOKING_PK PRIMARY KEY (id) -); +);/ CREATE TABLE flights ( id NUMBER, @@ -17,7 +17,7 @@ CREATE TABLE flights ( departure TIMESTAMP, price NUMBER, CONSTRAINT FLIGHT_PK PRIMARY KEY (id) -); +);/ CREATE TABLE seats ( id NUMBER, @@ -25,7 +25,7 @@ CREATE TABLE seats ( available BOOLEAN NOT NULL, CONSTRAINT SEAT_PK PRIMARY KEY (id), CONSTRAINT SEAT_FLIGHT_FK FOREIGN KEY (flight_id) REFERENCES flights(id) -); +);/ CREATE TABLE tickets ( id NUMBER GENERATED ALWAYS AS IDENTITY, @@ -34,12 +34,12 @@ CREATE TABLE tickets ( CONSTRAINT TICKET_PK PRIMARY KEY (id), CONSTRAINT TICKET_SEATS_FK FOREIGN KEY (seat_id) REFERENCES seats(id), CONSTRAINT TICKET_BOOKINGS_FK FOREIGN KEY (booking_id) REFERENCES bookings(id) -); +);/ CREATE TABLE payment_methods ( id NUMBER, CONSTRAINT PAYMENT_METHOD_PK PRIMARY KEY (id) -); +);/ CREATE TABLE receipts ( id NUMBER GENERATED ALWAYS AS IDENTITY, @@ -51,4 +51,19 @@ CREATE TABLE receipts ( CONSTRAINT RECEIPT_PK PRIMARY KEY (id), CONSTRAINT RECEIPT_BOOKING_FK FOREIGN KEY (booking_id) REFERENCES bookings(id), CONSTRAINT RECEIPT_PAYMENT_M_FK FOREIGN KEY (payment_method_id) REFERENCES payment_methods(id) -); \ No newline at end of file +);/ + +CREATE OR REPLACE PROCEDURE fetch_seats( + f_id IN NUMBER, + n_rows IN INT, + t_data OUT DBMS_SQL.NUMBER_TABLE +) AS + CURSOR c IS + SELECT id FROM seats + WHERE available = true AND flight_id = f_id + FOR UPDATE SKIP LOCKED; +BEGIN + OPEN c; + FETCH c BULK COLLECT INTO t_data LIMIT n_rows; + CLOSE c; +END fetch_seats; \ No newline at end of file diff --git a/java/jdbc/SessionlessTransactions/src/test/resources/createUser.sql b/java/jdbc/SessionlessTransactions/src/test/resources/createUser.sql index dd442b15..a2d774cf 100644 --- a/java/jdbc/SessionlessTransactions/src/test/resources/createUser.sql +++ b/java/jdbc/SessionlessTransactions/src/test/resources/createUser.sql @@ -8,4 +8,5 @@ GRANT CREATE SESSION TO test_user; GRANT CREATE TABLE TO test_user; GRANT CREATE SEQUENCE TO test_user; GRANT DROP ANY TABLE TO test_user; +GRANT CREATE PROCEDURE to test_user; GRANT UNLIMITED TABLESPACE TO test_user; \ No newline at end of file diff --git a/java/jdbc/SessionlessTransactions/src/test/resources/dropSchema.sql b/java/jdbc/SessionlessTransactions/src/test/resources/dropSchema.sql index 8a4849ea..dc0d21e5 100644 --- a/java/jdbc/SessionlessTransactions/src/test/resources/dropSchema.sql +++ b/java/jdbc/SessionlessTransactions/src/test/resources/dropSchema.sql @@ -3,6 +3,7 @@ * Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl/ */ +DROP PROCEDURE fetch_seats; DROP TABLE receipts; DROP TABLE payment_methods; DROP TABLE tickets;