Skip to content
Snippets Groups Projects
Commit 909f3dd4 authored by srosse's avatar srosse
Browse files

OO-534: add update script for postgres, add constraint not null on owner...

OO-534: add update script for postgres, add constraint not null on owner group, fix lower case of item type
parent 4c85efff
No related branches found
No related tags found
No related merge requests found
......@@ -56,7 +56,7 @@ public class QItemTypeDAO implements ApplicationListener<ContextRefreshedEvent>
typeKeys.add(type.getType());
}
for(QuestionType defaultType:QuestionType.values()) {
if(!typeKeys.contains(defaultType.name())) {
if(!typeKeys.contains(defaultType.name().toLowerCase())) {
create(defaultType.name(), false);
}
}
......
......@@ -61,7 +61,7 @@ create table if not exists o_qp_item (
q_dir varchar(32),
q_root_filename varchar(255),
fk_taxonomy_level bigint,
fk_ownergroup bigint,
fk_ownergroup bigint not null,
primary key (id)
);
......@@ -156,7 +156,7 @@ create or replace view o_qp_item_v as (
left join o_qp_edu_context as educontext on (item.fk_edu_context = educontext.id)
);
create or replace view o_qp_item_my_v as (
create or replace view o_qp_item_author_v as (
select
item.id as item_id,
ownership.identity_id as item_author,
......
drop table o_qp_pool_2_item;
drop table o_qp_share_item;
drop table o_qp_collection_2_item;
drop table o_qp_item_collection;
drop table o_qp_pool;
drop table o_qp_item;
drop table o_qp_taxonomy_level;
drop table o_qp_edu_context;
drop table o_qp_item_type;
drop table o_qp_license;
-- question item
create table if not exists o_qp_pool (
create table o_qp_pool (
id int8 not null,
creationdate timestamp not null,
lastmodified timestamp not null,
q_name varchar(255) not null,
q_public boolean default false,
fk_ownergroup int8,
primary key (id)
);
create table o_qp_taxonomy_level (
id int8 not null,
creationdate timestamp,
lastmodified timestamp,
q_name varchar(255),
creationdate timestamp not null,
lastmodified timestamp not null,
q_field varchar(255) not null,
q_mat_path_ids varchar(1024),
q_mat_path_names varchar(2048),
fk_parent_field int8,
primary key (id)
);
create table if not exists o_qp_item (
create table o_qp_item (
id int8 not null,
creationdate timestamp,
lastmodified timestamp,
q_subject varchar(255),
q_identifier varchar(36) not null,
q_master_identifier varchar(36),
q_title varchar(1024) not null,
q_description varchar(2048),
q_keywords varchar(1024),
q_coverage varchar(1024),
q_additional_informations varchar(256),
q_language varchar(16),
fk_edu_context bigint,
q_educational_learningtime varchar(32),
fk_type bigint,
q_difficulty decimal(10,9),
q_stdev_difficulty decimal(10,9),
q_differentiation decimal(10,9),
q_num_of_answers_alt int8 not null default 0,
q_usage int8 not null default 0,
q_assessment_type varchar(64),
q_status varchar(32) not null,
q_version varchar(50),
fk_license int8,
q_editor varchar(256),
q_editor_version varchar(256),
q_format varchar(32) not null,
creationdate timestamp not null,
lastmodified timestamp not null,
q_dir varchar(32),
q_root_filename varchar(255),
fk_taxonomy_level int8,
fk_ownergroup int8 not null,
primary key (id)
);
create table if not exists o_qp_pool_2_item (
create table o_qp_pool_2_item (
id int8 not null,
creationdate timestamp,
creationdate timestamp not null,
q_editable boolean default false,
fk_pool_id int8 not null,
fk_item_id int8 not null,
primary key (id)
);
create table o_qp_share_item (
id int8 not null,
creationdate timestamp not null,
q_editable boolean default false,
fk_resource_id int8 not null,
fk_item_id int8 not null,
primary key (id)
);
create table o_qp_item_collection (
id int8 not null,
creationdate timestamp not null,
lastmodified timestamp not null,
q_name varchar(256),
fk_owner_id int8 not null,
primary key (id)
);
create table o_qp_collection_2_item (
id int8 not null,
creationdate timestamp not null,
fk_collection_id int8 not null,
fk_item_id int8 not null,
primary key (id)
);
create table o_qp_edu_context (
id int8 not null,
creationdate timestamp not null,
q_level varchar(256) not null,
q_deletable boolean default false,
primary key (id)
);
create table o_qp_item_type (
id int8 not null,
creationdate timestamp not null,
q_type varchar(256) not null,
q_deletable boolean default false,
primary key (id)
);
create table o_qp_license (
id bigint not null,
creationdate timestamp not null,
q_license varchar(256) not null,
q_text varchar(2048),
q_deletable boolean default false,
primary key (id)
);
-- views with rating
create or replace view o_qp_item_v as (
select
item.id as item_id,
item.q_identifier as item_identifier,
item.q_master_identifier as item_master_identifier,
item.q_title as item_title,
item.q_language as item_language,
taxlevel.q_field as item_taxonomy_level,
educontext.q_level as item_edu_context,
item.q_educational_learningtime as item_educational_learningtime,
itemtype.q_type as item_type,
item.q_difficulty as item_difficulty,
item.q_stdev_difficulty as item_stdev_difficulty,
item.q_differentiation as item_differentiation,
item.q_num_of_answers_alt as item_num_of_answers_alt,
item.q_usage as item_usage,
item.q_status as item_status,
item.q_format as item_format,
item.creationdate as item_creationdate,
item.lastmodified as item_lastmodified,
(select avg(rating.rating) from o_userrating as rating
where rating.resid=item.id and rating.resname='QuestionItem' and rating.ressubpath is null
) as item_rating
from o_qp_item as item
left join o_qp_taxonomy_level as taxlevel on (item.fk_taxonomy_level = taxlevel.id)
left join o_qp_item_type as itemtype on (item.fk_type = itemtype.id)
left join o_qp_edu_context as educontext on (item.fk_edu_context = educontext.id)
);
create or replace view o_qp_item_author_v as (
select
item.id as item_id,
ownership.identity_id as item_author,
item.q_identifier as item_identifier,
item.q_master_identifier as item_master_identifier,
item.q_title as item_title,
item.q_language as item_language,
taxlevel.q_field as item_taxonomy_level,
educontext.q_level as item_edu_context,
item.q_educational_learningtime as item_educational_learningtime,
itemtype.q_type as item_type,
item.q_difficulty as item_difficulty,
item.q_stdev_difficulty as item_stdev_difficulty,
item.q_differentiation as item_differentiation,
item.q_num_of_answers_alt as item_num_of_answers_alt,
item.q_usage as item_usage,
item.q_status as item_status,
item.q_format as item_format,
item.creationdate as item_creationdate,
item.lastmodified as item_lastmodified,
(select avg(rating.rating) from o_userrating as rating
where rating.resid=item.id and rating.resname='QuestionItem' and rating.ressubpath is null
) as item_rating
from o_qp_item as item
inner join o_bs_secgroup as ownergroup on (ownergroup.id = item.fk_ownergroup)
inner join o_bs_membership as ownership on (ownergroup.id = ownership.secgroup_id)
left join o_qp_taxonomy_level as taxlevel on (item.fk_taxonomy_level = taxlevel.id)
left join o_qp_item_type as itemtype on (item.fk_type = itemtype.id)
left join o_qp_edu_context as educontext on (item.fk_edu_context = educontext.id)
);
create or replace view o_qp_item_pool_v as (
select
item.id as item_id,
pool2item.q_editable as item_editable,
pool2item.fk_pool_id as item_pool,
item.q_identifier as item_identifier,
item.q_master_identifier as item_master_identifier,
item.q_title as item_title,
item.q_language as item_language,
taxlevel.q_field as item_taxonomy_level,
educontext.q_level as item_edu_context,
item.q_educational_learningtime as item_educational_learningtime,
itemtype.q_type as item_type,
item.q_difficulty as item_difficulty,
item.q_stdev_difficulty as item_stdev_difficulty,
item.q_differentiation as item_differentiation,
item.q_num_of_answers_alt as item_num_of_answers_alt,
item.q_usage as item_usage,
item.q_status as item_status,
item.q_format as item_format,
item.creationdate as item_creationdate,
item.lastmodified as item_lastmodified,
(select avg(rating.rating) from o_userrating as rating
where rating.resid=item.id and rating.resname='QuestionItem' and rating.ressubpath is null
) as item_rating
from o_qp_item as item
inner join o_qp_pool_2_item as pool2item on (pool2item.fk_item_id = item.id)
left join o_qp_taxonomy_level as taxlevel on (item.fk_taxonomy_level = taxlevel.id)
left join o_qp_item_type as itemtype on (item.fk_type = itemtype.id)
left join o_qp_edu_context as educontext on (item.fk_edu_context = educontext.id)
);
create or replace view o_qp_item_shared_v as (
select
item.id as item_id,
shareditem.q_editable as item_editable,
shareditem.fk_resource_id as item_resource_id,
item.q_identifier as item_identifier,
item.q_master_identifier as item_master_identifier,
item.q_title as item_title,
item.q_language as item_language,
taxlevel.q_field as item_taxonomy_level,
educontext.q_level as item_edu_context,
item.q_educational_learningtime as item_educational_learningtime,
itemtype.q_type as item_type,
item.q_difficulty as item_difficulty,
item.q_stdev_difficulty as item_stdev_difficulty,
item.q_differentiation as item_differentiation,
item.q_num_of_answers_alt as item_num_of_answers_alt,
item.q_usage as item_usage,
item.q_status as item_status,
item.q_format as item_format,
item.creationdate as item_creationdate,
item.lastmodified as item_lastmodified,
(select avg(rating.rating) from o_userrating as rating
where rating.resid=item.id and rating.resname='QuestionItem' and rating.ressubpath is null
) as item_rating
from o_qp_item as item
inner join o_qp_share_item as shareditem on (shareditem.fk_item_id = item.id)
left join o_qp_taxonomy_level as taxlevel on (item.fk_taxonomy_level = taxlevel.id)
left join o_qp_item_type as itemtype on (item.fk_type = itemtype.id)
left join o_qp_edu_context as educontext on (item.fk_edu_context = educontext.id)
);
alter table o_qp_pool add constraint idx_qp_pool_owner_grp_id foreign key (fk_ownergroup) references o_bs_secgroup(id);
alter table o_qp_pool_2_item add constraint idx_qp_pool_2_item_pool_id foreign key (fk_pool_id) references o_qp_pool(id);
alter table o_qp_pool_2_item add constraint idx_qp_pool_2_item_item_id foreign key (fk_item_id) references o_qp_item(id);
alter table o_qp_pool_2_item add unique (fk_pool_id, fk_item_id);
alter table o_qp_share_item add constraint idx_qp_share_rsrc_id foreign key (fk_resource_id) references o_olatresource(resource_id);
alter table o_qp_share_item add constraint idx_qp_share_item_id foreign key (fk_item_id) references o_qp_item(id);
alter table o_qp_share_item add unique (fk_resource_id, fk_item_id);
alter table o_qp_item_collection add constraint idx_qp_coll_owner_id foreign key (fk_owner_id) references o_bs_identity(id);
alter table o_qp_collection_2_item add constraint idx_qp_coll_coll_id foreign key (fk_collection_id) references o_qp_item_collection(id);
alter table o_qp_collection_2_item add constraint idx_qp_coll_item_id foreign key (fk_item_id) references o_qp_item(id);
alter table o_qp_collection_2_item add unique (fk_collection_id, fk_item_id);
alter table o_qp_item add constraint idx_qp_pool_2_field_id foreign key (fk_taxonomy_level) references o_qp_taxonomy_level(id);
alter table o_qp_item add constraint idx_qp_item_owner_id foreign key (fk_ownergroup) references o_bs_secgroup(id);
alter table o_qp_item add constraint idx_qp_item_edu_ctxt_id foreign key (fk_edu_context) references o_qp_edu_context(id);
alter table o_qp_item add constraint idx_qp_item_type_id foreign key (fk_type) references o_qp_item_type(id);
alter table o_qp_item add constraint idx_qp_item_license_id foreign key (fk_license) references o_qp_license(id);
alter table o_qp_taxonomy_level add constraint idx_qp_field_2_parent_id foreign key (fk_parent_field) references o_qp_taxonomy_level(id);
alter table o_qp_item_type add constraint cst_unique_item_type unique (q_type);
\ No newline at end of file
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment