You can not select more than 25 topics
Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
393 lines
14 KiB
393 lines
14 KiB
[[appendix-schema]] |
|
= Security Database Schema |
|
The framework uses various database schema. This appendix provides a single reference point to them all. |
|
You need only provide the tables for the areas of functionality you require. |
|
|
|
DDL statements are given for the HSQLDB database. |
|
You can use these as a guideline for defining the schema for the database you are using. |
|
|
|
|
|
== User Schema |
|
The standard JDBC implementation of the `UserDetailsService` (`JdbcDaoImpl`) requires tables to load the password, account status (enabled or disabled) and a list of authorities (roles) for the user. |
|
You can use these as a guideline for defining the schema for the database you use. |
|
|
|
[source] |
|
---- |
|
|
|
create table users( |
|
username varchar_ignorecase(50) not null primary key, |
|
password varchar_ignorecase(500) not null, |
|
enabled boolean not null |
|
); |
|
|
|
create table authorities ( |
|
username varchar_ignorecase(50) not null, |
|
authority varchar_ignorecase(50) not null, |
|
constraint fk_authorities_users foreign key(username) references users(username) |
|
); |
|
create unique index ix_auth_username on authorities (username,authority); |
|
---- |
|
|
|
=== For Oracle database |
|
|
|
The following listing shows the Oracle variant of the schema creation commands: |
|
|
|
[source] |
|
---- |
|
CREATE TABLE USERS ( |
|
USERNAME NVARCHAR2(128) PRIMARY KEY, |
|
PASSWORD NVARCHAR2(128) NOT NULL, |
|
ENABLED CHAR(1) CHECK (ENABLED IN ('Y','N') ) NOT NULL |
|
); |
|
|
|
|
|
CREATE TABLE AUTHORITIES ( |
|
USERNAME NVARCHAR2(128) NOT NULL, |
|
AUTHORITY NVARCHAR2(128) NOT NULL |
|
); |
|
ALTER TABLE AUTHORITIES ADD CONSTRAINT AUTHORITIES_UNIQUE UNIQUE (USERNAME, AUTHORITY); |
|
ALTER TABLE AUTHORITIES ADD CONSTRAINT AUTHORITIES_FK1 FOREIGN KEY (USERNAME) REFERENCES USERS (USERNAME) ENABLE; |
|
---- |
|
|
|
=== Group Authorities |
|
Spring Security 2.0 introduced support for group authorities in `JdbcDaoImpl`. |
|
The table structure if groups are enabled is as follows. |
|
You need to adjust the following schema to match the database dialect you use: |
|
|
|
[source] |
|
---- |
|
|
|
create table groups ( |
|
id bigint generated by default as identity(start with 0) primary key, |
|
group_name varchar_ignorecase(50) not null |
|
); |
|
|
|
create table group_authorities ( |
|
group_id bigint not null, |
|
authority varchar(50) not null, |
|
constraint fk_group_authorities_group foreign key(group_id) references groups(id) |
|
); |
|
|
|
create table group_members ( |
|
id bigint generated by default as identity(start with 0) primary key, |
|
username varchar(50) not null, |
|
group_id bigint not null, |
|
constraint fk_group_members_group foreign key(group_id) references groups(id) |
|
); |
|
---- |
|
|
|
Remember that these tables are required only if you us the provided JDBC `UserDetailsService` implementation. |
|
If you write your own or choose to implement `AuthenticationProvider` without a `UserDetailsService`, you have complete freedom over how you store the data, as long as the interface contract is satisfied. |
|
|
|
|
|
== Persistent Login (Remember-Me) Schema |
|
This table is used to store the data used by the more secure <<remember-me-persistent-token,persistent token>> remember-me implementation. |
|
If you use `JdbcTokenRepositoryImpl` either directly or through the namespace, you need this table. |
|
Remember to adjust this schema to match the database dialect you use: |
|
|
|
[source] |
|
---- |
|
|
|
create table persistent_logins ( |
|
username varchar(64) not null, |
|
series varchar(64) primary key, |
|
token varchar(64) not null, |
|
last_used timestamp not null |
|
); |
|
|
|
---- |
|
|
|
[[dbschema-acl]] |
|
== ACL Schema |
|
The Spring Security xref:servlet/authorization/acls.adoc#domain-acls[ACL] implementation uses four tables. |
|
|
|
* `acl_sid` stores the security identities recognised by the ACL system. |
|
These can be unique principals or authorities, which may apply to multiple principals. |
|
* `acl_class` defines the domain object types to which ACLs apply. |
|
The `class` column stores the Java class name of the object. |
|
* `acl_object_identity` stores the object identity definitions of specific domain objects. |
|
* `acl_entry` stores the ACL permissions, each of which applies to a specific object identity and security identity. |
|
|
|
We assume that the database auto-generates the primary keys for each of the identities. |
|
The `JdbcMutableAclService` has to be able to retrieve these when it has created a new row in the `acl_sid` or `acl_class` tables. |
|
It has two properties that define the SQL needed to retrieve these values `classIdentityQuery` and `sidIdentityQuery`. |
|
Both of these default to `call identity()` |
|
|
|
The ACL artifact JAR contains files for creating the ACL schema in HyperSQL (HSQLDB), PostgreSQL, MySQL/MariaDB, Microsoft SQL Server, and Oracle Database. |
|
These schemas are also demonstrated in the following sections. |
|
|
|
=== HyperSQL |
|
The default schema works with the embedded HSQLDB database that is used in unit tests within the framework. |
|
|
|
[source,ddl] |
|
---- |
|
create table acl_sid( |
|
id bigint generated by default as identity(start with 100) not null primary key, |
|
principal boolean not null, |
|
sid varchar_ignorecase(100) not null, |
|
constraint unique_uk_1 unique(sid,principal) |
|
); |
|
|
|
create table acl_class( |
|
id bigint generated by default as identity(start with 100) not null primary key, |
|
class varchar_ignorecase(100) not null, |
|
constraint unique_uk_2 unique(class) |
|
); |
|
|
|
create table acl_object_identity( |
|
id bigint generated by default as identity(start with 100) not null primary key, |
|
object_id_class bigint not null, |
|
object_id_identity varchar_ignorecase(36) not null, |
|
parent_object bigint, |
|
owner_sid bigint, |
|
entries_inheriting boolean not null, |
|
constraint unique_uk_3 unique(object_id_class,object_id_identity), |
|
constraint foreign_fk_1 foreign key(parent_object)references acl_object_identity(id), |
|
constraint foreign_fk_2 foreign key(object_id_class)references acl_class(id), |
|
constraint foreign_fk_3 foreign key(owner_sid)references acl_sid(id) |
|
); |
|
|
|
create table acl_entry( |
|
id bigint generated by default as identity(start with 100) not null primary key, |
|
acl_object_identity bigint not null, |
|
ace_order int not null, |
|
sid bigint not null, |
|
mask integer not null, |
|
granting boolean not null, |
|
audit_success boolean not null, |
|
audit_failure boolean not null, |
|
constraint unique_uk_4 unique(acl_object_identity,ace_order), |
|
constraint foreign_fk_4 foreign key(acl_object_identity) references acl_object_identity(id), |
|
constraint foreign_fk_5 foreign key(sid) references acl_sid(id) |
|
); |
|
---- |
|
|
|
=== PostgreSQL |
|
|
|
For PostgreSQL, you have to set the `classIdentityQuery` and `sidIdentityQuery` properties of `JdbcMutableAclService` to the following values, respectively: |
|
|
|
* `select currval(pg_get_serial_sequence('acl_class', 'id'))` |
|
* `select currval(pg_get_serial_sequence('acl_sid', 'id'))` |
|
|
|
[source,ddl] |
|
---- |
|
create table acl_sid( |
|
id bigserial not null primary key, |
|
principal boolean not null, |
|
sid varchar(100) not null, |
|
constraint unique_uk_1 unique(sid,principal) |
|
); |
|
|
|
create table acl_class( |
|
id bigserial not null primary key, |
|
class varchar(100) not null, |
|
constraint unique_uk_2 unique(class) |
|
); |
|
|
|
create table acl_object_identity( |
|
id bigserial primary key, |
|
object_id_class bigint not null, |
|
object_id_identity varchar(36) not null, |
|
parent_object bigint, |
|
owner_sid bigint, |
|
entries_inheriting boolean not null, |
|
constraint unique_uk_3 unique(object_id_class,object_id_identity), |
|
constraint foreign_fk_1 foreign key(parent_object)references acl_object_identity(id), |
|
constraint foreign_fk_2 foreign key(object_id_class)references acl_class(id), |
|
constraint foreign_fk_3 foreign key(owner_sid)references acl_sid(id) |
|
); |
|
|
|
create table acl_entry( |
|
id bigserial primary key, |
|
acl_object_identity bigint not null, |
|
ace_order int not null, |
|
sid bigint not null, |
|
mask integer not null, |
|
granting boolean not null, |
|
audit_success boolean not null, |
|
audit_failure boolean not null, |
|
constraint unique_uk_4 unique(acl_object_identity,ace_order), |
|
constraint foreign_fk_4 foreign key(acl_object_identity) references acl_object_identity(id), |
|
constraint foreign_fk_5 foreign key(sid) references acl_sid(id) |
|
); |
|
---- |
|
|
|
=== MySQL and MariaDB |
|
|
|
[source,ddl] |
|
---- |
|
CREATE TABLE acl_sid ( |
|
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, |
|
principal BOOLEAN NOT NULL, |
|
sid VARCHAR(100) NOT NULL, |
|
UNIQUE KEY unique_acl_sid (sid, principal) |
|
) ENGINE=InnoDB; |
|
|
|
CREATE TABLE acl_class ( |
|
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, |
|
class VARCHAR(100) NOT NULL, |
|
UNIQUE KEY uk_acl_class (class) |
|
) ENGINE=InnoDB; |
|
|
|
CREATE TABLE acl_object_identity ( |
|
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, |
|
object_id_class BIGINT UNSIGNED NOT NULL, |
|
object_id_identity VARCHAR(36) NOT NULL, |
|
parent_object BIGINT UNSIGNED, |
|
owner_sid BIGINT UNSIGNED, |
|
entries_inheriting BOOLEAN NOT NULL, |
|
UNIQUE KEY uk_acl_object_identity (object_id_class, object_id_identity), |
|
CONSTRAINT fk_acl_object_identity_parent FOREIGN KEY (parent_object) REFERENCES acl_object_identity (id), |
|
CONSTRAINT fk_acl_object_identity_class FOREIGN KEY (object_id_class) REFERENCES acl_class (id), |
|
CONSTRAINT fk_acl_object_identity_owner FOREIGN KEY (owner_sid) REFERENCES acl_sid (id) |
|
) ENGINE=InnoDB; |
|
|
|
CREATE TABLE acl_entry ( |
|
id BIGINT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, |
|
acl_object_identity BIGINT UNSIGNED NOT NULL, |
|
ace_order INTEGER NOT NULL, |
|
sid BIGINT UNSIGNED NOT NULL, |
|
mask INTEGER UNSIGNED NOT NULL, |
|
granting BOOLEAN NOT NULL, |
|
audit_success BOOLEAN NOT NULL, |
|
audit_failure BOOLEAN NOT NULL, |
|
UNIQUE KEY unique_acl_entry (acl_object_identity, ace_order), |
|
CONSTRAINT fk_acl_entry_object FOREIGN KEY (acl_object_identity) REFERENCES acl_object_identity (id), |
|
CONSTRAINT fk_acl_entry_acl FOREIGN KEY (sid) REFERENCES acl_sid (id) |
|
) ENGINE=InnoDB; |
|
---- |
|
|
|
=== Microsoft SQL Server |
|
|
|
[source,ddl] |
|
---- |
|
CREATE TABLE acl_sid ( |
|
id BIGINT NOT NULL IDENTITY PRIMARY KEY, |
|
principal BIT NOT NULL, |
|
sid VARCHAR(100) NOT NULL, |
|
CONSTRAINT unique_acl_sid UNIQUE (sid, principal) |
|
); |
|
|
|
CREATE TABLE acl_class ( |
|
id BIGINT NOT NULL IDENTITY PRIMARY KEY, |
|
class VARCHAR(100) NOT NULL, |
|
CONSTRAINT uk_acl_class UNIQUE (class) |
|
); |
|
|
|
CREATE TABLE acl_object_identity ( |
|
id BIGINT NOT NULL IDENTITY PRIMARY KEY, |
|
object_id_class BIGINT NOT NULL, |
|
object_id_identity VARCHAR(36) NOT NULL, |
|
parent_object BIGINT, |
|
owner_sid BIGINT, |
|
entries_inheriting BIT NOT NULL, |
|
CONSTRAINT uk_acl_object_identity UNIQUE (object_id_class, object_id_identity), |
|
CONSTRAINT fk_acl_object_identity_parent FOREIGN KEY (parent_object) REFERENCES acl_object_identity (id), |
|
CONSTRAINT fk_acl_object_identity_class FOREIGN KEY (object_id_class) REFERENCES acl_class (id), |
|
CONSTRAINT fk_acl_object_identity_owner FOREIGN KEY (owner_sid) REFERENCES acl_sid (id) |
|
); |
|
|
|
CREATE TABLE acl_entry ( |
|
id BIGINT NOT NULL IDENTITY PRIMARY KEY, |
|
acl_object_identity BIGINT NOT NULL, |
|
ace_order INTEGER NOT NULL, |
|
sid BIGINT NOT NULL, |
|
mask INTEGER NOT NULL, |
|
granting BIT NOT NULL, |
|
audit_success BIT NOT NULL, |
|
audit_failure BIT NOT NULL, |
|
CONSTRAINT unique_acl_entry UNIQUE (acl_object_identity, ace_order), |
|
CONSTRAINT fk_acl_entry_object FOREIGN KEY (acl_object_identity) REFERENCES acl_object_identity (id), |
|
CONSTRAINT fk_acl_entry_acl FOREIGN KEY (sid) REFERENCES acl_sid (id) |
|
); |
|
---- |
|
|
|
=== Oracle Database |
|
|
|
[source,ddl] |
|
---- |
|
CREATE TABLE ACL_SID ( |
|
ID NUMBER(18) PRIMARY KEY, |
|
PRINCIPAL NUMBER(1) NOT NULL CHECK (PRINCIPAL IN (0, 1 )), |
|
SID NVARCHAR2(128) NOT NULL, |
|
CONSTRAINT ACL_SID_UNIQUE UNIQUE (SID, PRINCIPAL) |
|
); |
|
CREATE SEQUENCE ACL_SID_SQ START WITH 1 INCREMENT BY 1 NOMAXVALUE; |
|
CREATE OR REPLACE TRIGGER ACL_SID_SQ_TR BEFORE INSERT ON ACL_SID FOR EACH ROW |
|
BEGIN |
|
SELECT ACL_SID_SQ.NEXTVAL INTO :NEW.ID FROM DUAL; |
|
END; |
|
|
|
|
|
CREATE TABLE ACL_CLASS ( |
|
ID NUMBER(18) PRIMARY KEY, |
|
CLASS NVARCHAR2(128) NOT NULL, |
|
CONSTRAINT ACL_CLASS_UNIQUE UNIQUE (CLASS) |
|
); |
|
CREATE SEQUENCE ACL_CLASS_SQ START WITH 1 INCREMENT BY 1 NOMAXVALUE; |
|
CREATE OR REPLACE TRIGGER ACL_CLASS_ID_TR BEFORE INSERT ON ACL_CLASS FOR EACH ROW |
|
BEGIN |
|
SELECT ACL_CLASS_SQ.NEXTVAL INTO :NEW.ID FROM DUAL; |
|
END; |
|
|
|
|
|
CREATE TABLE ACL_OBJECT_IDENTITY( |
|
ID NUMBER(18) PRIMARY KEY, |
|
OBJECT_ID_CLASS NUMBER(18) NOT NULL, |
|
OBJECT_ID_IDENTITY NVARCHAR2(64) NOT NULL, |
|
PARENT_OBJECT NUMBER(18), |
|
OWNER_SID NUMBER(18), |
|
ENTRIES_INHERITING NUMBER(1) NOT NULL CHECK (ENTRIES_INHERITING IN (0, 1)), |
|
CONSTRAINT ACL_OBJECT_IDENTITY_UNIQUE UNIQUE (OBJECT_ID_CLASS, OBJECT_ID_IDENTITY), |
|
CONSTRAINT ACL_OBJECT_IDENTITY_PARENT_FK FOREIGN KEY (PARENT_OBJECT) REFERENCES ACL_OBJECT_IDENTITY(ID), |
|
CONSTRAINT ACL_OBJECT_IDENTITY_CLASS_FK FOREIGN KEY (OBJECT_ID_CLASS) REFERENCES ACL_CLASS(ID), |
|
CONSTRAINT ACL_OBJECT_IDENTITY_OWNER_FK FOREIGN KEY (OWNER_SID) REFERENCES ACL_SID(ID) |
|
); |
|
CREATE SEQUENCE ACL_OBJECT_IDENTITY_SQ START WITH 1 INCREMENT BY 1 NOMAXVALUE; |
|
CREATE OR REPLACE TRIGGER ACL_OBJECT_IDENTITY_ID_TR BEFORE INSERT ON ACL_OBJECT_IDENTITY FOR EACH ROW |
|
BEGIN |
|
SELECT ACL_OBJECT_IDENTITY_SQ.NEXTVAL INTO :NEW.ID FROM DUAL; |
|
END; |
|
|
|
|
|
CREATE TABLE ACL_ENTRY ( |
|
ID NUMBER(18) NOT NULL PRIMARY KEY, |
|
ACL_OBJECT_IDENTITY NUMBER(18) NOT NULL, |
|
ACE_ORDER INTEGER NOT NULL, |
|
SID NUMBER(18) NOT NULL, |
|
MASK INTEGER NOT NULL, |
|
GRANTING NUMBER(1) NOT NULL CHECK (GRANTING IN (0, 1)), |
|
AUDIT_SUCCESS NUMBER(1) NOT NULL CHECK (AUDIT_SUCCESS IN (0, 1)), |
|
AUDIT_FAILURE NUMBER(1) NOT NULL CHECK (AUDIT_FAILURE IN (0, 1)), |
|
CONSTRAINT ACL_ENTRY_UNIQUE UNIQUE (ACL_OBJECT_IDENTITY, ACE_ORDER), |
|
CONSTRAINT ACL_ENTRY_OBJECT_FK FOREIGN KEY (ACL_OBJECT_IDENTITY) REFERENCES ACL_OBJECT_IDENTITY (ID), |
|
CONSTRAINT ACL_ENTRY_ACL_FK FOREIGN KEY (SID) REFERENCES ACL_SID(ID) |
|
); |
|
CREATE SEQUENCE ACL_ENTRY_SQ START WITH 1 INCREMENT BY 1 NOMAXVALUE; |
|
CREATE OR REPLACE TRIGGER ACL_ENTRY_ID_TRIGGER BEFORE INSERT ON ACL_ENTRY FOR EACH ROW |
|
BEGIN |
|
SELECT ACL_ENTRY_SQ.NEXTVAL INTO :NEW.ID FROM DUAL; |
|
END; |
|
---- |
|
|
|
[[dbschema-oauth2-client]] |
|
== OAuth 2.0 Client Schema |
|
The JDBC implementation of xref:servlet/oauth2/client/core.adoc#oauth2Client-authorized-repo-service[ `OAuth2AuthorizedClientService`] (`JdbcOAuth2AuthorizedClientService`) requires a table for persisting `OAuth2AuthorizedClient` instances. |
|
You will need to adjust this schema to match the database dialect you use. |
|
|
|
[source,ddl] |
|
---- |
|
CREATE TABLE oauth2_authorized_client ( |
|
client_registration_id varchar(100) NOT NULL, |
|
principal_name varchar(200) NOT NULL, |
|
access_token_type varchar(100) NOT NULL, |
|
access_token_value blob NOT NULL, |
|
access_token_issued_at timestamp NOT NULL, |
|
access_token_expires_at timestamp NOT NULL, |
|
access_token_scopes varchar(1000) DEFAULT NULL, |
|
refresh_token_value blob DEFAULT NULL, |
|
refresh_token_issued_at timestamp DEFAULT NULL, |
|
created_at timestamp DEFAULT CURRENT_TIMESTAMP NOT NULL, |
|
PRIMARY KEY (client_registration_id, principal_name) |
|
); |
|
----
|
|
|