diff --git a/src/main/java/org/olat/core/commons/persistence/_spring/databaseCorecontext.xml b/src/main/java/org/olat/core/commons/persistence/_spring/databaseCorecontext.xml index 6a74269ed6b2b0bf38be75a6485ec5eebdfdd3b7..05d9328c7bb872e4caba441dceb11c7bc66ebf87 100644 --- a/src/main/java/org/olat/core/commons/persistence/_spring/databaseCorecontext.xml +++ b/src/main/java/org/olat/core/commons/persistence/_spring/databaseCorecontext.xml @@ -95,6 +95,31 @@ </constructor-arg> <property name="addMoreProperties" ref="hibernateProps" /> </bean> + + <bean id="oracle_local_HibernateProperties" class="org.olat.core.commons.persistence.DBVendorHibernatePropertiesSimplification"> + <constructor-arg> + <props> + <prop key="hibernate.connection.driver_class">oracle.jdbc.driver.OracleDriver</prop> + <prop key="hibernate.connection.url">jdbc:oracle:thin:@${db.host}:${db.host.port}:${db.name}</prop> + <prop key="hibernate.connection.username">${db.user}</prop> + <prop key="hibernate.connection.password">${db.pass}</prop> + <prop key="hibernate.dialect">org.hibernate.dialect.Oracle10gDialect</prop> + <prop key="hibernate.default_schema">${db.default.schema}</prop> + </props> + </constructor-arg> + <property name="addMoreProperties" ref="c3p0HibernateProperties" /> + </bean> + + <bean id="oracle_jndi_HibernateProperties" class="org.olat.core.commons.persistence.DBVendorHibernatePropertiesSimplification"> + <constructor-arg> + <props> + <!-- Using datasource of hibernate --> + <prop key="hibernate.connection.datasource">${db.jndi}</prop> + <prop key="hibernate.dialect">org.hibernate.dialect.Oracle10gDialect</prop> + </props> + </constructor-arg> + <property name="addMoreProperties" ref="hibernateProps" /> + </bean> <bean id="hibernateProps" class="org.olat.core.commons.persistence.DBVendorHibernatePropertiesSimplification"> <constructor-arg> @@ -226,4 +251,17 @@ <bean id="postgresql_jndi_DataSource" class="org.springframework.jndi.JndiObjectFactoryBean" lazy-init="true"> <property name="jndiName" value="${db.jndi}"/> </bean> + + <bean id="oracle_local_DataSource" class="org.springframework.jdbc.datasource.DriverManagerDataSource" lazy-init="true"> + <property name="driverClassName"><value>oracle.jdbc.driver.OracleDriver</value></property> + <property name="url"><value>jdbc:oracle:thin:@${db.host}:${db.host.port}:${db.name}</value></property> + <property name="username" value="${db.user}" /> + <property name="password" value="${db.pass}" /> + </bean> + + <bean id="oracle_jndi_DataSource" class="org.springframework.jndi.JndiObjectFactoryBean" lazy-init="true"> + <property name="jndiName" value="${db.jndi}"/> + </bean> + + </beans> \ No newline at end of file diff --git a/src/main/java/org/olat/course/statistic/_spring/statisticContext.xml b/src/main/java/org/olat/course/statistic/_spring/statisticContext.xml index 0dc4f6fd09cdd7a1d4442cf67f11ad3fafc8cb04..d4b9e0b72d0c77ffc7d9bde844efda3ed1a8f987 100644 --- a/src/main/java/org/olat/course/statistic/_spring/statisticContext.xml +++ b/src/main/java/org/olat/course/statistic/_spring/statisticContext.xml @@ -520,7 +520,149 @@ </list> </property> </bean> - + + <bean id="statisticUpdateConfig_oracle" class="org.olat.course.statistic.StatisticUpdateConfig"> + <property name="updaters"> + <list> + <bean class="org.olat.course.statistic.StatisticUpdater" id="LastUpdatedUpdater_oracle"> + <property name="loggingName" value="LastUpdatedUpdater_oracle"/> + <property name="jdbcTemplate" ref="statisticsMysqlJdbcTemplate" /> + <property name="updateSQL"> + <list> + <value> + update o_stat_lastupdated set from_datetime = until_datetime + </value> + <value> + update o_stat_lastupdated set until_datetime = (select sysdate - (5/(24*60)) from dual) + </value> + </list> + </property> + <property name="deleteSQL"> + <list> + <value> + update o_stat_lastupdated set until_datetime = to_date('19900101', 'YYYYmmdd') + </value> + </list> + </property> + </bean> + + <bean class="org.olat.course.statistic.StatisticUpdater" > + <property name="loggingName" value="StatTempTableCreator_oracle"/> + <property name="jdbcTemplate" ref="statisticsMysqlJdbcTemplate" /> + <property name="updateSQL"> + <list> + <value> + <![CDATA[ + create table o_stat_temptable as + select creationdate, businesspath, userproperty2, userproperty4, userproperty10, userproperty3, + to_number(substr(businesspath, instr(businesspath, ':') + 1, instr(businesspath, ']') - instr(businesspath, ':') - 1)) resid + from o_loggingtable + where actionverb='launch' and actionobject='node' and businesspath is not null + and creationdate >= (select from_datetime from o_stat_lastupdated) + and creationdate < (select until_datetime from o_stat_lastupdated) + ]]> + </value> + </list> + </property> + </bean> + + <bean class="org.olat.course.statistic.StatisticUpdater"> + <property name="loggingName" value="DailyStatisticUpdater"/> + <property name="jdbcTemplate" ref="statisticsMysqlJdbcTemplate" /> + <property name="updateSQL"> + <list> + <value> + merge into o_stat_daily old + using (select businesspath, resid, to_date(to_char(creationdate, 'YYYY-MM-DD'), 'YYYY-MM-DD') day, count (*) cnt + from o_stat_temptable + group by businesspath, resid, to_date(to_char(creationdate, 'YYYY-MM-DD'), 'YYYY-MM-DD') ) delta + on (old.businesspath = delta.businesspath AND old.day = delta.day) + when matched then + update set old.value=old.value+delta.cnt + when not matched then + insert (old.businesspath, old.resid, old.day, old.value) + values (delta.businesspath, delta.resid, delta.day, delta.cnt) + </value> + </list> + </property> + <property name="deleteSQL" value="truncate table o_stat_daily"/> + </bean> + + <bean class="org.olat.course.statistic.StatisticUpdater" > + <property name="loggingName" value="WeeklyStatisticUpdater"/> + <property name="jdbcTemplate" ref="statisticsMysqlJdbcTemplate" /> + <property name="updateSQL"> + <list> + <value> + merge into o_stat_weekly old + using (select businesspath, resid, to_char(creationdate, 'IYYY') || '-' || to_char(creationdate, 'IW') week, count (*) cnt + from o_stat_temptable + group by businesspath, resid, to_char(creationdate, 'IYYY') || '-' || to_char(creationdate, 'IW') ) delta + on (old.businesspath = delta.businesspath AND old.week = delta.week) + when matched then + update set old.value=old.value+delta.cnt + when not matched then + insert (old.businesspath, old.resid, old.week, old.value) + values (delta.businesspath, delta.resid, delta.week, delta.cnt) + </value> + </list> + </property> + <property name="deleteSQL" value="truncate table o_stat_weekly"/> + </bean> + + <bean class="org.olat.course.statistic.StatisticUpdater"> + <property name="loggingName" value="DayOfWeekStatisticUpdater"/> + <property name="jdbcTemplate" ref="statisticsMysqlJdbcTemplate" /> + <property name="updateSQL"> + <list> + <value> + merge into o_stat_dayofweek old + using (select businesspath, resid, to_char(creationdate, 'D') day, count (*) cnt + from o_stat_temptable + group by businesspath, resid, to_char(creationdate, 'D') ) delta + on (old.businesspath = delta.businesspath AND old.day = delta.day) + when matched then + update set old.value=old.value+delta.cnt + when not matched then + insert (old.businesspath, old.resid, old.day, old.value) + values (delta.businesspath, delta.resid, delta.day, delta.cnt) + </value> + </list> + </property> + <property name="deleteSQL" value="truncate table o_stat_dayofweek"/> + </bean> + + <bean class="org.olat.course.statistic.StatisticUpdater" > + <property name="loggingName" value="HourOfDayStatisticUpdater"/> + <property name="jdbcTemplate" ref="statisticsMysqlJdbcTemplate" /> + <property name="updateSQL"> + <list> + <value> + merge into o_stat_hourofday old + using (select businesspath, resid, to_char(creationdate, 'HH24') hour, count (*) cnt + from o_stat_temptable + group by businesspath, resid, to_char(creationdate, 'HH24') ) delta + on (old.businesspath = delta.businesspath AND old.hour = delta.hour) + when matched then + update set old.value=old.value+delta.cnt + when not matched then + insert (old.businesspath, old.resid, old.hour, old.value) + values (delta.businesspath, delta.resid, delta.hour, delta.cnt) + </value> + </list> + </property> + <property name="deleteSQL" value="truncate table o_stat_hourofday"/> + </bean> + + <bean class="org.olat.course.statistic.StatisticUpdater" id="StatTempTableDropper_common"> + <property name="loggingName" value="StatTempTableDropper_common"/> + <property name="jdbcTemplate" ref="statisticsMysqlJdbcTemplate" /> + <property name="updateSQL" value="drop table o_stat_temptable PURGE" /> + </bean> + </list> + </property> + </bean> + <bean id="org.olat.course.statistic.StatisticUpdateManager" class="org.olat.course.statistic.StatisticUpdateManagerImpl" > <constructor-arg> <ref bean="coordinatorManager"/> @@ -543,6 +685,9 @@ <entry key="postgresql"> <value>select round(date_part('epoch', creationdate)) from o_loggingtable limit 1;</value> </entry> + <entry key="oracle"> + <value>select round((creationdate - TO_DATE('19700101000000','YYYYMMDDHH24MISS'))*86400) from o_loggingtable where rownum=1</value> + </entry> </map> </constructor-arg> <constructor-arg value="${db.vendor}"/> diff --git a/src/main/resources/database/oracle/alter_8_1_x_to_8_2_0.sql b/src/main/resources/database/oracle/alter_8_1_x_to_8_2_0.sql new file mode 100644 index 0000000000000000000000000000000000000000..05cd9ed2c7c1d417a44a0ea264adc2e438da6a21 --- /dev/null +++ b/src/main/resources/database/oracle/alter_8_1_x_to_8_2_0.sql @@ -0,0 +1,252 @@ +-- relation groups to resources +create table o_gp_business_to_resource ( + g_id number(20) not null, + version number(20) not null, + creationdate date, + fk_resource number(20) not null, + fk_group number(20) not null, + primary key (g_id) +); +alter table o_gp_business_to_resource add constraint idx_bgp_to_rsrc_rsrc foreign key (fk_resource) references o_olatresource (resource_id); +alter table o_gp_business_to_resource add constraint idx_bgp_to_rsrc_group foreign key (fk_group) references o_gp_business (group_id); + +-- groups +alter table o_gp_business add fk_resource number(20) unique; +alter table o_gp_business add constraint idx_bgp_rsrc foreign key (fk_resource) references o_olatresource (resource_id); + + +-- area +alter table o_gp_bgarea modify groupcontext_fk number(20) null; +alter table o_gp_bgarea add fk_resource number(20); +alter table o_gp_bgarea add constraint idx_area_to_resource foreign key (fk_resource) references o_olatresource (resource_id); + +-- view +create or replace view o_gp_business_to_repository_v as ( + select + grp.group_id as grp_id, + repoentry.repositoryentry_id as re_id, + repoentry.displayname as re_displayname + from o_gp_business grp + inner join o_gp_business_to_resource relation on (relation.fk_group = grp.group_id) + inner join o_repositoryentry repoentry on (repoentry.fk_olatresource = relation.fk_resource) +); + +create or replace view o_re_member_v as ( + select + re.repositoryentry_id as re_id, + re.membersonly as re_membersonly, + re.accesscode as re_accesscode, + re_part_member.identity_id as re_part_member_id, + re_tutor_member.identity_id as re_tutor_member_id, + re_owner_member.identity_id as re_owner_member_id, + bg_part_member.identity_id as bg_part_member_id, + bg_owner_member.identity_id as bg_owner_member_id + from o_repositoryentry re + left join o_bs_membership re_part_member on (re_part_member.secgroup_id = re.fk_participantgroup) + left join o_bs_membership re_tutor_member on (re_tutor_member.secgroup_id = re.fk_tutorgroup) + left join o_bs_membership re_owner_member on (re_owner_member.secgroup_id = re.fk_ownergroup) + left join o_gp_business_to_resource bgroup_rel on (bgroup_rel.fk_resource = re.fk_olatresource) + left join o_gp_business bgroup on (bgroup.group_id = bgroup_rel.fk_group) + left join o_bs_membership bg_part_member on (bg_part_member.secgroup_id = bgroup.fk_partipiciantgroup) + left join o_bs_membership bg_owner_member on (bg_owner_member.secgroup_id = bgroup.fk_ownergroup) +); + +create or replace view o_re_strict_member_v as ( + select + re.repositoryentry_id as re_id, + re_part_member.identity_id as re_part_member_id, + re_tutor_member.identity_id as re_tutor_member_id, + re_owner_member.identity_id as re_owner_member_id, + bg_part_member.identity_id as bg_part_member_id, + bg_owner_member.identity_id as bg_owner_member_id + from o_repositoryentry re + left join o_bs_membership re_part_member on (re_part_member.secgroup_id = re.fk_participantgroup) + left join o_bs_membership re_tutor_member on (re_tutor_member.secgroup_id = re.fk_tutorgroup) + left join o_bs_membership re_owner_member on (re_owner_member.secgroup_id = re.fk_ownergroup) + left join o_gp_business_to_resource bgroup_rel on (bgroup_rel.fk_resource = re.fk_olatresource) + left join o_gp_business bgroup on (bgroup.group_id = bgroup_rel.fk_group) + left join o_bs_membership bg_part_member on (bg_part_member.secgroup_id = bgroup.fk_partipiciantgroup) + left join o_bs_membership bg_owner_member on (bg_owner_member.secgroup_id = bgroup.fk_ownergroup) + where re.membersonly=1 and re.accesscode=1 +); + +create or replace view o_re_strict_participant_v as ( + select + re.repositoryentry_id as re_id, + re_part_member.identity_id as re_part_member_id, + bg_part_member.identity_id as bg_part_member_id + from o_repositoryentry re + left join o_bs_membership re_part_member on (re_part_member.secgroup_id = re.fk_participantgroup) + left join o_gp_business_to_resource bgroup_rel on (bgroup_rel.fk_resource = re.fk_olatresource) + left join o_gp_business bgroup on (bgroup.group_id = bgroup_rel.fk_group) + left join o_bs_membership bg_part_member on (bg_part_member.secgroup_id = bgroup.fk_partipiciantgroup) + where (re.membersonly=1 and re.accesscode=1) or re.accesscode>=3 +); + +create or replace view o_re_strict_tutor_v as ( + select + re.repositoryentry_id as re_id, + re_tutor_member.identity_id as re_tutor_member_id, + re_owner_member.identity_id as re_owner_member_id, + bg_owner_member.identity_id as bg_owner_member_id + from o_repositoryentry re + left join o_bs_membership re_tutor_member on (re_tutor_member.secgroup_id = re.fk_tutorgroup) + left join o_bs_membership re_owner_member on (re_owner_member.secgroup_id = re.fk_ownergroup) + left join o_gp_business_to_resource bgroup_rel on (bgroup_rel.fk_resource = re.fk_olatresource) + left join o_gp_business bgroup on (bgroup.group_id = bgroup_rel.fk_group) + left join o_bs_membership bg_owner_member on (bg_owner_member.secgroup_id = bgroup.fk_ownergroup) + where (re.membersonly=1 and re.accesscode=1) or re.accesscode>=3 +); + +create or replace view o_re_membership_v as ( + select + membership.id as membership_id, + membership.identity_id as identity_id, + membership.lastmodified as lastmodified, + membership.creationdate as creationdate, + re_owner_member.repositoryentry_id as owner_re_id, + re_owner_member.fk_olatresource as owner_ores_id, + re_tutor_member.repositoryentry_id as tutor_re_id, + re_tutor_member.fk_olatresource as tutor_ores_id, + re_part_member.repositoryentry_id as participant_re_id, + re_part_member.fk_olatresource as participant_ores_id + from o_bs_membership membership + left join o_repositoryentry re_part_member on (membership.secgroup_id = re_part_member.fk_participantgroup) + left join o_repositoryentry re_tutor_member on (membership.secgroup_id = re_tutor_member.fk_tutorgroup) + left join o_repositoryentry re_owner_member on (membership.secgroup_id = re_owner_member.fk_ownergroup) +); + +create or replace view o_bs_gp_membership_v as ( + select + membership.id as membership_id, + membership.identity_id as identity_id, + membership.lastmodified as lastmodified, + membership.creationdate as creationdate, + owned_gp.group_id as owned_gp_id, + participant_gp.group_id as participant_gp_id, + waiting_gp.group_id as waiting_gp_id + from o_bs_membership membership + left join o_gp_business owned_gp on (membership.secgroup_id = owned_gp.fk_ownergroup) + left join o_gp_business participant_gp on (membership.secgroup_id = participant_gp.fk_partipiciantgroup) + left join o_gp_business waiting_gp on (membership.secgroup_id = waiting_gp.fk_waitinggroup) + where (owned_gp.group_id is not null or participant_gp.group_id is not null or waiting_gp.group_id is not null) +); + +create or replace view o_gp_business_v as ( + select + gp.group_id as group_id, + gp.groupname as groupname, + gp.lastmodified as lastmodified, + gp.creationdate as creationdate, + gp.lastusage as lastusage, + gp.descr as descr, + gp.minparticipants as minparticipants, + gp.maxparticipants as maxparticipants, + gp.waitinglist_enabled as waitinglist_enabled, + gp.autocloseranks_enabled as autocloseranks_enabled, + (select count(part.id) from o_bs_membership part where part.secgroup_id = gp.fk_partipiciantgroup) as num_of_participants, + (select count(own.id) from o_bs_membership own where own.secgroup_id = gp.fk_ownergroup) as num_of_owners, + (case when gp.waitinglist_enabled = 1 + then + (select count(waiting.id) from o_bs_membership waiting where waiting.secgroup_id = gp.fk_partipiciantgroup) + else + 0 + end) as num_waiting, + (select count(offer.offer_id) from o_ac_offer offer + where offer.fk_resource_id = gp.fk_resource + and offer.is_valid=1 + and (offer.validfrom is null or offer.validfrom >= current_date) + and (offer.validto is null or offer.validto <= current_date) + ) as num_of_valid_offers, + (select count(offer.offer_id) from o_ac_offer offer + where offer.fk_resource_id = gp.fk_resource + and offer.is_valid=1 + ) as num_of_offers, + (select count(relation.fk_resource) from o_gp_business_to_resource relation + where relation.fk_group = gp.group_id + ) as num_of_relations, + gp.fk_resource as fk_resource, + gp.fk_ownergroup as fk_ownergroup, + gp.fk_partipiciantgroup as fk_partipiciantgroup, + gp.fk_waitinggroup as fk_waitinggroup + from o_gp_business gp +); + +-- add paypal transactions +create table o_ac_paypal_transaction ( + transaction_id number(20) not null, + version number(20) not null, + creationdate date, + ref_no varchar(255 char), + order_id number(20) not null, + order_part_id number(20) not null, + method_id number(20) not null, + success_uuid varchar(32 char) not null, + cancel_uuid varchar(32 char) not null, + amount_amount DECIMAL, + amount_currency_code VARCHAR(3 char), + pay_response_date date, + pay_key varchar(255 char), + ack varchar(255 char), + build varchar(255 char), + coorelation_id varchar(255 char), + payment_exec_status varchar(255 char), + ipn_transaction_id varchar(255 char), + ipn_transaction_status varchar(255 char), + ipn_sender_transaction_id varchar(255 char), + ipn_sender_transaction_status varchar(255 char), + ipn_sender_email varchar(255 char), + ipn_verify_sign varchar(255 char), + ipn_pending_reason varchar(255 char), + trx_status VARCHAR(32 char) default 'NEW' not null, + trx_amount NUMBER (21,20), + trx_currency_code VARCHAR(3 char), + primary key (transaction_id) +); +create index paypal_pay_key_idx on o_ac_paypal_transaction (pay_key); +create index paypal_pay_trx_id_idx on o_ac_paypal_transaction (ipn_transaction_id); +create index paypal_pay_s_trx_id_idx on o_ac_paypal_transaction (ipn_sender_transaction_id); + +create table o_ac_reservation ( + reservation_id number(20) NOT NULL, + creationdate date, + lastmodified date, + version number(20) not null, + fk_identity number(20) not null, + fk_resource number(20) not null, + primary key (reservation_id) +); + +-- course db +create table o_co_db_entry ( + id number(20) not null, + version number(20) not null, + lastmodified date, + creationdate date, + courseid number(20), + identity number(20), + category varchar(32 char), + name varchar(255 char) not null, + floatvalue float, + longvalue number(20), + stringvalue varchar(255 char), + textvalue varchar2(4000 char), + primary key (id) +); +create index o_co_db_course_idx on o_co_db_entry (courseid); +create index o_co_db_cat_idx on o_co_db_entry (category); +create index o_co_db_name_idx on o_co_db_entry (name); +alter table o_co_db_entry add constraint FKB60B1BA5F7E870XY foreign key (identity) references o_bs_identity; + +-- add mapper table +create table o_mapper ( + id number(20) not null, + lastmodified date, + creationdate date, + mapper_uuid varchar(64 char), + orig_session_id varchar(32 char), + xml_config varchar(4000 char), + primary key (id) +); +create index o_mapper_uuid_idx on o_mapper (mapper_uuid); + diff --git a/src/main/resources/database/oracle/setupDatabase.sql b/src/main/resources/database/oracle/setupDatabase.sql index 3bde942d16ebc1f5d0c17c113aa5e118386afc73..99f3eded5aad8ce651ab3ff21e04ba839a5f9d6e 100644 --- a/src/main/resources/database/oracle/setupDatabase.sql +++ b/src/main/resources/database/oracle/setupDatabase.sql @@ -69,12 +69,14 @@ CREATE TABLE o_gp_business ( waitinglist_enabled number, autocloseranks_enabled number, groupcontext_fk number(20), + fk_resource number(20), fk_ownergroup number(20), fk_partipiciantgroup number(20), fk_waitinggroup number(20), CONSTRAINT u_o_gp_business UNIQUE (fk_ownergroup), CONSTRAINT u_o_gp_business01 UNIQUE (fk_partipiciantgroup), CONSTRAINT u_o_gp_business02 UNIQUE (fk_waitinggroup), + CONSTRAINT u_o_gp_business03 UNIQUE (fk_resource), PRIMARY KEY (group_id) ); @@ -288,6 +290,7 @@ CREATE TABLE o_user ( language varchar2(10 char), fontsize varchar2(10 char), notification_interval varchar2(16 char), + receiverealmail varchar2(16 char), presencemessagespublic number, informsessiontimeout number NOT NULL, PRIMARY KEY (user_id) @@ -399,8 +402,10 @@ CREATE TABLE o_bs_policy ( oresource_id number(20) NOT NULL, group_id number(20) NOT NULL, permission varchar2(16 char) NOT NULL, - PRIMARY KEY (id), - CONSTRAINT u_o_bs_policy UNIQUE (oresource_id, group_id, permission) + apply_from date, + apply_to date, + CONSTRAINT u_o_bs_policy UNIQUE (oresource_id, group_id, permission), + PRIMARY KEY (id) ); -- @@ -413,10 +418,24 @@ CREATE TABLE o_gp_bgarea ( creationdate date, name varchar2(255 char) NOT NULL, descr varchar2(4000), - groupcontext_fk number(20) NOT NULL, + groupcontext_fk number(20), + fk_resource number(20), PRIMARY KEY (area_id) ); +-- +-- Table: o_gp_business_to_resource +--; + +create table o_gp_business_to_resource ( + g_id number(20) not null, + version number(20) not null, + creationdate date, + fk_resource number(20) not null, + fk_group number(20) not null, + primary key (g_id) +); + -- -- Table: o_repositoryentry --; @@ -432,9 +451,12 @@ CREATE TABLE o_repositoryentry ( resourcename varchar2(100 char) NOT NULL, fk_olatresource number(20), fk_ownergroup number(20), + fk_tutorgroup number(20), + fk_participantgroup number(20), description varchar2(4000), initialauthor varchar2(128 char) NOT NULL, accesscode number(11) NOT NULL, + membersonly number default 0, statuscode number(11), canlaunch number NOT NULL, candownload number NOT NULL, @@ -531,6 +553,9 @@ CREATE TABLE oc_lock ( CONSTRAINT u_oc_lock UNIQUE (asset), PRIMARY KEY (lock_id) ); +--create index ocl_asset_idx on oc_lock (asset); +create index FK9E30F4B66115906D on oc_lock (identity_fk); +alter table oc_lock add constraint FK9E30F4B66115906D foreign key (identity_fk) references o_bs_identity (id); -- -- Table: o_readmessage @@ -617,6 +642,7 @@ CREATE TABLE o_checkpoint ( checklist_fk number(20), PRIMARY KEY (checkpoint_id) ); +alter table o_checkpoint add constraint FK9E30F4B661159ZZZ foreign key (checklist_fk) references o_checklist (checklist_id); -- -- Table: o_checkpoint_results @@ -729,9 +755,394 @@ CREATE TABLE o_info_message ( ); -- --- Table: o_stat_dayofweek +-- Table: o_ep_artefact +--; + +create table o_ep_artefact ( + artefact_id number(20) not null, + artefact_type varchar(32 char) not null, + version number(20) not null, + creationdate date, + collection_date date, + title varchar(512 char), + description varchar(4000 char), + signature number(20) default 0, + businesspath varchar(2048 char), + fulltextcontent clob, + reflexion clob, + source varchar(2048 char), + add_prop1 varchar(2048 char), + add_prop2 varchar(2048 char), + add_prop3 varchar(2048 char), + fk_struct_el_id number(20), + fk_artefact_auth_id number(20) not null, + primary key (artefact_id) +); + +-- +-- Table: o_ep_collect_restriction +--; + +create table o_ep_collect_restriction ( + collect_id number(20) not null, + version number(20) not null, + creationdate date, + artefact_type varchar(256 char), + amount number(20) default -1, + restriction varchar(32 char), + pos number(20) default 0, + fk_struct_el_id number(20), + primary key (collect_id) +); + +-- +-- Table: o_ep_struct_el +--; + +create table o_ep_struct_el ( + structure_id number(20) not null, + structure_type varchar(32 char) not null, + version number(20) not null, + creationdate date, + returndate date, + copydate date, + lastsyncheddate date, + deadline date, + title varchar(512 char), + description varchar(2048 char), + struct_el_source number(20), + target_resname varchar(50 char), + target_resid number(20), + target_ressubpath varchar(2048 char), + target_businesspath varchar(2048 char), + style varchar(128 char), + status varchar(32 char), + viewmode varchar(32 char), + fk_struct_root_id number(20), + fk_struct_root_map_id number(20), + fk_map_source_id number(20), + fk_ownergroup number(20), + fk_olatresource number(20) not null, + primary key (structure_id) +); + +-- +-- Table: o_ep_struct_struct_link +--; + +create table o_ep_struct_struct_link ( + link_id number(20) not null, + version number(20) not null, + creationdate date, + pos number(20) default 0, + fk_struct_parent_id number(20) not null, + fk_struct_child_id number(20) not null, + primary key (link_id) +); + +-- +-- Table: o_ep_struct_artefact_link --; +create table o_ep_struct_artefact_link ( + link_id number(20) not null, + version number(20) not null, + creationdate date, + pos number(20) default 0, + reflexion clob, + fk_auth_id number(20), + fk_struct_id number(20) not null, + fk_artefact_id number(20) not null, + primary key (link_id) +); + +-- +-- Table: o_bs_invitation +--; + +create table o_bs_invitation ( + id number(20) not null, + version number(20) not null, + creationdate date, + token varchar(64 char) not null, + first_name varchar(64 char), + last_name varchar(64 char), + mail varchar(128 char), + fk_secgroup number(20), + primary key (id) +); + +-- +-- Table: o_tag +--; + +create table o_tag ( + tag_id number(20) not null, + version number(20) not null, + creationdate date, + tag varchar(128 char) not null, + resname varchar(50 char) not null, + resid number(20) not null, + ressubpath varchar(2048 char), + businesspath varchar(2048 char), + fk_author_id number(20) not null, + primary key (tag_id) +); + +-- +-- Table: o_mail +--; + +create table o_mail ( + mail_id number(20) not null, + meta_mail_id varchar(64 char), + creationdate date, + lastmodified date, + resname varchar(50 char), + resid number(20), + ressubpath varchar(2048 char), + businesspath varchar(2048 char), + subject varchar(512 char), + body clob, + fk_from_id number(20), + primary key (mail_id) +); + +-- +-- Table: o_mail_to_recipient +--; + +create table o_mail_to_recipient ( + pos number(20) default 0, + fk_mail_id number(20), + fk_recipient_id number(20) +); + +-- +-- Table: o_mail_recipient +--; + +create table o_mail_recipient ( + recipient_id number(20) NOT NULL, + recipientvisible number, + deleted number, + mailread number, + mailmarked number, + email varchar(255 char), + recipientgroup varchar(255 char), + creationdate date, + fk_recipient_id number(20), + primary key (recipient_id) +); + +-- +-- Table: o_mail_attachment +--; + +create table o_mail_attachment ( + attachment_id number(20) NOT NULL, + creationdate date, + datas blob, + datas_size number(20), + datas_name varchar(255 char), + mimetype varchar(255 char), + fk_att_mail_id number(20), + primary key (attachment_id) +); + +-- +-- Table: o_ac_offer +--; + +create table o_ac_offer ( + offer_id number(20) NOT NULL, + creationdate date, + lastmodified date, + is_valid number default 1, + validfrom date, + validto date, + version number(20) not null, + resourceid number(20), + resourcetypename varchar(255 char), + resourcedisplayname varchar(255 char), + token varchar(255 char), + price_amount number(20,2), + price_currency_code VARCHAR(3 char), + offer_desc VARCHAR(2000 char), + fk_resource_id number(20), + primary key (offer_id) +); + +-- +-- Table: o_ac_method +--; + +create table o_ac_method ( + method_id number(20) NOT NULL, + access_method varchar(32 char), + version number(20) not null, + creationdate date, + lastmodified date, + is_valid number default 1, + is_enabled number default 1, + validfrom date, + validto date, + primary key (method_id) +); + +-- +-- Table: o_ac_offer_access +--; + +create table o_ac_offer_access ( + offer_method_id number(20) NOT NULL, + version number(20) not null, + creationdate date, + is_valid number default 1, + validfrom date, + validto date, + fk_offer_id number(20), + fk_method_id number(20), + primary key (offer_method_id) +); + +-- +-- Table: o_ac_order +--; + +create table o_ac_order ( + order_id number(20) NOT NULL, + version number(20) not null, + creationdate date, + lastmodified date, + is_valid number default 1, + total_lines_amount number(20,2), + total_lines_currency_code VARCHAR(3 char), + total_amount number(20,2), + total_currency_code VARCHAR(3 char), + discount_amount number(20,2), + discount_currency_code VARCHAR(3 char), + order_status VARCHAR(32 char) default 'NEW', + fk_delivery_id number(20), + primary key (order_id) +); + +-- +-- Table: o_ac_order_part +--; + +create table o_ac_order_part ( + order_part_id number(20) NOT NULL, + version number(20) not null, + pos number(20), + creationdate date, + total_lines_amount number(20,2), + total_lines_currency_code VARCHAR(3 char), + total_amount number(20,2), + total_currency_code VARCHAR(3 char), + fk_order_id number(20), + primary key (order_part_id) +); + +-- +-- Table: o_ac_order_line +--; + +create table o_ac_order_line ( + order_item_id number(20) NOT NULL, + version number(20) not null, + pos number(20), + creationdate date, + unit_price_amount number(20,2), + unit_price_currency_code VARCHAR(3 char), + total_amount number(20,2), + total_currency_code VARCHAR(3 char), + fk_order_part_id number(20), + fk_offer_id number(20), + primary key (order_item_id) +); + +-- +-- Table: o_ac_transaction +--; + +create table o_ac_transaction ( + transaction_id number(20) NOT NULL, + version number(20) not null, + creationdate date, + trx_status VARCHAR(32 char) default 'NEW', + amount_amount number(20,2), + amount_currency_code VARCHAR(3 char), + fk_order_part_id number(20), + fk_order_id number(20), + fk_method_id number(20), + primary key (transaction_id) +); + +-- +-- Table: o_ac_reservation +--; + +create table o_ac_reservation ( + reservation_id number(20) NOT NULL, + creationdate date, + lastmodified date, + version number(20) not null, + fk_identity number(20) not null, + fk_resource number(20) not null, + primary key (reservation_id) +); + +-- +-- Table: o_ac_paypal_transaction +--; + +create table o_ac_paypal_transaction ( + transaction_id number(20) not null, + version number(20) not null, + creationdate date, + ref_no varchar(255 char), + order_id number(20) not null, + order_part_id number(20) not null, + method_id number(20) not null, + success_uuid varchar(32 char) not null, + cancel_uuid varchar(32 char) not null, + amount_amount DECIMAL, + amount_currency_code VARCHAR(3 char), + pay_response_date date, + pay_key varchar(255 char), + ack varchar(255 char), + build varchar(255 char), + coorelation_id varchar(255 char), + payment_exec_status varchar(255 char), + ipn_transaction_id varchar(255 char), + ipn_transaction_status varchar(255 char), + ipn_sender_transaction_id varchar(255 char), + ipn_sender_transaction_status varchar(255 char), + ipn_sender_email varchar(255 char), + ipn_verify_sign varchar(255 char), + ipn_pending_reason varchar(255 char), + trx_status VARCHAR(32 char) default 'NEW' not null, + trx_amount NUMBER (21,20), + trx_currency_code VARCHAR(3 char), + primary key (transaction_id) +); + +-- +-- Table: o_stat_lastupdated +--; + +create table o_stat_lastupdated ( + lastupdated date not null, + from_datetime date not null, + until_datetime date not null +); +-- important: initialize with old date! +insert into o_stat_lastupdated values(to_date('1999-01-01'), to_date('1999-01-01'), to_date('1999-01-01')); + +-- +-- Table: o_stat_dayofweek +--; CREATE SEQUENCE sq_o_stat_dayofweek_id; CREATE TABLE o_stat_dayofweek ( @@ -848,6 +1259,356 @@ CREATE TABLE o_stat_studybranch3 ( PRIMARY KEY (id) ); +-- +-- Table: o_mark +--; + +create table o_mark ( + mark_id number(20) not null, + version number(20) not null, + creationdate date, + resname varchar(50 char) not null, + resid number(20) not null, + ressubpath varchar(2048 char), + businesspath varchar(2048 char), + creator_id number(20) not null, + primary key (mark_id) +); + +-- +-- Table: o_as_eff_statement +--; + +create table o_as_eff_statement ( + id number(20) not null, + version number(20) not null, + lastmodified date, + creationdate date, + passed number, + score float(4), + total_nodes number(20), + attempted_nodes number(20), + passed_nodes number(20), + course_title varchar(255 char), + course_short_title varchar(128 char), + course_repo_key number(20), + statement_xml clob, + fk_identity number(20), + fk_resource_id number(20), + CONSTRAINT u_o_as_eff_statement UNIQUE (fk_identity, fk_resource_id), + primary key (id) +); + +-- +-- Table: o_as_user_course_infos +--; + +create table o_as_user_course_infos ( + id number(20) not null, + version number(20) not null, + creationdate date, + lastmodified date, + initiallaunchdate date, + recentlaunchdate date, + visit number(20), + timespend number(20), + fk_identity number(20), + fk_resource_id number(20), + CONSTRAINT u_o_as_user_course_infos UNIQUE (fk_identity, fk_resource_id), + primary key (id) +); + +-- +-- Table: o_mapper +--; + +create table o_mapper ( + id number(20) not null, + lastmodified date, + creationdate date, + mapper_uuid varchar(64 char), + orig_session_id varchar(32 char), + xml_config varchar(4000 char), + primary key (id) +); + +-- +-- Table: o_co_db_entry +--; + +create table o_co_db_entry ( + id number(20) not null, + version number(20) not null, + lastmodified date, + creationdate date, + courseid number(20), + identity number(20), + category varchar(32 char), + name varchar(255 char) not null, + floatvalue float, + longvalue number(20), + stringvalue varchar(255 char), + textvalue varchar2(4000 char), + primary key (id) +); + +-- user view +create view o_bs_identity_short_v as ( + select + ident.id as id_id, + ident.name as id_name, + ident.lastlogin as id_lastlogin, + ident.status as id_status, + us.user_id as us_id, + p_firstname.propvalue as first_name, + p_lastname.propvalue as last_name, + p_email.propvalue as email + from o_bs_identity ident + inner join o_user us on (ident.fk_user_id = us.user_id) + left join o_userproperty p_firstname on (us.user_id = p_firstname.fk_user_id and p_firstname.propName = 'firstName') + left join o_userproperty p_lastname on (us.user_id = p_lastname.fk_user_id and p_lastname.propName = 'lastName') + left join o_userproperty p_email on (us.user_id = p_email.fk_user_id and p_email.propName = 'email') +); + +-- assessment results +-- help view +create view o_gp_contextresource_2_group_v as ( + select + cg_bg2resource.groupcontextresource_id as groupcontextresource_id, + cg_bgcontext.groupcontext_id as groupcontext_id, + cg_bgroup.group_id as group_id, + cg_bg2resource.oresource_id as oresource_id, + cg_bgcontext.grouptype as grouptype, + cg_bgcontext.defaultcontext as defaultcontext, + cg_bgroup.groupname as groupname, + cg_bgroup.fk_ownergroup as fk_ownergroup, + cg_bgroup.fk_partipiciantgroup as fk_partipiciantgroup, + cg_bgroup.fk_waitinggroup as fk_waitinggroup + from o_gp_bgcontextresource_rel cg_bg2resource + inner join o_gp_bgcontext cg_bgcontext on (cg_bg2resource.groupcontext_fk = cg_bgcontext.groupcontext_id) + inner join o_gp_business cg_bgroup on (cg_bg2resource.groupcontext_fk = cg_bgroup.groupcontext_fk) +); + +-- eportfolio views +create or replace view o_ep_notifications_struct_v as ( + select + struct.structure_id as struct_id, + struct.structure_type as struct_type, + struct.title as struct_title, + struct.fk_struct_root_id as struct_root_id, + struct.fk_struct_root_map_id as struct_root_map_id, + (case when struct.structure_type = 'page' then struct.structure_id else parent_struct.structure_id end) as page_key, + struct_link.creationdate as creation_date + from o_ep_struct_el struct + inner join o_ep_struct_struct_link struct_link on (struct_link.fk_struct_child_id = struct.structure_id) + inner join o_ep_struct_el parent_struct on (struct_link.fk_struct_parent_id = parent_struct.structure_id) + where struct.structure_type = 'page' or parent_struct.structure_type = 'page' +); + +create or replace view o_ep_notifications_art_v as ( + select + artefact.artefact_id as artefact_id, + artefact_link.link_id as link_id, + artefact.title as artefact_title, + (case when struct.structure_type = 'page' then struct.title else root_struct.title end ) as struct_title, + struct.structure_type as struct_type, + struct.structure_id as struct_id, + root_struct.structure_id as struct_root_id, + root_struct.structure_type as struct_root_type, + struct.fk_struct_root_map_id as struct_root_map_id, + (case when struct.structure_type = 'page' then struct.structure_id else root_struct.structure_id end ) as page_key, + artefact_link.fk_auth_id as author_id, + artefact_link.creationdate as creation_date + from o_ep_struct_el struct + inner join o_ep_struct_artefact_link artefact_link on (artefact_link.fk_struct_id = struct.structure_id) + inner join o_ep_artefact artefact on (artefact_link.fk_artefact_id = artefact.artefact_id) + left join o_ep_struct_el root_struct on (struct.fk_struct_root_id = root_struct.structure_id) +); + +create or replace view o_ep_notifications_rating_v as ( + select + urating.rating_id as rating_id, + map.structure_id as map_id, + map.title as map_title, + cast(urating.ressubpath as number(20)) as page_key, + page.title as page_title, + urating.creator_id as author_id, + urating.creationdate as creation_date, + urating.lastmodified as last_modified + from o_userrating urating + inner join o_olatresource rating_resource on (rating_resource.resid = urating.resid and rating_resource.resname = urating.resname) + inner join o_ep_struct_el map on (map.fk_olatresource = rating_resource.resource_id) + left join o_ep_struct_el page on (page.fk_struct_root_map_id = map.structure_id and page.structure_id = cast(urating.ressubpath as integer)) +); + + +create or replace view o_ep_notifications_comment_v as ( + select + ucomment.comment_id as comment_id, + map.structure_id as map_id, + map.title as map_title, + cast(ucomment.ressubpath as number(20)) as page_key, + page.title as page_title, + ucomment.creator_id as author_id, + ucomment.creationdate as creation_date + from o_usercomment ucomment + inner join o_olatresource comment_resource on (comment_resource.resid = ucomment.resid and comment_resource.resname = ucomment.resname) + inner join o_ep_struct_el map on (map.fk_olatresource = comment_resource.resource_id) + left join o_ep_struct_el page on (page.fk_struct_root_map_id = map.structure_id and page.structure_id = cast(ucomment.ressubpath as integer)) +); + +create or replace view o_gp_business_to_repository_v as ( + select + grp.group_id as grp_id, + repoentry.repositoryentry_id as re_id, + repoentry.displayname as re_displayname + from o_gp_business grp + inner join o_gp_business_to_resource relation on (relation.fk_group = grp.group_id) + inner join o_repositoryentry repoentry on (repoentry.fk_olatresource = relation.fk_resource) +); + +create or replace view o_re_member_v as ( + select + re.repositoryentry_id as re_id, + re.membersonly as re_membersonly, + re.accesscode as re_accesscode, + re_part_member.identity_id as re_part_member_id, + re_tutor_member.identity_id as re_tutor_member_id, + re_owner_member.identity_id as re_owner_member_id, + bg_part_member.identity_id as bg_part_member_id, + bg_owner_member.identity_id as bg_owner_member_id + from o_repositoryentry re + left join o_bs_membership re_part_member on (re_part_member.secgroup_id = re.fk_participantgroup) + left join o_bs_membership re_tutor_member on (re_tutor_member.secgroup_id = re.fk_tutorgroup) + left join o_bs_membership re_owner_member on (re_owner_member.secgroup_id = re.fk_ownergroup) + left join o_gp_business_to_resource bgroup_rel on (bgroup_rel.fk_resource = re.fk_olatresource) + left join o_gp_business bgroup on (bgroup.group_id = bgroup_rel.fk_group) + left join o_bs_membership bg_part_member on (bg_part_member.secgroup_id = bgroup.fk_partipiciantgroup) + left join o_bs_membership bg_owner_member on (bg_owner_member.secgroup_id = bgroup.fk_ownergroup) +); + +create or replace view o_re_strict_member_v as ( + select + re.repositoryentry_id as re_id, + re_part_member.identity_id as re_part_member_id, + re_tutor_member.identity_id as re_tutor_member_id, + re_owner_member.identity_id as re_owner_member_id, + bg_part_member.identity_id as bg_part_member_id, + bg_owner_member.identity_id as bg_owner_member_id + from o_repositoryentry re + left join o_bs_membership re_part_member on (re_part_member.secgroup_id = re.fk_participantgroup) + left join o_bs_membership re_tutor_member on (re_tutor_member.secgroup_id = re.fk_tutorgroup) + left join o_bs_membership re_owner_member on (re_owner_member.secgroup_id = re.fk_ownergroup) + left join o_gp_business_to_resource bgroup_rel on (bgroup_rel.fk_resource = re.fk_olatresource) + left join o_gp_business bgroup on (bgroup.group_id = bgroup_rel.fk_group) + left join o_bs_membership bg_part_member on (bg_part_member.secgroup_id = bgroup.fk_partipiciantgroup) + left join o_bs_membership bg_owner_member on (bg_owner_member.secgroup_id = bgroup.fk_ownergroup) + where re.membersonly=1 and re.accesscode=1 +); + +create or replace view o_re_strict_participant_v as ( + select + re.repositoryentry_id as re_id, + re_part_member.identity_id as re_part_member_id, + bg_part_member.identity_id as bg_part_member_id + from o_repositoryentry re + left join o_bs_membership re_part_member on (re_part_member.secgroup_id = re.fk_participantgroup) + left join o_gp_business_to_resource bgroup_rel on (bgroup_rel.fk_resource = re.fk_olatresource) + left join o_gp_business bgroup on (bgroup.group_id = bgroup_rel.fk_group) + left join o_bs_membership bg_part_member on (bg_part_member.secgroup_id = bgroup.fk_partipiciantgroup) + where (re.membersonly=1 and re.accesscode=1) or re.accesscode>=3 +); + +create or replace view o_re_strict_tutor_v as ( + select + re.repositoryentry_id as re_id, + re_tutor_member.identity_id as re_tutor_member_id, + re_owner_member.identity_id as re_owner_member_id, + bg_owner_member.identity_id as bg_owner_member_id + from o_repositoryentry re + left join o_bs_membership re_tutor_member on (re_tutor_member.secgroup_id = re.fk_tutorgroup) + left join o_bs_membership re_owner_member on (re_owner_member.secgroup_id = re.fk_ownergroup) + left join o_gp_business_to_resource bgroup_rel on (bgroup_rel.fk_resource = re.fk_olatresource) + left join o_gp_business bgroup on (bgroup.group_id = bgroup_rel.fk_group) + left join o_bs_membership bg_owner_member on (bg_owner_member.secgroup_id = bgroup.fk_ownergroup) + where (re.membersonly=1 and re.accesscode=1) or re.accesscode>=3 +); + +create or replace view o_re_membership_v as ( + select + membership.id as membership_id, + membership.identity_id as identity_id, + membership.lastmodified as lastmodified, + membership.creationdate as creationdate, + re_owner_member.repositoryentry_id as owner_re_id, + re_owner_member.fk_olatresource as owner_ores_id, + re_tutor_member.repositoryentry_id as tutor_re_id, + re_tutor_member.fk_olatresource as tutor_ores_id, + re_part_member.repositoryentry_id as participant_re_id, + re_part_member.fk_olatresource as participant_ores_id + from o_bs_membership membership + left join o_repositoryentry re_part_member on (membership.secgroup_id = re_part_member.fk_participantgroup) + left join o_repositoryentry re_tutor_member on (membership.secgroup_id = re_tutor_member.fk_tutorgroup) + left join o_repositoryentry re_owner_member on (membership.secgroup_id = re_owner_member.fk_ownergroup) +); + +create or replace view o_bs_gp_membership_v as ( + select + membership.id as membership_id, + membership.identity_id as identity_id, + membership.lastmodified as lastmodified, + membership.creationdate as creationdate, + owned_gp.group_id as owned_gp_id, + participant_gp.group_id as participant_gp_id, + waiting_gp.group_id as waiting_gp_id + from o_bs_membership membership + left join o_gp_business owned_gp on (membership.secgroup_id = owned_gp.fk_ownergroup) + left join o_gp_business participant_gp on (membership.secgroup_id = participant_gp.fk_partipiciantgroup) + left join o_gp_business waiting_gp on (membership.secgroup_id = waiting_gp.fk_waitinggroup) + where (owned_gp.group_id is not null or participant_gp.group_id is not null or waiting_gp.group_id is not null) +); + +create or replace view o_gp_business_v as ( + select + gp.group_id as group_id, + gp.groupname as groupname, + gp.lastmodified as lastmodified, + gp.creationdate as creationdate, + gp.lastusage as lastusage, + gp.descr as descr, + gp.minparticipants as minparticipants, + gp.maxparticipants as maxparticipants, + gp.waitinglist_enabled as waitinglist_enabled, + gp.autocloseranks_enabled as autocloseranks_enabled, + (select count(part.id) from o_bs_membership part where part.secgroup_id = gp.fk_partipiciantgroup) as num_of_participants, + (select count(own.id) from o_bs_membership own where own.secgroup_id = gp.fk_ownergroup) as num_of_owners, + (case when gp.waitinglist_enabled = 1 + then + (select count(waiting.id) from o_bs_membership waiting where waiting.secgroup_id = gp.fk_partipiciantgroup) + else + 0 + end) as num_waiting, + (select count(offer.offer_id) from o_ac_offer offer + where offer.fk_resource_id = gp.fk_resource + and offer.is_valid=1 + and (offer.validfrom is null or offer.validfrom >= current_date) + and (offer.validto is null or offer.validto <= current_date) + ) as num_of_valid_offers, + (select count(offer.offer_id) from o_ac_offer offer + where offer.fk_resource_id = gp.fk_resource + and offer.is_valid=1 + ) as num_of_offers, + (select count(relation.fk_resource) from o_gp_business_to_resource relation + where relation.fk_group = gp.group_id + ) as num_of_relations, + gp.fk_resource as fk_resource, + gp.fk_ownergroup as fk_ownergroup, + gp.fk_partipiciantgroup as fk_partipiciantgroup, + gp.fk_waitinggroup as fk_waitinggroup + from o_gp_business gp +); + + CREATE OR REPLACE TRIGGER ai_o_stat_dayofweek_id BEFORE INSERT ON o_stat_dayofweek FOR EACH ROW WHEN ( @@ -945,6 +1706,26 @@ END; / -- indexes +create index userrating_id_idx on o_userrating (resid); +create index userrating_name_idx on o_userrating (resname); +create index userrating_subpath_idx on o_userrating (ressubpath); +create index userrating_rating_idx on o_userrating (rating); +create index FKF26C8375236F20X on o_userrating (creator_id); +alter table o_userrating add constraint FKF26C8375236F20X foreign key (creator_id) references o_bs_identity (id); + +create index usercmt_id_idx on o_usercomment (resid); +create index usercmt_name_idx on o_usercomment (resname); +create index usercmt_subpath_idx on o_usercomment (ressubpath); +create index FK92B6864A18251F0 on o_usercomment (parent_key); +create index FKF26C8375236F20A on o_usercomment (creator_id); +alter table o_usercomment add constraint FK92B6864A18251F0 foreign key (parent_key) references o_usercomment (comment_id); +alter table o_usercomment add constraint FKF26C8375236F20A foreign key (creator_id) references o_bs_identity (id); + +alter table o_checkpoint_results add constraint FK9E30F4B661159ZZY foreign key (checkpoint_fk) references o_checkpoint (checkpoint_id); +alter table o_checkpoint_results add constraint FK9E30F4B661159ZZX foreign key (identity_fk) references o_bs_identity (id); + +--create index asset_idx on o_plock (asset); + create index statdow_resid_idx on o_stat_dayofweek (resid); create index stathod_resid_idx on o_stat_hourofday (resid); create index statwee_resid_idx on o_stat_weekly (resid); @@ -953,80 +1734,51 @@ create index stathor_resid_idx on o_stat_homeorg (resid); create index statorg_resid_idx on o_stat_orgtype (resid); create index statstl_resid_idx on o_stat_studylevel (resid); create index statstb_resid_idx on o_stat_studybranch3 (resid); --- create index ocl_asset_idx on oc_lock (asset); -create index resid_idx on o_property (resourcetypeid); -create index category_idx on o_property (category); -create index name_idx on o_property (name); -create index restype_idx on o_property (resourcetypename); -create index gp_name_idx on o_gp_business (groupname); -create index gp_type_idx on o_gp_business (businessgrouptype); -create index provider_idx on o_bs_authentication (provider); -create index credential_idx on o_bs_authentication (credential); -create index authusername_idx on o_bs_authentication (authusername); -create index onp_name_idx on o_noti_pub (resname, resid, subident); -create index oresdetindex on o_qtiresultset (olatresourcedetail); -create index oresindex on o_qtiresultset (olatresource_fk); -create index reprefindex on o_qtiresultset (repositoryref_fk); -create index assindex on o_qtiresultset (assessmentid); --- create index obi_name_idx on o_bs_identity (name); -create index identstatus_idx on o_bs_identity (status); -create index oores_name_idx on o_olatresource (resname); -create index id_idx on o_olatresource (resid); --- create index groupname_idx on o_bs_namedgroup (groupname); -create index on_resid_idx on o_note (resourcetypeid); -create index owner_idx on o_note (owner_id); -create index on_restype_idx on o_note (resourcetypename); -create index type_idx on o_gp_bgcontext (grouptype); -create index default_idx on o_gp_bgcontext (defaultcontext); -create index ogpbgc_name_idx on o_gp_bgcontext (name); -create index propvalue_idx on o_userproperty (propvalue); -create index itemindex on o_qtiresult (itemident); -create index ogpbga_name_idx on o_gp_bgarea (name); -create index access_idx on o_repositoryentry (accesscode); -create index initialAuthor_idx on o_repositoryentry (initialauthor); -create index resource_idx on o_repositoryentry (resourcename); -create index displayname_idx on o_repositoryentry (displayname); --- create index softkey_idx on o_repositoryentry (softkey); --- create index asset_idx on o_plock (asset); -create index lc_pref_idx on o_lifecycle (persistentref); -create index lc_type_idx on o_lifecycle (persistenttypename); -create index lc_action_idx on o_lifecycle (action); -create index readmessage_forum_idx on o_readmessage (forum_id); -create index readmessage_identity_idx on o_readmessage (identity_id); -create index opb_project_broker_idx on o_projectbroker_project (projectbroker_fk); --- create index projectbroker_project_id_idx on o_projectbroker_project (project_id); -create index opb_customfields_idx on o_projectbroker_customfields (fk_project_id); -create index cmt_id_idx on o_usercomment (resid); -create index cmt_name_idx on o_usercomment (resname); -create index cmt_subpath_idx on o_usercomment (ressubpath); -create index rtn_id_idx on o_userrating (resid); -create index rtn_name_idx on o_userrating (resname); -create index rtn_subpath_idx on o_userrating (ressubpath); -create index rtn_rating_idx on o_userrating (rating); -create index usr_notification_interval_idx on o_user (notification_interval); - +create index resid_idx1 on o_property (resourcetypeid); +create index category_idx on o_property (category); +create index name_idx1 on o_property (name); +create index restype_idx1 on o_property (resourcetypename); --- foreign keys -create index FK9E30F4B66115906D on oc_lock (identity_fk); -alter table oc_lock add constraint FK9E30F4B66115906D foreign key (identity_fk) references o_bs_identity (id); create index FKB60B1BA5190E5 on o_property (grp); alter table o_property add constraint FKB60B1BA5190E5 foreign key (grp) references o_gp_business (group_id); create index FKB60B1BA5F7E870BE on o_property (identity); alter table o_property add constraint FKB60B1BA5F7E870BE foreign key (identity) references o_bs_identity (id); +create index gp_name_idx on o_gp_business (groupname); +create index gp_type_idx on o_gp_business (businessgrouptype); create index FKCEEB8A86DF6BCD14 on o_gp_business (groupcontext_fk); -alter table o_gp_business add constraint FKCEEB8A86DF6BCD14 foreign key (groupcontext_fk) references o_gp_bgcontext (groupcontext_id); -- create index FKCEEB8A86A1FAC766 on o_gp_business (fk_ownergroup); alter table o_gp_business add constraint FKCEEB8A86A1FAC766 foreign key (fk_ownergroup) references o_bs_secgroup (id); -- create index FKCEEB8A86C06E3EF3 on o_gp_business (fk_partipiciantgroup); alter table o_gp_business add constraint FKCEEB8A86C06E3EF3 foreign key (fk_partipiciantgroup) references o_bs_secgroup (id); + +alter table o_gp_business add constraint idx_bgp_rsrc foreign key (fk_resource) references o_olatresource (resource_id); + +alter table o_gp_business_to_resource add constraint idx_bgp_to_rsrc_rsrc foreign key (fk_resource) references o_olatresource (resource_id); +alter table o_gp_business_to_resource add constraint idx_bgp_to_rsrc_group foreign key (fk_group) references o_gp_business (group_id); + +create index provider_idx on o_bs_authentication (provider); +create index credential_idx on o_bs_authentication (credential); +create index authusername_idx on o_bs_authentication (authusername); create index FKC6A5445652595FE6 on o_bs_authentication (identity_fk); alter table o_bs_authentication add constraint FKC6A5445652595FE6 foreign key (identity_fk) references o_bs_identity (id); + +create index name_idx2 on o_noti_pub (resname, resid, subident); +create index oresdetindex on o_qtiresultset (olatresourcedetail); +create index oresindex on o_qtiresultset (olatresource_fk); +create index reprefindex on o_qtiresultset (repositoryref_fk); +create index assindex on o_qtiresultset (assessmentid); create index FK14805D0F5259603C on o_qtiresultset (identity_id); alter table o_qtiresultset add constraint FK14805D0F5259603C foreign key (identity_id) references o_bs_identity (id); +--create index name_idx3 on o_bs_identity (name); +create index identstatus_idx on o_bs_identity (status); -- create index FKFF94111CD1A80C95 on o_bs_identity (fk_user_id); alter table o_bs_identity add constraint FKFF94111CD1A80C95 foreign key (fk_user_id) references o_user (user_id); create index FK4B04D83FD1A80C95 on o_userproperty (fk_user_id); alter table o_userproperty add constraint FK4B04D83FD1A80C95 foreign key (fk_user_id) references o_user (user_id); + +--create index name_idx4 on o_olatresource (resname); +--create index id_idx on o_olatresource (resid); +--create index groupname_idx on o_bs_namedgroup (groupname); create index FKBAFCBBC4B85B522C on o_bs_namedgroup (secgroup_id); alter table o_bs_namedgroup add constraint FKBAFCBBC4B85B522C foreign key (secgroup_id) references o_bs_secgroup (id); create index FKF4433C2C7B66B0D0 on o_catentry (parent_id); @@ -1035,16 +1787,25 @@ alter table o_catentry add constraint FKF4433C2C7B66B0D0 foreign key (parent_id alter table o_catentry add constraint FKF4433C2CA1FAC766 foreign key (fk_ownergroup) references o_bs_secgroup (id); create index FKF4433C2CDDD69946 on o_catentry (fk_repoentry); alter table o_catentry add constraint FKF4433C2CDDD69946 foreign key (fk_repoentry) references o_repositoryentry (repositoryentry_id); + +create index resid_idx2 on o_note (resourcetypeid); +create index owner_idx on o_note (owner_id); +create index restype_idx2 on o_note (resourcetypename); -- create index FKC2D855C263219E27 on o_note (owner_id); alter table o_note add constraint FKC2D855C263219E27 foreign key (owner_id) references o_bs_identity (id); +create index type_idx on o_gp_bgcontext (grouptype); +create index default_idx on o_gp_bgcontext (defaultcontext); +create index name_idx5 on o_gp_bgcontext (name); -- create index FK1C154FC47E4A0638 on o_gp_bgcontext (ownergroup_fk); alter table o_gp_bgcontext add constraint FK1C154FC47E4A0638 foreign key (ownergroup_fk) references o_bs_secgroup (id); -create index FKE971B4589AC44FBF on o_references (source_id); -alter table o_references add constraint FKE971B4589AC44FBF foreign key (source_id) references o_olatresource (resource_id); +--create index FKE971B4589AC44FBF on o_references (source_id); +--alter table o_references add constraint FKE971B4589AC44FBF foreign key (source_id) references o_olatresource (resource_id); create index FKE971B458CF634A89 on o_references (target_id); alter table o_references add constraint FKE971B458CF634A89 foreign key (target_id) references o_olatresource (resource_id); create index FKDB97A6493F14E3EE on o_repositorymetadata (fk_repositoryentry); alter table o_repositorymetadata add constraint FKDB97A6493F14E3EE foreign key (fk_repositoryentry) references o_repositoryentry (repositoryentry_id); + +--create index propvalue_idx on o_userproperty (propvalue); create index FK9903BEAC9F9C3F1D on o_gp_bgcontextresource_rel (oresource_id); alter table o_gp_bgcontextresource_rel add constraint FK9903BEAC9F9C3F1D foreign key (oresource_id) references o_olatresource (resource_id); create index FK9903BEACDF6BCD14 on o_gp_bgcontextresource_rel (groupcontext_fk); @@ -1067,36 +1828,116 @@ create index FK4FB8F04749E53702 on o_noti_sub (fk_publisher); alter table o_noti_sub add constraint FK4FB8F04749E53702 foreign key (fk_publisher) references o_noti_pub (publisher_id); create index FK4FB8F0476B1F22F8 on o_noti_sub (fk_identity); alter table o_noti_sub add constraint FK4FB8F0476B1F22F8 foreign key (fk_identity) references o_bs_identity (id); + +create index itemindex on o_qtiresult (itemident); + create index FK3563E67340EF401F on o_qtiresult (resultset_fk); alter table o_qtiresult add constraint FK3563E67340EF401F foreign key (resultset_fk) references o_qtiresultset (resultset_id); create index FK9A1C5109F9C3F1D on o_bs_policy (oresource_id); alter table o_bs_policy add constraint FK9A1C5109F9C3F1D foreign key (oresource_id) references o_olatresource (resource_id); create index FK9A1C5101E2E76DB on o_bs_policy (group_id); alter table o_bs_policy add constraint FK9A1C5101E2E76DB foreign key (group_id) references o_bs_secgroup (id); -create index FK9EFAF698DF6BCD14 on o_gp_bgarea (groupcontext_fk); -alter table o_gp_bgarea add constraint FK9EFAF698DF6BCD14 foreign key (groupcontext_fk) references o_gp_bgcontext (groupcontext_id); + +create index name_idx6 on o_gp_bgarea (name); + +alter table o_gp_bgarea add constraint idx_area_to_resource foreign key (fk_resource) references o_olatresource (resource_id); + +create index descritpion_idx on o_repositoryentry (description); +create index access_idx on o_repositoryentry (accesscode); +create index initialAuthor_idx on o_repositoryentry (initialauthor); +create index resource_idx on o_repositoryentry (resourcename); +create index displayname_idx on o_repositoryentry (displayname); +--create index softkey_idx on o_repositoryentry (softkey); + -- create index FK2F9C439888C31018 on o_repositoryentry (fk_olatresource); alter table o_repositoryentry add constraint FK2F9C439888C31018 foreign key (fk_olatresource) references o_olatresource (resource_id); -- create index FK2F9C4398A1FAC766 on o_repositoryentry (fk_ownergroup); alter table o_repositoryentry add constraint FK2F9C4398A1FAC766 foreign key (fk_ownergroup) references o_bs_secgroup (id); +create index repo_members_only_idx on o_repositoryentry (membersonly); +alter table o_repositoryentry add constraint repo_tutor_sec_group_ctx foreign key (fk_tutorgroup) references o_bs_secgroup (id); +alter table o_repositoryentry add constraint repo_parti_sec_group_ctx foreign key (fk_participantgroup) references o_bs_secgroup (id); create index FK68C4E30663219E27 on o_bookmark (owner_id); alter table o_bookmark add constraint FK68C4E30663219E27 foreign key (owner_id) references o_bs_identity (id); create index FK7B6288B45259603C on o_bs_membership (identity_id); alter table o_bs_membership add constraint FK7B6288B45259603C foreign key (identity_id) references o_bs_identity (id); create index FK7B6288B4B85B522C on o_bs_membership (secgroup_id); alter table o_bs_membership add constraint FK7B6288B4B85B522C foreign key (secgroup_id) references o_bs_secgroup (id); -create index FK92B6864A18251F0 on o_usercomment (parent_key); -alter table o_usercomment add constraint FK92B6864A18251F0 foreign key (parent_key) references o_usercomment (comment_id); -create index FKF26C8375236F20A on o_usercomment (creator_id); -alter table o_usercomment add constraint FKF26C8375236F20A foreign key (creator_id) references o_bs_identity (id); -create index FKF26C8375236F20X on o_userrating (creator_id); -alter table o_userrating add constraint FKF26C8375236F20X foreign key (creator_id) references o_bs_identity (id); +create index lc_pref_idx on o_lifecycle (persistentref); +create index lc_type_idx on o_lifecycle (persistenttypename); +create index lc_action_idx on o_lifecycle (action); +create index readmessage_forum_idx on o_readmessage (forum_id); +create index readmessage_identity_idx on o_readmessage (identity_id); +create index projectbroker_prj_broker_idx on o_projectbroker_project (projectbroker_fk); +--create index projectbroker_project_id_idx on o_projectbroker_project (project_id); +create index o_projectbroker_custflds_idx on o_projectbroker_customfields (fk_project_id); +create index usr_notification_interval_idx on o_user (notification_interval); + +create index mark_id_idx on o_mark (resid); +create index mark_name_idx on o_mark (resname); +create index mark_subpath_idx on o_mark (ressubpath); +create index mark_businesspath_idx on o_mark (businesspath); +create index FKF26C8375236F21X on o_mark (creator_id); +alter table o_mark add constraint FKF26C8375236F21X foreign key (creator_id) references o_bs_identity (id); + +-- foreign keys create index imsg_resid_idx on o_info_message (resid); create index imsg_author_idx on o_info_message (fk_author_id); alter table o_info_message add constraint FKF85553465A4FA5DC foreign key (fk_author_id) references o_bs_identity (id); create index imsg_modifier_idx on o_info_message (fk_modifier_id); alter table o_info_message add constraint FKF85553465A4FA5EF foreign key (fk_modifier_id) references o_bs_identity (id); +-- big copy bth +alter table o_ep_artefact add constraint FKF26C8375236F28X foreign key (fk_artefact_auth_id) references o_bs_identity (id); +alter table o_ep_struct_el add constraint FKF26C8375236F26X foreign key (fk_olatresource) references o_olatresource (resource_id); +alter table o_ep_struct_el add constraint FKF26C8375236F29X foreign key (fk_ownergroup) references o_bs_secgroup (id); +alter table o_ep_struct_el add constraint FK4ECC1C8D636191A1 foreign key (fk_map_source_id) references o_ep_struct_el (structure_id); +alter table o_ep_struct_el add constraint FK4ECC1C8D76990817 foreign key (fk_struct_root_id) references o_ep_struct_el (structure_id); +alter table o_ep_struct_el add constraint FK4ECC1C8D76990818 foreign key (fk_struct_root_map_id) references o_ep_struct_el (structure_id); +alter table o_ep_artefact add constraint FKA0070D12316A97B4 foreign key (fk_struct_el_id) references o_ep_struct_el (structure_id); +alter table o_ep_collect_restriction add constraint FKA0070D12316A97B5 foreign key (fk_struct_el_id) references o_ep_struct_el (structure_id); +alter table o_ep_struct_struct_link add constraint FKF26C8375236F22X foreign key (fk_struct_parent_id) references o_ep_struct_el (structure_id); +alter table o_ep_struct_struct_link add constraint FKF26C8375236F23X foreign key (fk_struct_child_id) references o_ep_struct_el (structure_id); +alter table o_ep_struct_artefact_link add constraint FKF26C8375236F24X foreign key (fk_struct_id) references o_ep_struct_el (structure_id); +alter table o_ep_struct_artefact_link add constraint FKF26C8375236F25X foreign key (fk_artefact_id) references o_ep_artefact (artefact_id); +alter table o_ep_struct_artefact_link add constraint FKF26C8375236F26Y foreign key (fk_auth_id) references o_bs_identity (id); + +alter table o_bs_invitation add constraint FKF26C8375236F27X foreign key (fk_secgroup) references o_bs_secgroup (id); + +alter table o_tag add constraint FK6491FCA5A4FA5DC foreign key (fk_author_id) references o_bs_identity (id); + +alter table o_mail_to_recipient add constraint FKF86663165A4FA5DE foreign key (fk_mail_id) references o_mail (mail_id); +alter table o_mail_recipient add constraint FKF86663165A4FA5DG foreign key (fk_recipient_id) references o_bs_identity (id); +alter table o_mail add constraint FKF86663165A4FA5DC foreign key (fk_from_id) references o_mail_recipient (recipient_id); +alter table o_mail_to_recipient add constraint FKF86663165A4FA5DD foreign key (fk_recipient_id) references o_mail_recipient (recipient_id); +alter table o_mail_attachment add constraint FKF86663165A4FA5DF foreign key (fk_att_mail_id) references o_mail (mail_id); + +create index ac_offer_to_resource_idx on o_ac_offer (fk_resource_id); +alter table o_ac_offer_access add constraint off_to_meth_meth_ctx foreign key (fk_method_id) references o_ac_method (method_id); +alter table o_ac_offer_access add constraint off_to_meth_off_ctx foreign key (fk_offer_id) references o_ac_offer (offer_id); +create index ac_order_to_delivery_idx on o_ac_order (fk_delivery_id); +alter table o_ac_order_part add constraint ord_part_ord_ctx foreign key (fk_order_id) references o_ac_order (order_id); +alter table o_ac_order_line add constraint ord_item_ord_part_ctx foreign key (fk_order_part_id) references o_ac_order_part (order_part_id); +alter table o_ac_order_line add constraint ord_item_offer_ctx foreign key (fk_offer_id) references o_ac_offer (offer_id); +alter table o_ac_transaction add constraint trans_ord_ctx foreign key (fk_order_id) references o_ac_order (order_id); +alter table o_ac_transaction add constraint trans_ord_part_ctx foreign key (fk_order_part_id) references o_ac_order_part (order_part_id); +alter table o_ac_transaction add constraint trans_method_ctx foreign key (fk_method_id) references o_ac_method (method_id); + +create index paypal_pay_key_idx on o_ac_paypal_transaction (pay_key); +create index paypal_pay_trx_id_idx on o_ac_paypal_transaction (ipn_transaction_id); +create index paypal_pay_s_trx_id_idx on o_ac_paypal_transaction (ipn_sender_transaction_id); + +alter table o_as_eff_statement add constraint eff_statement_id_cstr foreign key (fk_identity) references o_bs_identity (id); +create index eff_statement_repo_key_idx on o_as_eff_statement (course_repo_key); +alter table o_as_user_course_infos add constraint user_course_infos_id_cstr foreign key (fk_identity) references o_bs_identity (id); +alter table o_as_user_course_infos add constraint user_course_infos_res_cstr foreign key (fk_resource_id) references o_olatresource (resource_id); + +create index o_co_db_course_idx on o_co_db_entry (courseid); +create index o_co_db_cat_idx on o_co_db_entry (category); +create index o_co_db_name_idx on o_co_db_entry (name); +alter table o_co_db_entry add constraint FKB60B1BA5F7E870XY foreign key (identity) references o_bs_identity; + +create index o_mapper_uuid_idx on o_mapper (mapper_uuid); + insert into hibernate_unique_key values ( 0 ); commit / diff --git a/src/main/resources/serviceconfig/olat.properties b/src/main/resources/serviceconfig/olat.properties index d3ffa32b9aab266fed59d48656130c1ee3196646..c2fb6a68010fd2a6109c11a08a50dd3105e31321 100644 --- a/src/main/resources/serviceconfig/olat.properties +++ b/src/main/resources/serviceconfig/olat.properties @@ -405,6 +405,9 @@ db.name=olat db.user=olat db.pass=olat +#this option is currently only for oracle +db.default.schema=olat + # Special options for mysql database. Set useOldUTF8Behavior=true if # your mysql database is setup up with iso-latin (or any other) encoding. # Remove the useOldUTF8Behavior parameter if you use native UTF-8 on the diff --git a/src/test/profile/oracle/olat.eclipse.properties b/src/test/profile/oracle/olat.eclipse.properties new file mode 100644 index 0000000000000000000000000000000000000000..964f8099f28d37494aef14219ccbc020bd9d437f --- /dev/null +++ b/src/test/profile/oracle/olat.eclipse.properties @@ -0,0 +1,54 @@ +######################### +# +# This olat.local.properties file is only used when running junit tests! (Unit tests run in its own classpath environment) +# Use this file to set properties that affect or are a prerequisite for your tests. +# +######################### +tomcat.id=2 + +defaultlang=de +db.show_sql=false +#force use of java.io.tmpDir for unit tests +archive.dir= +log.dir= +folder.root= +restapi.enable=true + +instance.id=2 + +generate.index.at.startup=false + +# for UserTest +keepUserEmailAfterDeletion=true +keepUserLoginAfterDeletion=true + +# do not run upgrades and scheduled jobs and such +cluster.singleton.services = disabled +jmx.rmi.port=1009 + +# SingleVM jms.broker.url +jms.broker.url=vm://embedded?broker.persistent=false +search.broker.url=vm://embedded?broker.persistent=false +codepoint.jms.broker.url=vm://embedded?broker.persistent=false +# Cluster (remote) jms.broker.url +#jms.broker.url=failover:(tcp://localhost:${test.env.jms.broker.port}?wireFormat.maxInactivityDuration=0) +#search.broker.url=failover:(tcp://localhost:${test.env.jms.broker.port}?wireFormat.maxInactivityDuration=0) +#codepoint.jms.broker.url=failover:(tcp://localhost:${test.env.jms.broker.port}?wireFormat.maxInactivityDuration=0) + +# enable/disable codepoint/breakpoint framework +codepoint_server.enabled=true +smtp.host=testing + +# +# if you like to run your tests against mysql just uncomment the following. Please do not commit it! +# +db.vendor=oracle +db.name=xe +db.user=OLATTEST +db.pass=oracle +db.host=192.168.1.202 +db.host.port=1521 +db.default.schema=olattest +db.database.dialect=org.hibernate.dialect.Oracle10gDialect +db.hibernate.ddl.auto= +auto.upgrade.database=false