Skip to content

Commit

Permalink
Fix #222: Fix docs versioning and edit database structure docs [Backp…
Browse files Browse the repository at this point in the history
…ort] (#234)

* Fix #222: Fix docs versioning and edit database structure docs [Backport]
- Remove create scripts
- Remove other sections then tables
- Add create_schema.sql scripts
- Reference them in DB structure docs
- Add migration docs 1.4x to 1.5.0
- Add backport explanation
* - correct docs after backport
  • Loading branch information
jandusil authored Feb 27, 2024
1 parent aa3be4a commit 005198f
Show file tree
Hide file tree
Showing 3 changed files with 182 additions and 123 deletions.
127 changes: 4 additions & 123 deletions docs/Database-Structure.md
Original file line number Diff line number Diff line change
Expand Up @@ -2,11 +2,12 @@

<!-- TEMPLATE database -->

The database structure is extremely simple, we provide an example in PostgreSQL to describe it.
You can download DDL scripts for supported databases:

## Schema Overview
- [Oracle - Create Database Schema](./sql/oracle/create_schema.sql)
- [PostgreSQL - Create Database Schema](./sql/postgresql/create_schema.sql)

The following image captures the overview of the tables in the schema:
See the overall database schema:

<img src="./img/mobile_app.png" width="888" alt="Mobile Utility Server DB Schema"/>

Expand All @@ -17,18 +18,6 @@ The following image captures the overview of the tables in the schema:

Contains information related to various mobile apps.

#### Schema

```sql
CREATE TABLE mus_mobile_app (
id INTEGER PRIMARY KEY,
name VARCHAR(255) NOT NULL,
display_name VARCHAR(255) NOT NULL,
sign_private_key VARCHAR(255) NOT NULL,
sign_public_key VARCHAR(255) NOT NULL
);
```

#### Columns

| Column | Type | Description |
Expand All @@ -45,16 +34,6 @@ CREATE TABLE mus_mobile_app (

Contains information related to pinned domains.

#### Schema

```sql
CREATE TABLE mus_mobile_domain (
id INTEGER PRIMARY KEY,
app_id INTEGER NOT NULL,
domain VARCHAR(255) NOT NULL
);
```

#### Columns

| Column | Type | Description |
Expand All @@ -69,18 +48,6 @@ CREATE TABLE mus_mobile_domain (

Table with TLS/SSL certificate and fingerprints that should be pinned in the mobile app.

#### Schema

```sql
CREATE TABLE mus_certificate (
id INTEGER PRIMARY KEY,
pem TEXT NOT NULL,
fingerprint VARCHAR(255) NOT NULL,
expires INTEGER NOT NULL,
mobile_domain_id INTEGER NOT NULL
);
```

#### Columns

| Column | Type | Description |
Expand All @@ -97,17 +64,6 @@ CREATE TABLE mus_certificate (

Table with users for basic HTTP authentication.

#### Schema

```sql
CREATE TABLE mus_user (
id INTEGER PRIMARY KEY,
username VARCHAR(255) NOT NULL UNIQUE,
password VARCHAR(255) NOT NULL,
enabled BOOLEAN NOT NULL
);
```

#### Columns

| Column | Type | Description |
Expand All @@ -123,16 +79,6 @@ CREATE TABLE mus_user (

Table with users authorities.

#### Schema

```sql
CREATE TABLE mus_user_authority (
id INTEGER PRIMARY KEY,
user_id INTEGER NOT NULL UNIQUE,
authority VARCHAR(255) NOT NULL
);
```

#### Columns

| Column | Type | Description |
Expand All @@ -148,21 +94,6 @@ CREATE TABLE mus_user_authority (

Table to force or suggest update of mobile application version.

#### Schema

```sql
create table mus_mobile_app_version
(
id integer not null primary key,
app_id integer not null,
platform varchar(10) not null,
major_os_version integer,
suggested_version varchar(24),
required_version varchar(24),
message_key varchar(255)
);
```

#### Columns

| Column | Type | Description |
Expand All @@ -182,18 +113,6 @@ create table mus_mobile_app_version

Table with localized texts.

#### Schema

```sql
create table mus_localized_text
(
message_key varchar(255) not null,
language varchar(2) not null,
text text not null,
primary key (message_key, language)
);
```

#### Columns

| Column | Type | Description |
Expand All @@ -211,47 +130,27 @@ create table mus_localized_text

Sequence responsible for mobile app autoincrements.

#### Schema

```sql
CREATE SEQUENCE IF NOT EXISTS mus_mobile_app_seq INCREMENT BY 1 START WITH 1 CACHE 20;
```
<!-- end -->

<!-- begin database sequence mus_mobile_domain_seq -->
### Mobile App Domain Sequence

Sequence responsible for mobile domain autoincrements.

#### Schema

```sql
CREATE SEQUENCE IF NOT EXISTS mus_mobile_domain_seq INCREMENT BY 1 START WITH 1 CACHE 20;
```
<!-- end -->

<!-- begin database sequence mus_certificate_seq -->
### SSL Certificate Sequence

Sequence responsible for SSL certificates and fingerprints autoincrements.

#### Schema

```sql
CREATE SEQUENCE IF NOT EXISTS mus_certificates_seq INCREMENT BY 1 START WITH 1 CACHE 20;
```
<!-- end -->

<!-- begin database sequence mus_mobile_app_version_seq -->
### Mobile Application Version Sequence

Sequence responsible for mobile application version autoincrements.

#### Schema

```sql
CREATE SEQUENCE IF NOT EXISTS mus_mobile_app_version_seq INCREMENT BY 1 START WITH 1 CACHE 20;
```
<!-- end -->


Expand All @@ -264,36 +163,18 @@ The tables are relatively small and as a result, do not require indexes. To marg

Foreign index for mapping the fingerprint to domain.

#### Schema
```sql
ALTER TABLE mus_mobile_fingerprint
ADD CONSTRAINT mobile_ssl_pinning_app_fk FOREIGN KEY (mobile_domain_id)
REFERENCES mus_mobile_domain ON UPDATE CASCADE ON DELETE CASCADE;
```
<!-- end -->

<!-- begin database index mus_mobile_domain -->
### Foreign Index for Domain Lookup

Foreign index to map the domain to mobile app.

#### Schema
```sql
ALTER TABLE mus_mobile_domain
ADD CONSTRAINT mus_mobile_domain_fk FOREIGN KEY (app_id)
REFERENCES mus_mobile_app ON UPDATE CASCADE ON DELETE CASCADE;
```
<!-- end -->

<!-- begin database index mus_user_authority -->
### Foreign Index for User Authority Lookup

Foreign index to map the user authority to the user.

#### Schema
```sql
ALTER TABLE mus_user_authority
ADD CONSTRAINT mus_user_fk FOREIGN KEY (app_id)
REFERENCES mus_user ON UPDATE CASCADE ON DELETE CASCADE;
```
<!-- end -->
89 changes: 89 additions & 0 deletions docs/sql/oracle/create_schema.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,89 @@
-- Changeset mobile-utility-server/1.5.x/20230227-initial-import.xml::1::Petr Dvorak
-- Create a new sequence for mobile app entities.
CREATE SEQUENCE mus_mobile_app_seq START WITH 1 INCREMENT BY 1 CACHE 20;

-- Changeset mobile-utility-server/1.5.x/20230227-initial-import.xml::2::Petr Dvorak
-- Create a new sequence for mobile domain entities.
CREATE SEQUENCE mus_mobile_domain_seq START WITH 1 INCREMENT BY 1 CACHE 20;

-- Changeset mobile-utility-server/1.5.x/20230227-initial-import.xml::3::Petr Dvorak
-- Create a new sequence for mobile SSL fingerprints entities.
CREATE SEQUENCE mus_mobile_fingerprint_seq START WITH 1 INCREMENT BY 1 CACHE 20;

-- Changeset mobile-utility-server/1.5.x/20230227-initial-import.xml::4::Petr Dvorak
-- Create a new table for mobile app entities.
CREATE TABLE mus_mobile_app (id INTEGER NOT NULL, name VARCHAR2(255) NOT NULL, display_name VARCHAR2(255) NOT NULL, sign_private_key VARCHAR2(255) NOT NULL, sign_public_key VARCHAR2(255) NOT NULL, CONSTRAINT PK_MUS_MOBILE_APP PRIMARY KEY (id));

-- Changeset mobile-utility-server/1.5.x/20230227-initial-import.xml::5::Petr Dvorak
-- Create a new table for mobile domain entities.
CREATE TABLE mus_mobile_domain (id INTEGER NOT NULL, app_id INTEGER NOT NULL, domain VARCHAR2(255) NOT NULL, CONSTRAINT PK_MUS_MOBILE_DOMAIN PRIMARY KEY (id), CONSTRAINT mus_mobile_domain_app_id_fk FOREIGN KEY (app_id) REFERENCES mus_mobile_app(id) ON DELETE CASCADE);

-- Changeset mobile-utility-server/1.5.x/20230227-initial-import.xml::6::Petr Dvorak
-- Create a new table for mobile SSL fingerprint entities.
CREATE TABLE mus_mobile_fingerprint (id INTEGER NOT NULL, fingerprint VARCHAR2(255) NOT NULL, expires INTEGER NOT NULL, mobile_domain_id INTEGER NOT NULL, CONSTRAINT PK_MUS_MOBILE_FINGERPRINT PRIMARY KEY (id), CONSTRAINT mus_mobile_fingerprint_mobile_domain_id_fk FOREIGN KEY (mobile_domain_id) REFERENCES mus_mobile_domain(id) ON DELETE CASCADE);

-- Changeset mobile-utility-server/1.5.x/20230306-add-user-schema.xml::1::Petr Dvorak
-- Create a new sequence for user entities.
CREATE SEQUENCE mus_user_seq START WITH 1 INCREMENT BY 1 CACHE 20;

-- Changeset mobile-utility-server/1.5.x/20230306-add-user-schema.xml::2::Petr Dvorak
-- Create a new sequence for user authority entities.
CREATE SEQUENCE mus_user_authority_seq START WITH 1 INCREMENT BY 1 CACHE 20;

-- Changeset mobile-utility-server/1.5.x/20230306-add-user-schema.xml::3::Petr Dvorak
-- Create a new table for user entities.
CREATE TABLE mus_user (id INTEGER NOT NULL, username VARCHAR2(255) NOT NULL, "password" VARCHAR2(255) NOT NULL, enabled NUMBER(1) NOT NULL, CONSTRAINT PK_MUS_USER PRIMARY KEY (id), UNIQUE (username));

-- Changeset mobile-utility-server/1.5.x/20230306-add-user-schema.xml::4::Petr Dvorak
-- Create a new table for user authority entities.
CREATE TABLE mus_user_authority (id INTEGER NOT NULL, user_id INTEGER NOT NULL, authority VARCHAR2(255) NOT NULL, CONSTRAINT PK_MUS_USER_AUTHORITY PRIMARY KEY (id), CONSTRAINT mus_user_authority_user_id_fk FOREIGN KEY (user_id) REFERENCES mus_user(id) ON DELETE CASCADE);

-- Changeset mobile-utility-server/1.5.x/20230308-additional-cert-info.xml::1::Petr Dvorak
-- Create a new column to store the certificate in PEM format.
ALTER TABLE mus_mobile_fingerprint ADD pem CLOB NOT NULL;

-- Changeset mobile-utility-server/1.5.x/20230308-additional-cert-info.xml::2::Petr Dvorak
-- Rename the mus_mobile_fingerprint table to mus_certificate.
ALTER TABLE mus_mobile_fingerprint RENAME TO mus_certificate;

-- Changeset mobile-utility-server/1.5.x/20230308-additional-cert-info.xml::3::Petr Dvorak
-- Rename the mus_mobile_fingerprint_seq sequence to mus_certificate_seq.
RENAME mus_mobile_fingerprint_seq TO mus_certificate_seq;

-- Changeset mobile-utility-server/1.5.x/20230308-additional-cert-info.xml::4::Jan Dusil
ALTER TABLE mus_certificate DROP CONSTRAINT mus_mobile_fingerprint_mobile_domain_id_fk;

-- Changeset mobile-utility-server/1.5.x/20230609-add-application-version.xml::1::Lubos Racansky
-- Create a new sequence mus_mobile_app_version_seq.
CREATE SEQUENCE mus_mobile_app_version_seq START WITH 1 INCREMENT BY 1 CACHE 20;

-- Changeset mobile-utility-server/1.5.x/20230609-add-application-version.xml::2::Lubos Racansky
-- Create a new table mus_mobile_app_version.
CREATE TABLE mus_mobile_app_version (id INTEGER NOT NULL, app_id INTEGER NOT NULL, platform VARCHAR2(10) NOT NULL, major_os_version INTEGER, suggested_version VARCHAR2(24), required_version VARCHAR2(24), message_key VARCHAR2(255), CONSTRAINT PK_MUS_MOBILE_APP_VERSION PRIMARY KEY (id), CONSTRAINT mus_mobile_app_version_app_id_fk FOREIGN KEY (app_id) REFERENCES mus_mobile_app(id));

COMMENT ON COLUMN mus_mobile_app_version.platform IS 'ANDROID, IOS';

COMMENT ON COLUMN mus_mobile_app_version.major_os_version IS 'For iOS e.g. 12.4.2 it is 12. For Android, it is API level e.g. 29.';

COMMENT ON COLUMN mus_mobile_app_version.suggested_version IS 'SemVer 2.0';

COMMENT ON COLUMN mus_mobile_app_version.required_version IS 'SemVer 2.0';

COMMENT ON COLUMN mus_mobile_app_version.message_key IS 'Together with language identifies row in mus_localized_text';

-- Changeset mobile-utility-server/1.5.x/20230609-add-application-version.xml::3::Lubos Racansky
-- Create a new table mus_localized_text.
CREATE TABLE mus_localized_text (message_key VARCHAR2(255) NOT NULL, language VARCHAR2(2) NOT NULL, text CLOB NOT NULL, CONSTRAINT PK_MUS_LOCALIZED_TEXT PRIMARY KEY (message_key, language));

COMMENT ON COLUMN mus_localized_text.language IS 'ISO 639-1 two-letter language code.';

-- Changeset mobile-utility-server/1.5.x/20230622-add-foreign-keys.xml::1::Lubos Racansky
ALTER TABLE mus_user_authority ADD CONSTRAINT mus_user_authority_user_id_fk FOREIGN KEY (user_id) REFERENCES mus_user (id);

-- Changeset mobile-utility-server/1.5.x/20230622-add-foreign-keys.xml::2::Lubos Racansky
ALTER TABLE mus_mobile_domain ADD CONSTRAINT mus_mobile_domain_app_id_fk FOREIGN KEY (app_id) REFERENCES mus_mobile_app (id);

-- Changeset mobile-utility-server/1.5.x/20230622-add-foreign-keys.xml::3::Lubos Racansky
ALTER TABLE mus_certificate ADD CONSTRAINT mus_certificate_mobile_domain_id_fk FOREIGN KEY (mobile_domain_id) REFERENCES mus_mobile_domain (id);

-- Changeset mobile-utility-server/1.5.x/20230905-add-tag-1.5.0.xml::1::Lubos Racansky
Loading

0 comments on commit 005198f

Please sign in to comment.