[feat] add initial database schema with tables, triggers, and views
This commit is contained in:
9
database/main/attribute.sql
Normal file
9
database/main/attribute.sql
Normal file
@@ -0,0 +1,9 @@
|
||||
create table attribute
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
code TEXT
|
||||
unique,
|
||||
name TEXT
|
||||
);
|
||||
|
20
database/main/book.sql
Normal file
20
database/main/book.sql
Normal file
@@ -0,0 +1,20 @@
|
||||
create table book
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
code TEXT not null
|
||||
unique,
|
||||
title TEXT not null,
|
||||
subtitle TEXT,
|
||||
series TEXT,
|
||||
volume TEXT,
|
||||
edition TEXT,
|
||||
isbn13 TEXT
|
||||
unique,
|
||||
publisher TEXT,
|
||||
language TEXT,
|
||||
published_at TEXT,
|
||||
url TEXT,
|
||||
license TEXT
|
||||
);
|
||||
|
17
database/main/citation.sql
Normal file
17
database/main/citation.sql
Normal file
@@ -0,0 +1,17 @@
|
||||
create table citation
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
book_id INTEGER not null
|
||||
references book
|
||||
on delete cascade,
|
||||
page_start INTEGER not null,
|
||||
page_end INTEGER,
|
||||
section TEXT,
|
||||
anchor TEXT,
|
||||
note TEXT
|
||||
);
|
||||
|
||||
create index idx_citation_book
|
||||
on citation (book_id, page_start);
|
||||
|
12
database/main/culture.sql
Normal file
12
database/main/culture.sql
Normal file
@@ -0,0 +1,12 @@
|
||||
create table culture
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
optolith_key TEXT not null
|
||||
unique,
|
||||
name TEXT not null
|
||||
);
|
||||
|
||||
create index idx_culture_name
|
||||
on culture (name);
|
||||
|
14
database/main/culture_citation.sql
Normal file
14
database/main/culture_citation.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table culture_citation
|
||||
(
|
||||
culture_id INTEGER not null
|
||||
references culture
|
||||
on delete cascade,
|
||||
citation_id INTEGER not null
|
||||
references citation
|
||||
on delete cascade,
|
||||
primary key (culture_id, citation_id)
|
||||
);
|
||||
|
||||
create index idx_culture_citation_cit
|
||||
on culture_citation (citation_id);
|
||||
|
15
database/main/culture_language.sql
Normal file
15
database/main/culture_language.sql
Normal file
@@ -0,0 +1,15 @@
|
||||
create table culture_language
|
||||
(
|
||||
culture_id INTEGER not null
|
||||
references culture
|
||||
on delete cascade,
|
||||
language_id INTEGER not null
|
||||
references language
|
||||
on delete restrict,
|
||||
level TEXT,
|
||||
primary key (culture_id, language_id)
|
||||
);
|
||||
|
||||
create index idx_culture_language_lang
|
||||
on culture_language (language_id);
|
||||
|
14
database/main/culture_profession.sql
Normal file
14
database/main/culture_profession.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table culture_profession
|
||||
(
|
||||
culture_id INTEGER not null
|
||||
references culture
|
||||
on delete cascade,
|
||||
profession_id INTEGER not null
|
||||
references profession
|
||||
on delete restrict,
|
||||
primary key (culture_id, profession_id)
|
||||
);
|
||||
|
||||
create index idx_culture_profession_prof
|
||||
on culture_profession (profession_id);
|
||||
|
14
database/main/culture_script.sql
Normal file
14
database/main/culture_script.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table culture_script
|
||||
(
|
||||
culture_id INTEGER not null
|
||||
references culture
|
||||
on delete cascade,
|
||||
script_id INTEGER not null
|
||||
references script
|
||||
on delete restrict,
|
||||
primary key (culture_id, script_id)
|
||||
);
|
||||
|
||||
create index idx_culture_script_script
|
||||
on culture_script (script_id);
|
||||
|
21
database/main/culture_trait.sql
Normal file
21
database/main/culture_trait.sql
Normal file
@@ -0,0 +1,21 @@
|
||||
create table culture_trait
|
||||
(
|
||||
culture_id INTEGER not null
|
||||
references culture
|
||||
on delete cascade,
|
||||
trait_id INTEGER not null
|
||||
references trait
|
||||
on delete restrict,
|
||||
tag TEXT not null,
|
||||
level INTEGER,
|
||||
param_value TEXT,
|
||||
primary key (culture_id, trait_id, tag),
|
||||
check (tag IN ('TYPISCH', 'EMPFOHLEN'))
|
||||
);
|
||||
|
||||
create index idx_culture_trait_trait
|
||||
on culture_trait (trait_id);
|
||||
|
||||
create index idx_culture_trait_trait2
|
||||
on culture_trait (trait_id);
|
||||
|
9
database/main/exclusive_group.sql
Normal file
9
database/main/exclusive_group.sql
Normal file
@@ -0,0 +1,9 @@
|
||||
create table exclusive_group
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
name TEXT not null,
|
||||
scope TEXT not null,
|
||||
check (scope IN ('TRAIT', 'SF', 'TALENT', 'SPELL', 'LITURGY'))
|
||||
);
|
||||
|
9
database/main/exclusive_group_member.sql
Normal file
9
database/main/exclusive_group_member.sql
Normal file
@@ -0,0 +1,9 @@
|
||||
create table exclusive_group_member
|
||||
(
|
||||
group_id INTEGER not null
|
||||
references exclusive_group
|
||||
on delete cascade,
|
||||
owner_id INTEGER not null,
|
||||
primary key (group_id, owner_id)
|
||||
);
|
||||
|
17
database/main/kampftechnik.sql
Normal file
17
database/main/kampftechnik.sql
Normal file
@@ -0,0 +1,17 @@
|
||||
create table kampftechnik
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
optolith_key TEXT not null
|
||||
unique,
|
||||
name TEXT not null,
|
||||
grundwert INTEGER default 6 not null,
|
||||
probe_attr1_id INTEGER
|
||||
references attribute,
|
||||
probe_attr2_id INTEGER
|
||||
references attribute,
|
||||
probe_attr3_id INTEGER
|
||||
references attribute,
|
||||
beschreibung TEXT
|
||||
);
|
||||
|
10
database/main/language.sql
Normal file
10
database/main/language.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
create table language
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
code TEXT
|
||||
unique,
|
||||
name TEXT not null
|
||||
unique
|
||||
);
|
||||
|
22
database/main/liturgy.sql
Normal file
22
database/main/liturgy.sql
Normal file
@@ -0,0 +1,22 @@
|
||||
create table liturgy
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
optolith_key TEXT not null
|
||||
unique,
|
||||
name TEXT not null,
|
||||
probe_attr1_id INTEGER not null
|
||||
references attribute,
|
||||
probe_attr2_id INTEGER not null
|
||||
references attribute,
|
||||
probe_attr3_id INTEGER not null
|
||||
references attribute,
|
||||
wirkung TEXT,
|
||||
dauer TEXT,
|
||||
kap_kosten TEXT,
|
||||
reichweite TEXT,
|
||||
wirkungsdauer TEXT,
|
||||
steig_faktor TEXT not null,
|
||||
check (steig_faktor IN ('A', 'B', 'C', 'D'))
|
||||
);
|
||||
|
14
database/main/liturgy_citation.sql
Normal file
14
database/main/liturgy_citation.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table liturgy_citation
|
||||
(
|
||||
liturgy_id INTEGER not null
|
||||
references liturgy
|
||||
on delete cascade,
|
||||
citation_id INTEGER not null
|
||||
references citation
|
||||
on delete cascade,
|
||||
primary key (liturgy_id, citation_id)
|
||||
);
|
||||
|
||||
create index idx_liturgy_citation_cit
|
||||
on liturgy_citation (citation_id);
|
||||
|
14
database/main/liturgy_tradition.sql
Normal file
14
database/main/liturgy_tradition.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table liturgy_tradition
|
||||
(
|
||||
liturgy_id INTEGER not null
|
||||
references liturgy
|
||||
on delete cascade,
|
||||
tradition_id INTEGER not null
|
||||
references tradition
|
||||
on delete restrict,
|
||||
primary key (liturgy_id, tradition_id)
|
||||
);
|
||||
|
||||
create index idx_liturgy_tradition_t
|
||||
on liturgy_tradition (tradition_id);
|
||||
|
14
database/main/liturgy_zielkategorie.sql
Normal file
14
database/main/liturgy_zielkategorie.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table liturgy_zielkategorie
|
||||
(
|
||||
liturgy_id INTEGER not null
|
||||
references liturgy
|
||||
on delete cascade,
|
||||
zielkategorie_id INTEGER not null
|
||||
references zielkategorie
|
||||
on delete restrict,
|
||||
primary key (liturgy_id, zielkategorie_id)
|
||||
);
|
||||
|
||||
create index idx_liturgy_zielkat_z
|
||||
on liturgy_zielkategorie (zielkategorie_id);
|
||||
|
8
database/main/merkmal.sql
Normal file
8
database/main/merkmal.sql
Normal file
@@ -0,0 +1,8 @@
|
||||
create table merkmal
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
name TEXT not null
|
||||
unique
|
||||
);
|
||||
|
14
database/main/profession.sql
Normal file
14
database/main/profession.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table profession
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
optolith_key TEXT not null
|
||||
unique,
|
||||
name TEXT not null,
|
||||
typ TEXT,
|
||||
beschreibung TEXT
|
||||
);
|
||||
|
||||
create index idx_profession_name
|
||||
on profession (name);
|
||||
|
14
database/main/profession_citation.sql
Normal file
14
database/main/profession_citation.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table profession_citation
|
||||
(
|
||||
profession_id INTEGER not null
|
||||
references profession
|
||||
on delete cascade,
|
||||
citation_id INTEGER not null
|
||||
references citation
|
||||
on delete cascade,
|
||||
primary key (profession_id, citation_id)
|
||||
);
|
||||
|
||||
create index idx_profession_citation_cit
|
||||
on profession_citation (citation_id);
|
||||
|
14
database/main/profession_special_ability.sql
Normal file
14
database/main/profession_special_ability.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table profession_special_ability
|
||||
(
|
||||
profession_id INTEGER not null
|
||||
references profession
|
||||
on delete cascade,
|
||||
special_ability_id INTEGER not null
|
||||
references special_ability
|
||||
on delete restrict,
|
||||
primary key (profession_id, special_ability_id)
|
||||
);
|
||||
|
||||
create index idx_profession_sa_sa
|
||||
on profession_special_ability (special_ability_id);
|
||||
|
19
database/main/profession_trait.sql
Normal file
19
database/main/profession_trait.sql
Normal file
@@ -0,0 +1,19 @@
|
||||
create table profession_trait
|
||||
(
|
||||
profession_id INTEGER not null
|
||||
references profession
|
||||
on delete cascade,
|
||||
trait_id INTEGER not null
|
||||
references trait
|
||||
on delete restrict,
|
||||
level INTEGER,
|
||||
param_value TEXT,
|
||||
primary key (profession_id, trait_id)
|
||||
);
|
||||
|
||||
create index idx_profession_trait_trait
|
||||
on profession_trait (trait_id);
|
||||
|
||||
create index idx_profession_trait_trait2
|
||||
on profession_trait (trait_id);
|
||||
|
31
database/main/requirement.sql
Normal file
31
database/main/requirement.sql
Normal file
@@ -0,0 +1,31 @@
|
||||
create table requirement
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
owner_kind TEXT not null,
|
||||
owner_id INTEGER not null,
|
||||
group_no INTEGER default 1 not null,
|
||||
negate INTEGER default 0 not null,
|
||||
req_type TEXT not null,
|
||||
req_id INTEGER,
|
||||
req_level INTEGER,
|
||||
req_optokey TEXT,
|
||||
note TEXT,
|
||||
check (negate IN (0, 1)),
|
||||
check (owner_kind IN (
|
||||
'TRAIT', 'SF', 'TALENT', 'SPELL', 'LITURGY', 'PROFESSION', 'SPECIES', 'CULTURE'
|
||||
)),
|
||||
check (req_type IN (
|
||||
'TRAIT', 'TRAIT_LEVEL_MIN',
|
||||
'ATTR_MIN', 'TALENT_MIN', 'SF',
|
||||
'SPECIES', 'CULTURE', 'TRADITION', 'MERKMAL',
|
||||
'EXCLUSIVE_GROUP'
|
||||
))
|
||||
);
|
||||
|
||||
create index idx_requirement_owner
|
||||
on requirement (owner_kind, owner_id, group_no);
|
||||
|
||||
create index idx_requirement_ref
|
||||
on requirement (req_type, req_id);
|
||||
|
7
database/main/sa_type.sql
Normal file
7
database/main/sa_type.sql
Normal file
@@ -0,0 +1,7 @@
|
||||
create table sa_type
|
||||
(
|
||||
code TEXT
|
||||
primary key,
|
||||
name TEXT not null
|
||||
);
|
||||
|
10
database/main/script.sql
Normal file
10
database/main/script.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
create table script
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
code TEXT
|
||||
unique,
|
||||
name TEXT not null
|
||||
unique
|
||||
);
|
||||
|
14
database/main/special_ability.sql
Normal file
14
database/main/special_ability.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table special_ability
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
optolith_key TEXT not null
|
||||
unique,
|
||||
name TEXT not null,
|
||||
type_code TEXT
|
||||
references sa_type
|
||||
on update cascade,
|
||||
ap_kosten INTEGER,
|
||||
beschreibung TEXT
|
||||
);
|
||||
|
14
database/main/special_ability_citation.sql
Normal file
14
database/main/special_ability_citation.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table special_ability_citation
|
||||
(
|
||||
special_ability_id INTEGER not null
|
||||
references special_ability
|
||||
on delete cascade,
|
||||
citation_id INTEGER not null
|
||||
references citation
|
||||
on delete cascade,
|
||||
primary key (special_ability_id, citation_id)
|
||||
);
|
||||
|
||||
create index idx_special_ability_citation_cit
|
||||
on special_ability_citation (citation_id);
|
||||
|
17
database/main/species.sql
Normal file
17
database/main/species.sql
Normal file
@@ -0,0 +1,17 @@
|
||||
create table species
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
optolith_key TEXT not null
|
||||
unique,
|
||||
name TEXT not null,
|
||||
ap_kosten INTEGER,
|
||||
le_grund INTEGER,
|
||||
sk_grund INTEGER,
|
||||
zk_grund INTEGER,
|
||||
gs_grund INTEGER
|
||||
);
|
||||
|
||||
create index idx_species_name
|
||||
on species (name);
|
||||
|
15
database/main/species_attribute_mod.sql
Normal file
15
database/main/species_attribute_mod.sql
Normal file
@@ -0,0 +1,15 @@
|
||||
create table species_attribute_mod
|
||||
(
|
||||
species_id INTEGER not null
|
||||
references species
|
||||
on delete cascade,
|
||||
attribute_id INTEGER not null
|
||||
references attribute
|
||||
on delete restrict,
|
||||
delta INTEGER not null,
|
||||
primary key (species_id, attribute_id)
|
||||
);
|
||||
|
||||
create index idx_species_attrmod_attr
|
||||
on species_attribute_mod (attribute_id);
|
||||
|
14
database/main/species_citation.sql
Normal file
14
database/main/species_citation.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table species_citation
|
||||
(
|
||||
species_id INTEGER not null
|
||||
references species
|
||||
on delete cascade,
|
||||
citation_id INTEGER not null
|
||||
references citation
|
||||
on delete cascade,
|
||||
primary key (species_id, citation_id)
|
||||
);
|
||||
|
||||
create index idx_species_citation_cit
|
||||
on species_citation (citation_id);
|
||||
|
21
database/main/species_trait.sql
Normal file
21
database/main/species_trait.sql
Normal file
@@ -0,0 +1,21 @@
|
||||
create table species_trait
|
||||
(
|
||||
species_id INTEGER not null
|
||||
references species
|
||||
on delete cascade,
|
||||
trait_id INTEGER not null
|
||||
references trait
|
||||
on delete restrict,
|
||||
source TEXT not null,
|
||||
level INTEGER,
|
||||
param_value TEXT,
|
||||
primary key (species_id, trait_id, source),
|
||||
check (source IN ('AUTOMATISCH', 'TYPISCH', 'EMPFOHLEN'))
|
||||
);
|
||||
|
||||
create index idx_species_trait_trait
|
||||
on species_trait (trait_id);
|
||||
|
||||
create index idx_species_trait_trait2
|
||||
on species_trait (trait_id);
|
||||
|
22
database/main/spell.sql
Normal file
22
database/main/spell.sql
Normal file
@@ -0,0 +1,22 @@
|
||||
create table spell
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
optolith_key TEXT not null
|
||||
unique,
|
||||
name TEXT not null,
|
||||
probe_attr1_id INTEGER not null
|
||||
references attribute,
|
||||
probe_attr2_id INTEGER not null
|
||||
references attribute,
|
||||
probe_attr3_id INTEGER not null
|
||||
references attribute,
|
||||
wirkung TEXT,
|
||||
zauberdauer TEXT,
|
||||
asp_kosten TEXT,
|
||||
reichweite TEXT,
|
||||
wirkungsdauer TEXT,
|
||||
steig_faktor TEXT not null,
|
||||
check (steig_faktor IN ('A', 'B', 'C', 'D'))
|
||||
);
|
||||
|
14
database/main/spell_citation.sql
Normal file
14
database/main/spell_citation.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table spell_citation
|
||||
(
|
||||
spell_id INTEGER not null
|
||||
references spell
|
||||
on delete cascade,
|
||||
citation_id INTEGER not null
|
||||
references citation
|
||||
on delete cascade,
|
||||
primary key (spell_id, citation_id)
|
||||
);
|
||||
|
||||
create index idx_spell_citation_cit
|
||||
on spell_citation (citation_id);
|
||||
|
14
database/main/spell_merkmal.sql
Normal file
14
database/main/spell_merkmal.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table spell_merkmal
|
||||
(
|
||||
spell_id INTEGER not null
|
||||
references spell
|
||||
on delete cascade,
|
||||
merkmal_id INTEGER not null
|
||||
references merkmal
|
||||
on delete restrict,
|
||||
primary key (spell_id, merkmal_id)
|
||||
);
|
||||
|
||||
create index idx_spell_merkmal_m
|
||||
on spell_merkmal (merkmal_id);
|
||||
|
14
database/main/spell_tradition.sql
Normal file
14
database/main/spell_tradition.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table spell_tradition
|
||||
(
|
||||
spell_id INTEGER not null
|
||||
references spell
|
||||
on delete cascade,
|
||||
tradition_id INTEGER not null
|
||||
references tradition
|
||||
on delete restrict,
|
||||
primary key (spell_id, tradition_id)
|
||||
);
|
||||
|
||||
create index idx_spell_tradition_t
|
||||
on spell_tradition (tradition_id);
|
||||
|
14
database/main/spell_zielkategorie.sql
Normal file
14
database/main/spell_zielkategorie.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table spell_zielkategorie
|
||||
(
|
||||
spell_id INTEGER not null
|
||||
references spell
|
||||
on delete cascade,
|
||||
zielkategorie_id INTEGER not null
|
||||
references zielkategorie
|
||||
on delete restrict,
|
||||
primary key (spell_id, zielkategorie_id)
|
||||
);
|
||||
|
||||
create index idx_spell_zielkat_z
|
||||
on spell_zielkategorie (zielkategorie_id);
|
||||
|
24
database/main/talent.sql
Normal file
24
database/main/talent.sql
Normal file
@@ -0,0 +1,24 @@
|
||||
create table talent
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
optolith_key TEXT not null
|
||||
unique,
|
||||
name TEXT not null,
|
||||
group_code TEXT
|
||||
references talent_group
|
||||
on update cascade,
|
||||
probe_attr1_id INTEGER not null
|
||||
references attribute,
|
||||
probe_attr2_id INTEGER not null
|
||||
references attribute,
|
||||
probe_attr3_id INTEGER not null
|
||||
references attribute,
|
||||
steig_faktor TEXT not null,
|
||||
beschreibung TEXT,
|
||||
check (steig_faktor IN ('A', 'B', 'C', 'D'))
|
||||
);
|
||||
|
||||
create index idx_talent_group
|
||||
on talent (group_code);
|
||||
|
14
database/main/talent_citation.sql
Normal file
14
database/main/talent_citation.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table talent_citation
|
||||
(
|
||||
talent_id INTEGER not null
|
||||
references talent
|
||||
on delete cascade,
|
||||
citation_id INTEGER not null
|
||||
references citation
|
||||
on delete cascade,
|
||||
primary key (talent_id, citation_id)
|
||||
);
|
||||
|
||||
create index idx_talent_citation_cit
|
||||
on talent_citation (citation_id);
|
||||
|
7
database/main/talent_group.sql
Normal file
7
database/main/talent_group.sql
Normal file
@@ -0,0 +1,7 @@
|
||||
create table talent_group
|
||||
(
|
||||
code TEXT
|
||||
primary key,
|
||||
name TEXT not null
|
||||
);
|
||||
|
8
database/main/tradition.sql
Normal file
8
database/main/tradition.sql
Normal file
@@ -0,0 +1,8 @@
|
||||
create table tradition
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
name TEXT not null
|
||||
unique
|
||||
);
|
||||
|
25
database/main/trait.sql
Normal file
25
database/main/trait.sql
Normal file
@@ -0,0 +1,25 @@
|
||||
create table trait
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
optolith_key TEXT not null
|
||||
unique,
|
||||
name TEXT not null,
|
||||
kind TEXT not null,
|
||||
is_leveled INTEGER default 0 not null,
|
||||
level_min INTEGER,
|
||||
level_max INTEGER,
|
||||
level_step INTEGER,
|
||||
ap_cost_mode TEXT default 'FIXED' not null,
|
||||
ap_wert INTEGER,
|
||||
ap_per_level INTEGER,
|
||||
ap_formula TEXT,
|
||||
beschreibung TEXT,
|
||||
check (ap_cost_mode IN ('FIXED', 'PER_LEVEL', 'TABLE', 'FORMULA')),
|
||||
check (is_leveled IN (0, 1)),
|
||||
check (kind IN ('VORTEIL', 'NACHTEIL'))
|
||||
);
|
||||
|
||||
create index idx_trait_kind
|
||||
on trait (kind);
|
||||
|
14
database/main/trait_citation.sql
Normal file
14
database/main/trait_citation.sql
Normal file
@@ -0,0 +1,14 @@
|
||||
create table trait_citation
|
||||
(
|
||||
trait_id INTEGER not null
|
||||
references trait
|
||||
on delete cascade,
|
||||
citation_id INTEGER not null
|
||||
references citation
|
||||
on delete cascade,
|
||||
primary key (trait_id, citation_id)
|
||||
);
|
||||
|
||||
create index idx_trait_citation_cit
|
||||
on trait_citation (citation_id);
|
||||
|
11
database/main/trait_conflict.sql
Normal file
11
database/main/trait_conflict.sql
Normal file
@@ -0,0 +1,11 @@
|
||||
create table trait_conflict
|
||||
(
|
||||
trait_id INTEGER not null
|
||||
references trait
|
||||
on delete cascade,
|
||||
incompatible_trait_id INTEGER not null
|
||||
references trait
|
||||
on delete cascade,
|
||||
primary key (trait_id, incompatible_trait_id)
|
||||
);
|
||||
|
12
database/main/trait_level.sql
Normal file
12
database/main/trait_level.sql
Normal file
@@ -0,0 +1,12 @@
|
||||
create table trait_level
|
||||
(
|
||||
trait_id INTEGER not null
|
||||
references trait
|
||||
on delete cascade,
|
||||
level INTEGER not null,
|
||||
ap_cost INTEGER,
|
||||
label TEXT,
|
||||
note TEXT,
|
||||
primary key (trait_id, level)
|
||||
);
|
||||
|
10
database/main/trg_requirement_check_attr_insert.sql
Normal file
10
database/main/trg_requirement_check_attr_insert.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_attr_insert
|
||||
BEFORE INSERT ON requirement
|
||||
WHEN NEW.req_type = 'ATTR_MIN'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM attribute WHERE id = NEW.req_id)
|
||||
THEN RAISE(ABORT, 'requirement.req_id must reference attribute.id for ATTR_MIN')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_attr_update.sql
Normal file
10
database/main/trg_requirement_check_attr_update.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_attr_update
|
||||
BEFORE UPDATE ON requirement
|
||||
WHEN NEW.req_type = 'ATTR_MIN'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM attribute WHERE id = NEW.req_id)
|
||||
THEN RAISE(ABORT, 'requirement.req_id must reference attribute.id for ATTR_MIN (UPDATE)')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_culture_insert.sql
Normal file
10
database/main/trg_requirement_check_culture_insert.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_culture_insert
|
||||
BEFORE INSERT ON requirement
|
||||
WHEN NEW.req_type='CULTURE'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM culture WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference culture.id for CULTURE')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_culture_update.sql
Normal file
10
database/main/trg_requirement_check_culture_update.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_culture_update
|
||||
BEFORE UPDATE ON requirement
|
||||
WHEN NEW.req_type='CULTURE'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM culture WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference culture.id for CULTURE (UPDATE)')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_exclgrp_insert.sql
Normal file
10
database/main/trg_requirement_check_exclgrp_insert.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_exclgrp_insert
|
||||
BEFORE INSERT ON requirement
|
||||
WHEN NEW.req_type='EXCLUSIVE_GROUP'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM exclusive_group WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference exclusive_group.id for EXCLUSIVE_GROUP')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_exclgrp_update.sql
Normal file
10
database/main/trg_requirement_check_exclgrp_update.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_exclgrp_update
|
||||
BEFORE UPDATE ON requirement
|
||||
WHEN NEW.req_type='EXCLUSIVE_GROUP'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM exclusive_group WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference exclusive_group.id for EXCLUSIVE_GROUP (UPDATE)')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_merk_insert.sql
Normal file
10
database/main/trg_requirement_check_merk_insert.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_merk_insert
|
||||
BEFORE INSERT ON requirement
|
||||
WHEN NEW.req_type='MERKMAL'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM merkmal WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference merkmal.id for MERKMAL')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_merk_update.sql
Normal file
10
database/main/trg_requirement_check_merk_update.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_merk_update
|
||||
BEFORE UPDATE ON requirement
|
||||
WHEN NEW.req_type='MERKMAL'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM merkmal WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference merkmal.id for MERKMAL (UPDATE)')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_sf_insert.sql
Normal file
10
database/main/trg_requirement_check_sf_insert.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_sf_insert
|
||||
BEFORE INSERT ON requirement
|
||||
WHEN NEW.req_type='SF'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM special_ability WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference special_ability.id for SF')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_sf_update.sql
Normal file
10
database/main/trg_requirement_check_sf_update.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_sf_update
|
||||
BEFORE UPDATE ON requirement
|
||||
WHEN NEW.req_type='SF'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM special_ability WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference special_ability.id for SF (UPDATE)')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_species_insert.sql
Normal file
10
database/main/trg_requirement_check_species_insert.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_species_insert
|
||||
BEFORE INSERT ON requirement
|
||||
WHEN NEW.req_type='SPECIES'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM species WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference species.id for SPECIES')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_species_update.sql
Normal file
10
database/main/trg_requirement_check_species_update.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_species_update
|
||||
BEFORE UPDATE ON requirement
|
||||
WHEN NEW.req_type='SPECIES'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM species WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference species.id for SPECIES (UPDATE)')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_talent_insert.sql
Normal file
10
database/main/trg_requirement_check_talent_insert.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_talent_insert
|
||||
BEFORE INSERT ON requirement
|
||||
WHEN NEW.req_type='TALENT_MIN'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM talent WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference talent.id for TALENT_MIN')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_talent_update.sql
Normal file
10
database/main/trg_requirement_check_talent_update.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_talent_update
|
||||
BEFORE UPDATE ON requirement
|
||||
WHEN NEW.req_type='TALENT_MIN'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM talent WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference talent.id for TALENT_MIN (UPDATE)')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_trad_insert.sql
Normal file
10
database/main/trg_requirement_check_trad_insert.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_trad_insert
|
||||
BEFORE INSERT ON requirement
|
||||
WHEN NEW.req_type='TRADITION'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM tradition WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference tradition.id for TRADITION')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_trad_update.sql
Normal file
10
database/main/trg_requirement_check_trad_update.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_trad_update
|
||||
BEFORE UPDATE ON requirement
|
||||
WHEN NEW.req_type='TRADITION'
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM tradition WHERE id=NEW.req_id)
|
||||
THEN RAISE(ABORT,'requirement.req_id must reference tradition.id for TRADITION (UPDATE)')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_trait_insert.sql
Normal file
10
database/main/trg_requirement_check_trait_insert.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_trait_insert
|
||||
BEFORE INSERT ON requirement
|
||||
WHEN NEW.req_type IN ('TRAIT','TRAIT_LEVEL_MIN')
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM trait WHERE id = NEW.req_id)
|
||||
THEN RAISE(ABORT, 'requirement.req_id must reference trait.id for TRAIT/TRAIT_LEVEL_MIN')
|
||||
END;
|
||||
END;
|
||||
|
10
database/main/trg_requirement_check_trait_update.sql
Normal file
10
database/main/trg_requirement_check_trait_update.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
CREATE TRIGGER trg_requirement_check_trait_update
|
||||
BEFORE UPDATE ON requirement
|
||||
WHEN NEW.req_type IN ('TRAIT','TRAIT_LEVEL_MIN')
|
||||
BEGIN
|
||||
SELECT CASE
|
||||
WHEN NEW.req_id IS NULL OR NOT EXISTS (SELECT 1 FROM trait WHERE id = NEW.req_id)
|
||||
THEN RAISE(ABORT, 'requirement.req_id must reference trait.id for TRAIT/TRAIT_LEVEL_MIN (UPDATE)')
|
||||
END;
|
||||
END;
|
||||
|
7
database/main/trg_trait_conflict_order.sql
Normal file
7
database/main/trg_trait_conflict_order.sql
Normal file
@@ -0,0 +1,7 @@
|
||||
CREATE TRIGGER trg_trait_conflict_order
|
||||
BEFORE INSERT ON trait_conflict
|
||||
WHEN NEW.trait_id > NEW.incompatible_trait_id
|
||||
BEGIN
|
||||
SELECT RAISE(ABORT, 'Insert smaller id first (trait_id < incompatible_trait_id)');
|
||||
END;
|
||||
|
17
database/main/v_book_index.sql
Normal file
17
database/main/v_book_index.sql
Normal file
@@ -0,0 +1,17 @@
|
||||
CREATE VIEW v_book_index AS
|
||||
SELECT 'TRAIT' AS kind, t.name, b.code, c.page_start, c.page_end
|
||||
FROM trait t JOIN trait_citation tc ON tc.trait_id=t.id
|
||||
JOIN citation c ON c.id=tc.citation_id JOIN book b ON b.id=c.book_id
|
||||
UNION ALL
|
||||
SELECT 'SPECIES', s.name, b.code, c.page_start, c.page_end
|
||||
FROM species s JOIN species_citation sc ON sc.species_id=s.id
|
||||
JOIN citation c ON c.id=sc.citation_id JOIN book b ON b.id=c.book_id
|
||||
UNION ALL
|
||||
SELECT 'CULTURE', cu.name, b.code, c.page_start, c.page_end
|
||||
FROM culture cu JOIN culture_citation cc ON cc.culture_id=cu.id
|
||||
JOIN citation c ON c.id=cc.citation_id JOIN book b ON b.id=c.book_id
|
||||
UNION ALL
|
||||
SELECT 'PROFESSION', p.name, b.code, c.page_start, c.page_end
|
||||
FROM profession p JOIN profession_citation pc ON pc.profession_id=p.id
|
||||
JOIN citation c ON c.id=pc.citation_id JOIN book b ON b.id=c.book_id;
|
||||
|
13
database/main/v_requirement_debug.sql
Normal file
13
database/main/v_requirement_debug.sql
Normal file
@@ -0,0 +1,13 @@
|
||||
CREATE VIEW v_requirement_debug AS
|
||||
SELECT
|
||||
owner_kind,
|
||||
owner_id,
|
||||
group_no,
|
||||
CASE negate WHEN 1 THEN 'NOT ' ELSE '' END || req_type AS req_op,
|
||||
req_id,
|
||||
req_level,
|
||||
req_optokey,
|
||||
note
|
||||
FROM requirement
|
||||
ORDER BY owner_kind, owner_id, group_no, negate DESC, req_type, req_id;
|
||||
|
7
database/main/v_species_auto_traits.sql
Normal file
7
database/main/v_species_auto_traits.sql
Normal file
@@ -0,0 +1,7 @@
|
||||
CREATE VIEW v_species_auto_traits AS
|
||||
SELECT s.id AS species_id, s.name AS species,
|
||||
t.id AS trait_id, t.name AS trait, st.level, st.param_value
|
||||
FROM species s
|
||||
JOIN species_trait st ON st.species_id = s.id AND st.source = 'AUTOMATISCH'
|
||||
JOIN trait t ON t.id = st.trait_id;
|
||||
|
8
database/main/zielkategorie.sql
Normal file
8
database/main/zielkategorie.sql
Normal file
@@ -0,0 +1,8 @@
|
||||
create table zielkategorie
|
||||
(
|
||||
id INTEGER
|
||||
primary key,
|
||||
name TEXT not null
|
||||
unique
|
||||
);
|
||||
|
Reference in New Issue
Block a user