|
| 1 | +## Overview |
| 2 | + |
| 3 | +This project demonstrates the use of the latest sharding [feature](https://github.com/spring-projects/spring-framework/pull/31506) in Spring Framework with the Oracle Database. |
| 4 | +The feature is about supporting direct routing to sharded databases. |
| 5 | + |
| 6 | +This version uses Spring Data JDBC (JdbcTemplate), for data access. |
| 7 | + |
| 8 | +You can use the datasource configurations provided in this project as a template for setting up the sharding feature in your own projects. |
| 9 | + |
| 10 | +## Configuration |
| 11 | + |
| 12 | +### Database |
| 13 | + |
| 14 | +You can refer to the [Oracle Docs](https://docs.oracle.com/en/database/oracle/oracle-database/21/shard/sharding-deployment.html#GUID-F99B8742-4089-4E77-87D4-4691EA932207) |
| 15 | +to learn how to set up and deploy an Oracle sharded database. |
| 16 | +You can also refer to [Oracle Database Operator](https://github.com/oracle/oracle-database-operator) that makes deploying a sharded database on a Kubernetes Cluster an easy process. |
| 17 | + |
| 18 | +After your sharded database is set, connect to the shard catalog as sysdba and create the demo application schema user. |
| 19 | + |
| 20 | +~~~SQL |
| 21 | +ALTER SESSION ENABLE SHARD DDL; |
| 22 | + |
| 23 | +-- Create demo schema user |
| 24 | +CREATE USER demo_user IDENTIFIED BY demo_user; |
| 25 | +GRANT CONNECT, RESOURCE TO demo_user; |
| 26 | +GRANT CREATE TABLE TO demo_user; |
| 27 | +GRANT UNLIMITED TABLESPACE TO demo_user; |
| 28 | + |
| 29 | +-- Create tablespace |
| 30 | +CREATE TABLESPACE SET TS1 USING TEMPLATE ( |
| 31 | + DATAFILE SIZE 10M AUTOEXTEND ON NEXT 10M MAXSIZE UNLIMITED |
| 32 | + EXTENT MANAGEMENT LOCAL SEGMENT SPACE MANAGEMENT AUTO); |
| 33 | +~~~ |
| 34 | + |
| 35 | +On the shard catalog connect as demo_user and run the following SQL script to create your tables. |
| 36 | + |
| 37 | +~~~SQL |
| 38 | +ALTER SESSION ENABLE SHARD DDL; |
| 39 | + |
| 40 | +CREATE SHARDED TABLE users ( |
| 41 | + user_id NUMBER PRIMARY KEY, |
| 42 | + name VARCHAR2(100), |
| 43 | + password VARCHAR2(255), |
| 44 | + role VARCHAR2(5), |
| 45 | +CONSTRAINT roleCheck CHECK (role IN ('USER', 'ADMIN'))) |
| 46 | +TABLESPACE SET TS1 PARTITION BY CONSISTENT HASH (user_id); |
| 47 | + |
| 48 | +CREATE SHARDED TABLE notes ( |
| 49 | + note_id NUMBER NOT NULL, |
| 50 | + user_id NUMBER NOT NULL, |
| 51 | + title VARCHAR2(255), |
| 52 | + content CLOB, |
| 53 | +CONSTRAINT notePK PRIMARY KEY (note_id, user_id), |
| 54 | +CONSTRAINT userFK FOREIGN KEY (user_id) REFERENCES users(user_id)) |
| 55 | +PARTITION BY REFERENCE (UserFK); |
| 56 | + |
| 57 | +CREATE SEQUENCE note_sequence INCREMENT BY 1 START WITH 1 MAXVALUE 2E9 SHARD; |
| 58 | +~~~ |
| 59 | + |
| 60 | +Make sure to insert a user or two in the database before testing the application. |
| 61 | + |
| 62 | +~~~SQL |
| 63 | +INSERT INTO users VALUES (0, 'user1', LOWER(STANDARD_HASH('user1', 'SHA256')), 'USER'); |
| 64 | +INSERT INTO users VALUES (1, 'admin', LOWER(STANDARD_HASH('admin', 'SHA256')), 'ADMIN'); |
| 65 | +COMMIT; |
| 66 | +~~~ |
| 67 | + |
| 68 | +To uninstall and clean up the preceding setup, you can connect as sysdba and run the following SQL script. |
| 69 | + |
| 70 | +~~~SQL |
| 71 | +ALTER SESSION ENABLE SHARD DDL; |
| 72 | + |
| 73 | +DROP USER demo_user CASCADE; |
| 74 | +DROP TABLESPACE SET TS1; |
| 75 | +~~~ |
| 76 | + |
| 77 | +## Building the application |
| 78 | +To build the application run: |
| 79 | + |
| 80 | +~~~ |
| 81 | +mvn install |
| 82 | +~~~ |
| 83 | + |
| 84 | +## Running the application |
| 85 | + |
| 86 | +Before running the application set the following environment variables or update [application.properties](src/main/resources/application.properties). These configure the URL and credentials for the catalog database and shard director (GSM) used by the application. |
| 87 | + |
| 88 | +~~~shell |
| 89 | +export CATALOG_URL="the catalog url" |
| 90 | +export CATALOG_USER="demo_user" |
| 91 | +export CATALOG_PASS="demo_user" |
| 92 | +export SHARD_DIRECTOR_URL="the shard director url" |
| 93 | +export SHARD_DIRECTOR_USER="demo_user" |
| 94 | +export SHARD_DIRECTOR_PASS="demo_user" |
| 95 | +~~~ |
| 96 | + |
| 97 | +Then you can run the application using: |
| 98 | + |
| 99 | +~~~shell |
| 100 | +mvn spring-boot:run |
| 101 | +~~~ |
0 commit comments