From a1222d55b4c75e43166ebf4d1e8f8c84d7862fbc Mon Sep 17 00:00:00 2001
From: srosse <none@none>
Date: Thu, 2 Aug 2012 15:51:59 +0200
Subject: [PATCH] OO-291: update SQL scripts add a unit test for membership

---
 .../database/mysql/alter_8_1_x_to_8_2_0.sql   |  5 --
 .../database/mysql/setupDatabase.sql          | 49 +++++++++++++++++
 .../postgresql/alter_8_1_x_to_8_2_0.sql       | 53 ++++++++++++++++++-
 .../database/postgresql/setupDatabase.sql     | 50 +++++++++++++++++
 .../olat/group/test/BusinessGroupDAOTest.java | 49 +++++++++--------
 5 files changed, 179 insertions(+), 27 deletions(-)

diff --git a/src/main/resources/database/mysql/alter_8_1_x_to_8_2_0.sql b/src/main/resources/database/mysql/alter_8_1_x_to_8_2_0.sql
index 997ab6cae80..cb4f2552a30 100644
--- a/src/main/resources/database/mysql/alter_8_1_x_to_8_2_0.sql
+++ b/src/main/resources/database/mysql/alter_8_1_x_to_8_2_0.sql
@@ -127,23 +127,18 @@ create or replace view o_gp_business_v  as (
       gp.maxparticipants as maxparticipants,
       gp.waitinglist_enabled as waitinglist_enabled,
       gp.autocloseranks_enabled as autocloseranks_enabled,
-      -- count participants
       (select count(part.id) from o_bs_membership as part where part.secgroup_id = gp.fk_partipiciantgroup) as num_of_participants,
-      -- count owners
       (select count(own.id) from o_bs_membership as own where own.secgroup_id = gp.fk_ownergroup) as num_of_owners,
-      -- count valid offers
       (select count(offer.offer_id) from o_ac_offer as offer 
          where offer.fk_resource_id = gp.fk_resource
          and offer.is_valid=1
          and (offer.validfrom is null or offer.validfrom >= curtime())
          and (offer.validto is null or offer.validto <= curtime())
       ) as num_of_valid_offers,
-      -- count offers
       (select count(offer.offer_id) from o_ac_offer as offer 
          where offer.fk_resource_id = gp.fk_resource
          and offer.is_valid=1
       ) as num_of_offers,
-      -- count relations
       (select count(relation.fk_resource) from o_gp_business_to_resource as relation 
          where relation.fk_group = gp.group_id
       ) as num_of_relations,
diff --git a/src/main/resources/database/mysql/setupDatabase.sql b/src/main/resources/database/mysql/setupDatabase.sql
index 0c081cb5ca3..db4af391f53 100644
--- a/src/main/resources/database/mysql/setupDatabase.sql
+++ b/src/main/resources/database/mysql/setupDatabase.sql
@@ -1068,6 +1068,55 @@ create or replace view o_gp_business_to_repository_v as (
 	inner join o_repositoryentry as repoentry on (repoentry.fk_olatresource = relation.fk_resource)
 );
 
+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 as membership
+   left join o_gp_business as owned_gp on (membership.secgroup_id = owned_gp.fk_ownergroup)
+   left join o_gp_business as participant_gp on (membership.secgroup_id = participant_gp.fk_partipiciantgroup)
+   left join o_gp_business as 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 as part where part.secgroup_id = gp.fk_partipiciantgroup) as num_of_participants,
+      (select count(own.id) from o_bs_membership as own where own.secgroup_id = gp.fk_ownergroup) as num_of_owners,
+      (select count(offer.offer_id) from o_ac_offer as offer 
+         where offer.fk_resource_id = gp.fk_resource
+         and offer.is_valid=1
+         and (offer.validfrom is null or offer.validfrom >= curtime())
+         and (offer.validto is null or offer.validto <= curtime())
+      ) as num_of_valid_offers,
+      (select count(offer.offer_id) from o_ac_offer as 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 as 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 as gp
+);
 
 create or replace view o_re_member_v as (
    select
diff --git a/src/main/resources/database/postgresql/alter_8_1_x_to_8_2_0.sql b/src/main/resources/database/postgresql/alter_8_1_x_to_8_2_0.sql
index 6fcebab64cd..516acc9b2be 100644
--- a/src/main/resources/database/postgresql/alter_8_1_x_to_8_2_0.sql
+++ b/src/main/resources/database/postgresql/alter_8_1_x_to_8_2_0.sql
@@ -97,4 +97,55 @@ create or replace view o_re_strict_tutor_v as (
    left join o_gp_business as bgroup on (bgroup.group_id = bgroup_rel.fk_group)
    left join o_bs_membership as bg_owner_member on (bg_owner_member.secgroup_id = bgroup.fk_ownergroup)
    where re.membersonly=true and re.accesscode=1
-);
\ No newline at end of file
+);
+
+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 as membership
+   left join o_gp_business as owned_gp on (membership.secgroup_id = owned_gp.fk_ownergroup)
+   left join o_gp_business as participant_gp on (membership.secgroup_id = participant_gp.fk_partipiciantgroup)
+   left join o_gp_business as 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 as part where part.secgroup_id = gp.fk_partipiciantgroup) as num_of_participants,
+      (select count(own.id) from o_bs_membership as own where own.secgroup_id = gp.fk_ownergroup) as num_of_owners,
+      (select count(offer.offer_id) from o_ac_offer as offer 
+         where offer.fk_resource_id = gp.fk_resource
+         and offer.is_valid=true
+         and (offer.validfrom is null or offer.validfrom >= current_timestamp)
+         and (offer.validto is null or offer.validto <= current_timestamp)
+      ) as num_of_valid_offers,
+      (select count(offer.offer_id) from o_ac_offer as offer 
+         where offer.fk_resource_id = gp.fk_resource
+         and offer.is_valid=true
+      ) as num_of_offers,
+      (select count(relation.fk_resource) from o_gp_business_to_resource as 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 as gp
+);
+
diff --git a/src/main/resources/database/postgresql/setupDatabase.sql b/src/main/resources/database/postgresql/setupDatabase.sql
index 984d74feed9..dd6fa31b119 100644
--- a/src/main/resources/database/postgresql/setupDatabase.sql
+++ b/src/main/resources/database/postgresql/setupDatabase.sql
@@ -1065,6 +1065,56 @@ create or replace view o_gp_business_to_repository_v as (
 	inner join o_repositoryentry as repoentry on (repoentry.fk_olatresource = relation.fk_resource)
 );
 
+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 as membership
+   left join o_gp_business as owned_gp on (membership.secgroup_id = owned_gp.fk_ownergroup)
+   left join o_gp_business as participant_gp on (membership.secgroup_id = participant_gp.fk_partipiciantgroup)
+   left join o_gp_business as 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 as part where part.secgroup_id = gp.fk_partipiciantgroup) as num_of_participants,
+      (select count(own.id) from o_bs_membership as own where own.secgroup_id = gp.fk_ownergroup) as num_of_owners,
+      (select count(offer.offer_id) from o_ac_offer as offer 
+         where offer.fk_resource_id = gp.fk_resource
+         and offer.is_valid=true
+         and (offer.validfrom is null or offer.validfrom >= current_timestamp)
+         and (offer.validto is null or offer.validto <= current_timestamp)
+      ) as num_of_valid_offers,
+      (select count(offer.offer_id) from o_ac_offer as offer 
+         where offer.fk_resource_id = gp.fk_resource
+         and offer.is_valid=true
+      ) as num_of_offers,
+      (select count(relation.fk_resource) from o_gp_business_to_resource as 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 as gp
+);
+
 create or replace view o_re_member_v as (
    select
       re.repositoryentry_id as re_id,
diff --git a/src/test/java/org/olat/group/test/BusinessGroupDAOTest.java b/src/test/java/org/olat/group/test/BusinessGroupDAOTest.java
index 41d60a35dba..b30745f8580 100644
--- a/src/test/java/org/olat/group/test/BusinessGroupDAOTest.java
+++ b/src/test/java/org/olat/group/test/BusinessGroupDAOTest.java
@@ -39,6 +39,7 @@ import org.olat.core.id.Identity;
 import org.olat.core.logging.OLog;
 import org.olat.core.logging.Tracing;
 import org.olat.group.BusinessGroup;
+import org.olat.group.BusinessGroupMembership;
 import org.olat.group.BusinessGroupOrder;
 import org.olat.group.BusinessGroupShort;
 import org.olat.group.BusinessGroupView;
@@ -1204,29 +1205,35 @@ public class BusinessGroupDAOTest extends OlatTestCase {
 		securityManager.addIdentityToSecurityGroup(id, group3.getWaitingGroup());
 		dbInstance.commitAndCloseSession();
 		
-		List<BusinessGroup> groups = new ArrayList<BusinessGroup>();
-		groups.add(group1);
-		groups.add(group2);
-		groups.add(group3);
+		List<Long> groupKeys = new ArrayList<Long>();
+		groupKeys.add(group1.getKey());
+		groupKeys.add(group2.getKey());
+		groupKeys.add(group3.getKey());
 
 		//check owner + attendee
-		List<Long> groupKeysA = businessGroupDao.isIdentityInBusinessGroups(id, true, true, false, groups);
-		Assert.assertNotNull(groupKeysA);
-		Assert.assertEquals(2, groupKeysA.size());
-		Assert.assertTrue(groupKeysA.contains(group1.getKey()));
-		Assert.assertTrue(groupKeysA.contains(group2.getKey()));
-		
-		//check owner 
-		List<Long> groupKeysB = businessGroupDao.isIdentityInBusinessGroups(id, true, false, false, groups);
-		Assert.assertNotNull(groupKeysB);
-		Assert.assertEquals(1, groupKeysB.size());
-		Assert.assertTrue(groupKeysB.contains(group1.getKey()));
-
-		//check attendee 
-		List<Long> groupKeysC = businessGroupDao.isIdentityInBusinessGroups(id, false, true, false, groups);
-		Assert.assertNotNull(groupKeysC);
-		Assert.assertEquals(1, groupKeysC.size());
-		Assert.assertTrue(groupKeysC.contains(group2.getKey()));
+		int countMembershipA = businessGroupDao.countMembershipInfoInBusinessGroups(id, groupKeys);
+		Assert.assertEquals(3, countMembershipA);
+		List<BusinessGroupMembership> memberships = businessGroupDao.getMembershipInfoInBusinessGroups(id, groupKeys);
+		Assert.assertNotNull(memberships);
+		Assert.assertEquals(3, memberships.size());
+		
+		int found = 0;
+		for(BusinessGroupMembership membership:memberships) {
+			Assert.assertNotNull(membership.getIdentityKey());
+			Assert.assertNotNull(membership.getCreationDate());
+			Assert.assertNotNull(membership.getLastModified());
+			Assert.assertNotNull(membership.getMembership());
+			if(membership.getOwnerGroupKey() != null && group1.getKey().equals(membership.getOwnerGroupKey())) {
+				found++;
+			}
+			if(membership.getParticipantGroupKey() != null && group2.getKey().equals(membership.getParticipantGroupKey())) {
+				found++;
+			}
+			if(membership.getWaitingGroupKey() != null && group3.getKey().equals(membership.getWaitingGroupKey())) {
+				found++;
+			}
+		}
+		Assert.assertEquals(3, found);
 	}
 	
 	private boolean contains(List<BusinessGroupView> views, BusinessGroup group) {
-- 
GitLab