X-Git-Url: https://git.rapsys.eu/airbundle/blobdiff_plain/7937366ad177149e96d3c93da6353d45945d4b33..d2ee346ded5b153cb2eeb000daa18bcf7ff410cb:/Repository/SessionRepository.php?ds=sidebyside

diff --git a/Repository/SessionRepository.php b/Repository/SessionRepository.php
index 7db5bb9..4deb69e 100644
--- a/Repository/SessionRepository.php
+++ b/Repository/SessionRepository.php
@@ -17,11 +17,14 @@ class SessionRepository extends \Doctrine\ORM\EntityRepository {
 	///Set accuweather max number of hourly pages
 	const ACCUWEATHER_HOURLY = 3;
 
-	///Set user with bad behaviour delay
-	const BAD_DELAY = 3;
+	///Set guest delay
+	const GUEST_DELAY = 2;
 
-	///Set user with good behaviour delay
-	const GOOD_DELAY = 4;
+	///Set regular delay
+	const REGULAR_DELAY = 3;
+
+	///Set senior
+	const SENIOR_DELAY = 4;
 
 	///Set glyphs
 	//TODO: document utf-8 codes ?
@@ -87,13 +90,66 @@ class SessionRepository extends \Doctrine\ORM\EntityRepository {
 			->getResult();
 	}
 
+	/**
+	 * Find one session by location and user id within last month
+	 *
+	 * @param $location The location id
+	 * @param $user The user id
+	 */
+	public function findOneWithinLastMonthByLocationUser($location, $user) {
+		//Get entity manager
+		$em = $this->getEntityManager();
+
+		//Get quote strategy
+		$qs = $em->getConfiguration()->getQuoteStrategy();
+		$dp = $em->getConnection()->getDatabasePlatform();
+
+		//Get quoted table names
+		//XXX: this allow to make this code table name independent
+		$tables = [
+			'RapsysAirBundle:Session' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Session'), $dp),
+			'RapsysAirBundle:Application' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Application'), $dp),
+			"\t" => '',
+			"\n" => ' '
+		];
+
+		//Set the request
+		//XXX: give the gooddelay to guest just in case
+		$req =<<<SQL
+SELECT s.id
+FROM RapsysAirBundle:Session s
+JOIN RapsysAirBundle:Application a ON (a.id = s.application_id AND a.user_id = :uid AND (a.canceled IS NULL OR TIMESTAMPDIFF(DAY, a.canceled, ADDTIME(s.date, s.begin)) < 1))
+WHERE s.location_id = :lid AND s.date >= DATE_ADD(DATE_SUB(NOW(), INTERVAL 1 MONTH), INTERVAL :gooddelay DAY)
+SQL;
+
+		//Replace bundle entity name by table name
+		$req = str_replace(array_keys($tables), array_values($tables), $req);
+
+		//Get result set mapping instance
+		$rsm = new ResultSetMapping();
+
+		//Declare all fields
+		//XXX: see vendor/doctrine/dbal/lib/Doctrine/DBAL/Types/Types.php
+		$rsm->addScalarResult('id', 'id', 'integer')
+			->addIndexByScalar('id');
+
+		//Return result
+		return $em
+			->createNativeQuery($req, $rsm)
+			->setParameter('lid', $location)
+			->setParameter('uid', $user)
+			->setParameter('gooddelay', self::SENIOR_DELAY)
+			->getOneOrNullResult();
+	}
+
 	/**
 	 * Fetch session by id
 	 *
 	 * @param $id The session id
+	 * @param $locale The locale
 	 * @return array The session data
 	 */
-	public function fetchOneById($id) {
+	public function fetchOneById($id, $locale = null) {
 		//Get entity manager
 		$em = $this->getEntityManager();
 
@@ -104,13 +160,17 @@ class SessionRepository extends \Doctrine\ORM\EntityRepository {
 		//Get quoted table names
 		//XXX: this allow to make this code table name independent
 		$tables = [
-			'RapsysAirBundle:GroupUser' => $qs->getJoinTableName($em->getClassMetadata('RapsysAirBundle:User')->getAssociationMapping('groups'), $em->getClassMetadata('RapsysAirBundle:User'), $dp),
-			'RapsysAirBundle:Session' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Session'), $dp),
 			'RapsysAirBundle:Application' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Application'), $dp),
 			'RapsysAirBundle:Group' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Group'), $dp),
+			'RapsysAirBundle:GroupUser' => $qs->getJoinTableName($em->getClassMetadata('RapsysAirBundle:User')->getAssociationMapping('groups'), $em->getClassMetadata('RapsysAirBundle:User'), $dp),
 			'RapsysAirBundle:Location' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Location'), $dp),
+			'RapsysAirBundle:Session' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Session'), $dp),
+			'RapsysAirBundle:Snippet' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Snippet'), $dp),
 			'RapsysAirBundle:Slot' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Slot'), $dp),
-			'RapsysAirBundle:User' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:User'), $dp)
+			'RapsysAirBundle:User' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:User'), $dp),
+			':afterid' => 4,
+			"\t" => '',
+			"\n" => ' '
 		];
 
 		//Set the request
@@ -121,9 +181,9 @@ SELECT
 	s.id,
 	s.date,
 	s.begin,
-	ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = 4, 1, 0) DAY) AS start,
+	ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY) AS start,
 	s.length,
-	ADDDATE(ADDTIME(ADDTIME(s.date, s.begin), s.length), INTERVAL IF(s.slot_id = 4, 1, 0) DAY) AS stop,
+	ADDDATE(ADDTIME(ADDTIME(s.date, s.begin), s.length), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY) AS stop,
 	s.rainfall,
 	s.rainrisk,
 	s.realfeel,
@@ -132,6 +192,7 @@ SELECT
 	s.temperature,
 	s.temperaturemin,
 	s.temperaturemax,
+	s.locked,
 	s.created,
 	s.updated,
 	s.location_id AS l_id,
@@ -145,20 +206,29 @@ SELECT
 	s.slot_id AS t_id,
 	t.title AS t_title,
 	s.application_id AS a_id,
+	a.canceled AS a_canceled,
 	a.user_id AS au_id,
 	au.pseudonym AS au_pseudonym,
-	GROUP_CONCAT(sa.id ORDER BY sa.user_id SEPARATOR "\n") AS sa_id,
-	GROUP_CONCAT(IFNULL(sa.score, 'NULL') ORDER BY sa.user_id SEPARATOR "\n") AS sa_score,
-	GROUP_CONCAT(sa.created ORDER BY sa.user_id SEPARATOR "\n") AS sa_created,
-	GROUP_CONCAT(sa.updated ORDER BY sa.user_id SEPARATOR "\n") AS sa_updated,
-	GROUP_CONCAT(IFNULL(sa.canceled, 'NULL') ORDER BY sa.user_id SEPARATOR "\n") AS sa_canceled,
-	GROUP_CONCAT(sa.user_id ORDER BY sa.user_id SEPARATOR "\n") AS sau_id,
-	GROUP_CONCAT(sau.pseudonym ORDER BY sa.user_id SEPARATOR "\n") AS sau_pseudonym
+	p.id AS p_id,
+	p.description AS p_description,
+	p.class AS p_class,
+	p.contact AS p_contact,
+	p.donate AS p_donate,
+	p.link AS p_link,
+	p.profile AS p_profile,
+	GROUP_CONCAT(sa.id ORDER BY sa.user_id SEPARATOR "\\n") AS sa_id,
+	GROUP_CONCAT(IFNULL(sa.score, 'NULL') ORDER BY sa.user_id SEPARATOR "\\n") AS sa_score,
+	GROUP_CONCAT(sa.created ORDER BY sa.user_id SEPARATOR "\\n") AS sa_created,
+	GROUP_CONCAT(sa.updated ORDER BY sa.user_id SEPARATOR "\\n") AS sa_updated,
+	GROUP_CONCAT(IFNULL(sa.canceled, 'NULL') ORDER BY sa.user_id SEPARATOR "\\n") AS sa_canceled,
+	GROUP_CONCAT(sa.user_id ORDER BY sa.user_id SEPARATOR "\\n") AS sau_id,
+	GROUP_CONCAT(sau.pseudonym ORDER BY sa.user_id SEPARATOR "\\n") AS sau_pseudonym
 FROM RapsysAirBundle:Session AS s
 JOIN RapsysAirBundle:Location AS l ON (l.id = s.location_id)
 JOIN RapsysAirBundle:Slot AS t ON (t.id = s.slot_id)
 LEFT JOIN RapsysAirBundle:Application AS a ON (a.id = s.application_id)
 LEFT JOIN RapsysAirBundle:User AS au ON (au.id = a.user_id)
+LEFT JOIN RapsysAirBundle:Snippet AS p ON (p.location_id = s.location_id AND p.user_id = a.user_id AND p.locale = :locale)
 LEFT JOIN RapsysAirBundle:Application AS sa ON (sa.session_id = s.id)
 LEFT JOIN RapsysAirBundle:User AS sau ON (sau.id = sa.user_id)
 WHERE s.id = :sid
@@ -189,6 +259,7 @@ SQL;
 			->addScalarResult('temperature', 'temperature', 'float')
 			->addScalarResult('temperaturemin', 'temperaturemin', 'float')
 			->addScalarResult('temperaturemax', 'temperaturemax', 'float')
+			->addScalarResult('locked', 'locked', 'datetime')
 			->addScalarResult('created', 'created', 'datetime')
 			->addScalarResult('updated', 'updated', 'datetime')
 			->addScalarResult('l_id', 'l_id', 'integer')
@@ -202,8 +273,16 @@ SQL;
 			->addScalarResult('t_id', 't_id', 'integer')
 			->addScalarResult('t_title', 't_title', 'string')
 			->addScalarResult('a_id', 'a_id', 'integer')
+			->addScalarResult('a_canceled', 'a_canceled', 'datetime')
 			->addScalarResult('au_id', 'au_id', 'integer')
 			->addScalarResult('au_pseudonym', 'au_pseudonym', 'string')
+			->addScalarResult('p_id', 'p_id', 'integer')
+			->addScalarResult('p_description', 'p_description', 'text')
+			->addScalarResult('p_class', 'p_class', 'text')
+			->addScalarResult('p_contact', 'p_contact', 'text')
+			->addScalarResult('p_donate', 'p_donate', 'text')
+			->addScalarResult('p_link', 'p_link', 'text')
+			->addScalarResult('p_profile', 'p_profile', 'text')
 			//XXX: is a string because of \n separator
 			->addScalarResult('sa_id', 'sa_id', 'string')
 			//XXX: is a string because of \n separator
@@ -224,6 +303,7 @@ SQL;
 		return $em
 			->createNativeQuery($req, $rsm)
 			->setParameter('sid', $id)
+			->setParameter('locale', $locale)
 			->getOneOrNullResult();
 	}
 
@@ -254,24 +334,63 @@ SQL;
 			'RapsysAirBundle:Location' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Location'), $dp),
 			'RapsysAirBundle:Slot' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Slot'), $dp),
 			'RapsysAirBundle:User' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:User'), $dp),
+			':afterid' => 4,
 			"\t" => '',
 			"\n" => ' '
 		];
 
+		//Init granted sql
+		$grantSql = '';
+
+		//When granted is set
+		if (empty($granted)) {
+			//Set application and user as optional
+			$grantSql = 'LEFT ';
+		}
+
+		//Init location sql
+		$locationSql = '';
+
+		//When location id is set
+		if (!empty($locationId)) {
+			//Add location id clause
+			$locationSql = "\n\t".'AND s.location_id = :lid';
+		}
+
 		//Set the request
-		//TODO: change as_u_* in sau_*, a_u_* in au_*, etc, see request up
-		$req = 'SELECT s.id, s.date, s.rainrisk, s.rainfall, s.realfeel, s.temperature, s.location_id AS l_id, l.short AS l_short, l.title AS l_title, s.slot_id AS t_id, t.title AS t_title, s.application_id AS a_id, a.user_id AS a_u_id, au.pseudonym AS a_u_pseudonym, GROUP_CONCAT(sa.user_id ORDER BY sa.user_id SEPARATOR "\n") AS as_u_id, GROUP_CONCAT(sau.pseudonym ORDER BY sa.user_id SEPARATOR "\n") AS as_u_pseudonym
-			FROM RapsysAirBundle:Session AS s
-			JOIN RapsysAirBundle:Location AS l ON (l.id = s.location_id)
-			JOIN RapsysAirBundle:Slot AS t ON (t.id = s.slot_id)
-			'.($granted?'':'LEFT ').'JOIN RapsysAirBundle:Application AS a ON (a.id = s.application_id)
-			'.($granted?'':'LEFT ').'JOIN RapsysAirBundle:User AS au ON (au.id = a.user_id)
-			LEFT JOIN RapsysAirBundle:Application AS sa ON (sa.session_id = s.id)
-			LEFT JOIN RapsysAirBundle:User AS sau ON (sau.id = sa.user_id)
-			WHERE s.date BETWEEN :begin AND :end
-			'.($locationId?'AND s.location_id = :lid':'').'
-			GROUP BY s.id
-			ORDER BY NULL';
+		$req = <<<SQL
+SELECT
+	s.id,
+	s.date,
+	s.rainrisk,
+	s.rainfall,
+	s.realfeel,
+	s.temperature,
+	s.locked,
+	ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY) AS start,
+	ADDDATE(ADDTIME(ADDTIME(s.date, s.begin), s.length), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY) AS stop,
+	s.location_id AS l_id,
+	l.short AS l_short,
+	l.title AS l_title,
+	s.slot_id AS t_id,
+	t.title AS t_title,
+	s.application_id AS a_id,
+	a.canceled AS a_canceled,
+	a.user_id AS au_id,
+	au.pseudonym AS au_pseudonym,
+	GROUP_CONCAT(sa.user_id ORDER BY sa.user_id SEPARATOR "\\n") AS sau_id,
+	GROUP_CONCAT(sau.pseudonym ORDER BY sa.user_id SEPARATOR "\\n") AS sau_pseudonym
+FROM RapsysAirBundle:Session AS s
+JOIN RapsysAirBundle:Location AS l ON (l.id = s.location_id)
+JOIN RapsysAirBundle:Slot AS t ON (t.id = s.slot_id)
+${grantSql}JOIN RapsysAirBundle:Application AS a ON (a.id = s.application_id)
+${grantSql}JOIN RapsysAirBundle:User AS au ON (au.id = a.user_id)
+LEFT JOIN RapsysAirBundle:Application AS sa ON (sa.session_id = s.id)
+LEFT JOIN RapsysAirBundle:User AS sau ON (sau.id = sa.user_id)
+WHERE s.date BETWEEN :begin AND :end${locationSql}
+GROUP BY s.id
+ORDER BY NULL
+SQL;
 
 		//Replace bundle entity name by table name
 		$req = str_replace(array_keys($tables), array_values($tables), $req);
@@ -289,27 +408,37 @@ SQL;
 			->addScalarResult('rainfall', 'rainfall', 'float')
 			->addScalarResult('realfeel', 'realfeel', 'float')
 			->addScalarResult('temperature', 'temperature', 'float')
+			->addScalarResult('locked', 'locked', 'datetime')
+			->addScalarResult('start', 'start', 'datetime')
+			->addScalarResult('stop', 'stop', 'datetime')
 			->addScalarResult('t_id', 't_id', 'integer')
 			->addScalarResult('t_title', 't_title', 'string')
 			->addScalarResult('l_id', 'l_id', 'integer')
 			->addScalarResult('l_short', 'l_short', 'string')
 			->addScalarResult('l_title', 'l_title', 'string')
 			->addScalarResult('a_id', 'a_id', 'integer')
-			->addScalarResult('a_u_id', 'a_u_id', 'integer')
-			->addScalarResult('a_u_pseudonym', 'a_u_pseudonym', 'string')
+			->addScalarResult('a_canceled', 'a_canceled', 'datetime')
+			->addScalarResult('au_id', 'au_id', 'integer')
+			->addScalarResult('au_pseudonym', 'au_pseudonym', 'string')
 			//XXX: is a string because of \n separator
-			->addScalarResult('as_u_id', 'as_u_id', 'string')
+			->addScalarResult('sau_id', 'sau_id', 'string')
 			//XXX: is a string because of \n separator
-			->addScalarResult('as_u_pseudonym', 'as_u_pseudonym', 'string')
+			->addScalarResult('sau_pseudonym', 'sau_pseudonym', 'string')
 			->addIndexByScalar('id');
 
 		//Fetch result
 		$res = $em
 			->createNativeQuery($req, $rsm)
 			->setParameter('begin', $period->getStartDate())
-			->setParameter('end', $period->getEndDate())
-			->setParameter('lid', $locationId)
-			->getResult();
+			->setParameter('end', $period->getEndDate());
+
+		//Add optional location id
+		if (!empty($locationId)) {
+			$res->setParameter('lid', $locationId);
+		}
+
+		//Get result
+		$res = $res->getResult();
 
 		//Init calendar
 		$calendar = [];
@@ -321,7 +450,7 @@ SQL;
 		foreach($period as $date) {
 			//Init day in calendar
 			$calendar[$Ymd = $date->format('Ymd')] = [
-				'title' => $date->format('d'),
+				'title' => $translator->trans($date->format('l')).' '.$date->format('d'),
 				'class' => [],
 				'sessions' => []
 			];
@@ -349,24 +478,33 @@ SQL;
 			//Set next month days
 			if ($date->format('m') > date('m')) {
 				$calendar[$Ymd]['next'] = true;
-				$calendar[$Ymd]['class'][] = 'next';
+				#$calendar[$Ymd]['class'][] = 'next';
+			}
+
+			//Detect sunday
+			if ($date->format('w') == 0) {
+				$calendar[$Ymd]['class'][] = 'sunday';
 			}
 
 			//Iterate on each session to find the one of the day
 			foreach($res as $session) {
 				if (($sessionYmd = $session['date']->format('Ymd')) == $Ymd) {
 					//Count number of application
-					$count = count(explode("\n", $session['as_u_id']));
+					$count = count(explode("\n", $session['sau_id']));
 
 					//Compute classes
 					$class = [];
 					if (!empty($session['a_id'])) {
-						$applications = [ $session['a_u_id'] => $session['a_u_pseudonym'] ];
-						$class[] = 'granted';
-					} elseif ($count == 0) {
-						$class[] = 'orphaned';
+						$applications = [ $session['au_id'] => $session['au_pseudonym'] ];
+						if (!empty($session['a_canceled'])) {
+							$class[] = 'canceled';
+						} else {
+							$class[] = 'granted';
+						}
 					} elseif ($count > 1) {
 						$class[] = 'disputed';
+					} elseif (!empty($session['locked'])) {
+						$class[] = 'locked';
 					} else {
 						$class[] = 'pending';
 					}
@@ -426,31 +564,34 @@ SQL;
 					];
 
 					//Fetch pseudonyms from session applications
-					$applications += array_combine(explode("\n", $session['as_u_id']), array_map(function ($v) {return '- '.$v;}, explode("\n", $session['as_u_pseudonym'])));
+					$applications += array_combine(explode("\n", $session['sau_id']), array_map(function ($v) {return '- '.$v;}, explode("\n", $session['sau_pseudonym'])));
+
+					//Set pseudonym
+					$pseudonym = null;
 
 					//Check that session is not granted
 					if (empty($session['a_id'])) {
 						//With location id and unique application
-						if ($locationId && $count == 1) {
-							//Set unique application pseudonym as title
-							$title = $session['as_u_pseudonym'];
-						//Without location id or multiple application
-						} else {
-							//Set location title with optional count
-							$title = $translator->trans($session['l_title']).($count > 1 ? ' ['.$count.']':'');
+						if ($count == 1) {
+							//Set unique application pseudonym
+							$pseudonym = $session['sau_pseudonym'];
 						}
 					//Session is granted
 					} else {
 						//Replace granted application
-						$applications[$session['a_u_id']] = '* '.$session['a_u_pseudonym'];
-						//Set pseudonym with optional location title and count
-						$title = $session['a_u_pseudonym'].($locationId?'':' '.$translator->trans('at '.$session['l_short'])).($count > 1 ? ' ['.$count.']':'');
+						$applications[$session['au_id']] = '* '.$session['au_pseudonym'];
+
+						//Set pseudonym
+						$pseudonym = $session['au_pseudonym'].($count > 1 ? ' ['.$count.']':'');
 					}
 
 					//Add the session
-					$calendar[$Ymd]['sessions'][$session['t_id'].sprintf('%02d', $session['l_id'])] = [
+					$calendar[$Ymd]['sessions'][$session['t_id'].sprintf('%05d', $session['id'])] = [
 						'id' => $session['id'],
-						'title' => $title,
+						'start' => $session['start'],
+						'stop' => $session['stop'],
+						'location' => $translator->trans($session['l_short']),
+						'pseudonym' => $pseudonym,
 						'class' => $class,
 						'slot' => self::GLYPHS[$session['t_title']],
 						'slottitle' => $translator->trans($session['t_title']),
@@ -495,24 +636,56 @@ SQL;
 			'RapsysAirBundle:Location' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Location'), $dp),
 			'RapsysAirBundle:Slot' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Slot'), $dp),
 			'RapsysAirBundle:User' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:User'), $dp),
+			':afterid' => 4,
 			"\t" => '',
 			"\n" => ' '
 		];
 
+		//Init user sql
+		$userJoinSql = $userWhereSql = '';
+
+		//When user id is set
+		if (!empty($userId)) {
+			//Add user join
+			$userJoinSql = 'JOIN RapsysAirBundle:Application AS sua ON (sua.session_id = s.id)'."\n";
+			//Add user id clause
+			$userWhereSql = "\n\t".'AND sua.user_id = :uid';
+		}
+
 		//Set the request
-		$req = 'SELECT s.id, s.date, s.rainrisk, s.rainfall, s.realfeel, s.temperature, s.location_id AS l_id, l.short AS l_short, l.title AS l_title, s.slot_id AS t_id, t.title AS t_title, s.application_id AS a_id, a.user_id AS a_u_id, au.pseudonym AS a_u_pseudonym, GROUP_CONCAT(sa.user_id ORDER BY sa.user_id SEPARATOR "\n") AS as_u_id, GROUP_CONCAT(CONCAT("- ", sau.pseudonym) ORDER BY sa.user_id SEPARATOR "\n") AS as_u_pseudonym
-			FROM RapsysAirBundle:Session AS s
-			JOIN RapsysAirBundle:Location AS l ON (l.id = s.location_id)
-			JOIN RapsysAirBundle:Slot AS t ON (t.id = s.slot_id)
-			'.($userId?'JOIN RapsysAirBundle:Application AS sua ON (sua.session_id = s.id)':'').'
-			LEFT JOIN RapsysAirBundle:Application AS a ON (a.id = s.application_id)
-			LEFT JOIN RapsysAirBundle:User AS au ON (au.id = a.user_id)
-			LEFT JOIN RapsysAirBundle:Application AS sa ON (sa.session_id = s.id)
-			LEFT JOIN RapsysAirBundle:User AS sau ON (sau.id = sa.user_id)
-			WHERE s.date BETWEEN :begin AND :end
-			'.($userId?'AND sua.user_id = :uid':'').'
-			GROUP BY s.id
-			ORDER BY NULL';
+		//TODO: change as_u_* in sau_*, a_u_* in au_*, etc, see request up
+		$req = <<<SQL
+SELECT
+	s.id,
+	s.date,
+	s.rainrisk,
+	s.rainfall,
+	s.realfeel,
+	s.temperature,
+	s.locked,
+	ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY) AS start,
+	ADDDATE(ADDTIME(ADDTIME(s.date, s.begin), s.length), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY) AS stop,
+	s.location_id AS l_id,
+	l.short AS l_short,
+	l.title AS l_title,
+	s.slot_id AS t_id,
+	t.title AS t_title,
+	s.application_id AS a_id,
+	a.user_id AS au_id,
+	au.pseudonym AS au_pseudonym,
+	GROUP_CONCAT(sa.user_id ORDER BY sa.user_id SEPARATOR "\\n") AS sau_id,
+	GROUP_CONCAT(CONCAT("- ", sau.pseudonym) ORDER BY sa.user_id SEPARATOR "\\n") AS sau_pseudonym
+FROM RapsysAirBundle:Session AS s
+JOIN RapsysAirBundle:Location AS l ON (l.id = s.location_id)
+JOIN RapsysAirBundle:Slot AS t ON (t.id = s.slot_id)
+${userJoinSql}LEFT JOIN RapsysAirBundle:Application AS a ON (a.id = s.application_id)
+LEFT JOIN RapsysAirBundle:User AS au ON (au.id = a.user_id)
+LEFT JOIN RapsysAirBundle:Application AS sa ON (sa.session_id = s.id)
+LEFT JOIN RapsysAirBundle:User AS sau ON (sau.id = sa.user_id)
+WHERE s.date BETWEEN :begin AND :end${userWhereSql}
+GROUP BY s.id
+ORDER BY NULL
+SQL;
 
 		//Replace bundle entity name by table name
 		$req = str_replace(array_keys($tables), array_values($tables), $req);
@@ -530,18 +703,21 @@ SQL;
 			->addScalarResult('rainfall', 'rainfall', 'float')
 			->addScalarResult('realfeel', 'realfeel', 'float')
 			->addScalarResult('temperature', 'temperature', 'float')
+			->addScalarResult('locked', 'locked', 'datetime')
+			->addScalarResult('start', 'start', 'datetime')
+			->addScalarResult('stop', 'stop', 'datetime')
 			->addScalarResult('t_id', 't_id', 'integer')
 			->addScalarResult('t_title', 't_title', 'string')
 			->addScalarResult('l_id', 'l_id', 'integer')
 			->addScalarResult('l_short', 'l_short', 'string')
 			->addScalarResult('l_title', 'l_title', 'string')
 			->addScalarResult('a_id', 'a_id', 'integer')
-			->addScalarResult('a_u_id', 'a_u_id', 'integer')
-			->addScalarResult('a_u_pseudonym', 'a_u_pseudonym', 'string')
+			->addScalarResult('au_id', 'au_id', 'integer')
+			->addScalarResult('au_pseudonym', 'au_pseudonym', 'string')
 			//XXX: is a string because of \n separator
-			->addScalarResult('as_u_id', 'as_u_id', 'string')
+			->addScalarResult('sau_id', 'sau_id', 'string')
 			//XXX: is a string because of \n separator
-			->addScalarResult('as_u_pseudonym', 'as_u_pseudonym', 'string')
+			->addScalarResult('sau_pseudonym', 'sau_pseudonym', 'string')
 			->addIndexByScalar('id');
 
 		//Fetch result
@@ -562,7 +738,7 @@ SQL;
 		foreach($period as $date) {
 			//Init day in calendar
 			$calendar[$Ymd = $date->format('Ymd')] = [
-				'title' => $date->format('d'),
+				'title' => $translator->trans($date->format('l')).' '.$date->format('d'),
 				'class' => [],
 				'sessions' => []
 			];
@@ -590,28 +766,33 @@ SQL;
 			//Set next month days
 			if ($date->format('m') > date('m')) {
 				$calendar[$Ymd]['next'] = true;
-				$calendar[$Ymd]['class'][] = 'next';
+				#$calendar[$Ymd]['class'][] = 'next';
+			}
+
+			//Detect sunday
+			if ($date->format('w') == 0) {
+				$calendar[$Ymd]['class'][] = 'sunday';
 			}
 
 			//Iterate on each session to find the one of the day
 			foreach($res as $session) {
 				if (($sessionYmd = $session['date']->format('Ymd')) == $Ymd) {
 					//Count number of application
-					$count = count(explode("\n", $session['as_u_id']));
+					$count = count(explode("\n", $session['sau_id']));
 
 					//Compute classes
 					$class = [];
 					if (!empty($session['a_id'])) {
-						$applications = [ $session['a_u_id'] => $session['a_u_pseudonym'] ];
-						if ($session['a_u_id'] == $userId) {
+						$applications = [ $session['au_id'] => $session['au_pseudonym'] ];
+						if ($session['au_id'] == $userId) {
 							$class[] = 'granted';
 						} else {
 							$class[] = 'disputed';
 						}
-					} elseif ($count == 0) {
-						$class[] = 'orphaned';
 					} elseif ($count > 1) {
 						$class[] = 'disputed';
+					} elseif (!empty($session['locked'])) {
+						$class[] = 'locked';
 					} else {
 						$class[] = 'pending';
 					}
@@ -670,16 +851,26 @@ SQL;
 						0 => $translator->trans($session['t_title']).' '.$translator->trans('at '.$session['l_title']).$translator->trans(':')
 					];
 
+					//Fetch pseudonyms from session applications
+					$applications += array_combine(explode("\n", $session['sau_id']), array_map(function ($v) {return '- '.$v;}, explode("\n", $session['sau_pseudonym'])));
+
+					//Set pseudonym
+					$pseudonym = null;
+
 					//Check that session is not granted
 					if (empty($session['a_id'])) {
-						//Fetch pseudonyms from session applications
-						$applications += array_combine(explode("\n", $session['as_u_id']), explode("\n", $session['as_u_pseudonym']));
+						//With location id and unique application
+						if ($count == 1) {
+							//Set unique application pseudonym
+							$pseudonym = $session['sau_pseudonym'];
+						}
 					//Session is granted
 					} else {
-						//Fetch pseudonyms from session applications
-						$applications += array_combine(explode("\n", $session['as_u_id']), explode("\n", $session['as_u_pseudonym']));
 						//Replace granted application
-						$applications[$session['a_u_id']] = '* '.$session['a_u_pseudonym'];
+						$applications[$session['au_id']] = '* '.$session['au_pseudonym'];
+
+						//Set pseudonym
+						$pseudonym = $session['au_pseudonym'].($count > 1 ? ' ['.$count.']':'');
 					}
 
 					//Set title
@@ -688,7 +879,10 @@ SQL;
 					//Add the session
 					$calendar[$Ymd]['sessions'][$session['t_id'].sprintf('%02d', $session['l_id'])] = [
 						'id' => $session['id'],
-						'title' => $title,
+						'start' => $session['start'],
+						'stop' => $session['stop'],
+						'location' => $translator->trans($session['l_short']),
+						'pseudonym' => $pseudonym,
 						'class' => $class,
 						'slot' => self::GLYPHS[$session['t_title']],
 						'slottitle' => $translator->trans($session['t_title']),
@@ -708,11 +902,11 @@ SQL;
 	}
 
 	/**
-	 * Find every session pending application
+	 * Find all session pending hourly weather
 	 *
 	 * @return array<Session> The sessions to update
 	 */
-	public function findAllPendingApplication() {
+	public function findAllPendingHourlyWeather() {
 		//Get entity manager
 		$em = $this->getEntityManager();
 
@@ -724,22 +918,22 @@ SQL;
 		//XXX: this allow to make this code table name independent
 		$tables = [
 			'RapsysAirBundle:Session' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Session'), $dp),
+			'RapsysAirBundle:Location' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Location'), $dp),
+			//Accuweather
+			':accuhourly' => self::ACCUWEATHER_HOURLY,
+			//Delay
+			':afterid' => 4,
 			"\t" => '',
 			"\n" => ' '
 		];
 
-		//Select all sessions without application attributed with diff(start, now) <= if(diff(start, created) <= GOOD_DELAY day, diff(start, created)*3/4, GOOD_DELAY day)
-		//XXX: consider only unfinished sessions with stop > now
-		//XXX: consider creation enough in the past when we are after 1/4 of the period between creation and start time
-		//XXX: we may remove ADDDATE(start, INTERVAL IF(s.slot_id = 4, 1, 0) DAY) used for after specificity
-		$req =<<<SQL
-SELECT s.id
+		//Select all sessions starting and stopping in the next 3 days
+		//XXX: select session starting after now and stopping before date(now)+3d as accuweather only provide hourly data for the next 3 days (INTERVAL 3 DAY)
+		$req = <<<SQL
+SELECT s.id, s.slot_id, s.location_id, s.date, s.begin, s.length, s.rainfall, s.rainrisk, s.realfeel, s.realfeelmin, s.realfeelmax, s.temperature, s.temperaturemin, s.temperaturemax, l.zipcode
 FROM RapsysAirBundle:Session AS s
-WHERE
-	s.application_id IS NULL AND
-	ADDDATE(ADDTIME(ADDTIME(s.date, s.begin), s.length), INTERVAL IF(s.slot_id = 4, 1, 0) DAY) > NOW() AND
-	TIMEDIFF(ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = 4, 1, 0) DAY), NOW()) <= IF(DATEDIFF(ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = 4, 1, 0) DAY), s.created) <= :gooddelay, SEC_TO_TIME(TIME_TO_SEC(TIMEDIFF(ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = 4, 1, 0) DAY), s.created))*3/4), SEC_TO_TIME(:gooddelay*24*3600))
-ORDER BY ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = 4, 1, 0) DAY) ASC, s.created ASC
+JOIN RapsysAirBundle:Location AS l ON (l.id = s.location_id)
+WHERE ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY) >= NOW() AND ADDDATE(ADDTIME(ADDTIME(s.date, s.begin), s.length), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY) < DATE(ADDDATE(NOW(), INTERVAL :accuhourly DAY))
 SQL;
 
 		//Replace bundle entity name by table name
@@ -752,22 +946,36 @@ SQL;
 		$rsm
 			->addEntityResult('RapsysAirBundle:Session', 's')
 			->addFieldResult('s', 'id', 'id')
+			->addFieldResult('s', 'date', 'date')
+			->addFieldResult('s', 'begin', 'begin')
+			->addFieldResult('s', 'length', 'length')
+			->addFieldResult('s', 'rainfall', 'rainfall')
+			->addFieldResult('s', 'rainrisk', 'rainrisk')
+			->addFieldResult('s', 'realfeel', 'realfeel')
+			->addFieldResult('s', 'realfeelmin', 'realfeelmin')
+			->addFieldResult('s', 'realfeelmax', 'realfeelmax')
+			->addFieldResult('s', 'temperature', 'temperature')
+			->addFieldResult('s', 'temperaturemin', 'temperaturemin')
+			->addFieldResult('s', 'temperaturemax', 'temperaturemax')
+			->addJoinedEntityResult('RapsysAirBundle:Slot', 'o', 's', 'slot')
+			->addFieldResult('o', 'slot_id', 'id')
+			->addJoinedEntityResult('RapsysAirBundle:Location', 'l', 's', 'location')
+			->addFieldResult('l', 'location_id', 'id')
+			->addFieldResult('l', 'zipcode', 'zipcode')
 			->addIndexBy('s', 'id');
 
 		//Send result
 		return $em
 			->createNativeQuery($req, $rsm)
-			->setParameter('limit', PHP_INT_MAX)
-			->setParameter('gooddelay', self::GOOD_DELAY)
 			->getResult();
 	}
 
 	/**
-	 * Find all session pending hourly weather
+	 * Find all session pending daily weather
 	 *
 	 * @return array<Session> The sessions to update
 	 */
-	public function findAllPendingHourlyWeather() {
+	public function findAllPendingDailyWeather() {
 		//Get entity manager
 		$em = $this->getEntityManager();
 
@@ -779,21 +987,23 @@ SQL;
 		//XXX: this allow to make this code table name independent
 		$tables = [
 			'RapsysAirBundle:Session' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Session'), $dp),
-			'RapsysAirBundle:Slot' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Slot'), $dp),
 			'RapsysAirBundle:Location' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Location'), $dp),
+			//Accuweather
+			':accudaily' => self::ACCUWEATHER_DAILY,
+			':accuhourly' => self::ACCUWEATHER_HOURLY,
+			//Delay
+			':afterid' => 4,
 			"\t" => '',
 			"\n" => ' '
 		];
 
-		//Select all sessions starting and stopping in the next 3 days
-		//XXX: select session starting after now and stopping before date(now)+3d as accuweather only provide hourly data for the next 3 days (INTERVAL 3 DAY)
-		//XXX: we may remove ADDDATE(start, INTERVAL IF(s.slot_id = 4, 1, 0) DAY) used for after specificity
+		//Select all sessions stopping after next 3 days
+		//XXX: select session stopping after or equal date(now)+3d as accuweather only provide hourly data for the next 3 days (INTERVAL 3 DAY)
 		$req = <<<SQL
-SELECT s.id, s.slot_id, s.location_id, s.date, s.begin, s.length, s.rainfall, s.rainrisk, s.realfeel, s.realfeelmin, s.realfeelmax, s.temperature, s.temperaturemin, s.temperaturemax, l.zipcode, o.title
+SELECT s.id, s.slot_id, s.location_id, s.date, s.begin, s.length, s.rainfall, s.rainrisk, s.realfeel, s.realfeelmin, s.realfeelmax, s.temperature, s.temperaturemin, s.temperaturemax, l.zipcode
 FROM RapsysAirBundle:Session AS s
-JOIN RapsysAirBundle:Slot AS o ON (o.id = s.slot_id)
 JOIN RapsysAirBundle:Location AS l ON (l.id = s.location_id)
-WHERE ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = 4, 1, 0) DAY) >= NOW() AND ADDDATE(ADDTIME(ADDTIME(s.date, s.begin), s.length), INTERVAL IF(s.slot_id = 4, 1, 0) DAY) < DATE(ADDDATE(NOW(), INTERVAL :accuhourly DAY))
+WHERE ADDDATE(ADDTIME(ADDTIME(s.date, s.begin), s.length), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY) >= DATE(ADDDATE(NOW(), INTERVAL :accuhourly DAY)) AND ADDDATE(ADDTIME(ADDTIME(s.date, s.begin), s.length), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY) < DATE(ADDDATE(NOW(), INTERVAL :accudaily DAY))
 SQL;
 
 		//Replace bundle entity name by table name
@@ -819,7 +1029,6 @@ SQL;
 			->addFieldResult('s', 'temperaturemax', 'temperaturemax')
 			->addJoinedEntityResult('RapsysAirBundle:Slot', 'o', 's', 'slot')
 			->addFieldResult('o', 'slot_id', 'id')
-			->addFieldResult('o', 'title', 'title')
 			->addJoinedEntityResult('RapsysAirBundle:Location', 'l', 's', 'location')
 			->addFieldResult('l', 'location_id', 'id')
 			->addFieldResult('l', 'zipcode', 'zipcode')
@@ -828,16 +1037,15 @@ SQL;
 		//Send result
 		return $em
 			->createNativeQuery($req, $rsm)
-			->setParameter('accuhourly', self::ACCUWEATHER_HOURLY)
 			->getResult();
 	}
 
 	/**
-	 * Find all session pending daily weather
+	 * Find every session pending application
 	 *
 	 * @return array<Session> The sessions to update
 	 */
-	public function findAllPendingDailyWeather() {
+	public function findAllPendingApplication() {
 		//Get entity manager
 		$em = $this->getEntityManager();
 
@@ -848,24 +1056,36 @@ SQL;
 		//Get quoted table names
 		//XXX: this allow to make this code table name independent
 		$tables = [
+			'RapsysAirBundle:Application' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Application'), $dp),
 			'RapsysAirBundle:Session' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Session'), $dp),
-			'RapsysAirBundle:Slot' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Slot'), $dp),
-			'RapsysAirBundle:Location' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Location'), $dp),
+			//Delay
+			':regulardelay' => self::REGULAR_DELAY * 24 * 3600,
+			':seniordelay' => self::SENIOR_DELAY * 24 * 3600,
+			//Slot
+			':afterid' => 4,
 			"\t" => '',
 			"\n" => ' '
 		];
 
-		//Select all sessions stopping after next 3 days
-		//XXX: select session stopping after or equal date(now)+3d as accuweather only provide hourly data for the next 3 days (INTERVAL 3 DAY)
-		//XXX: we may remove ADDDATE(start, INTERVAL IF(s.slot_id = 4, 1, 0) DAY) used for after specificity
-		$req = <<<SQL
-SELECT s.id, s.slot_id, s.location_id, s.date, s.begin, s.length, s.rainfall, s.rainrisk, s.realfeel, s.realfeelmin, s.realfeelmax, s.temperature, s.temperaturemin, s.temperaturemax, l.zipcode, o.title
-FROM RapsysAirBundle:Session AS s
-JOIN RapsysAirBundle:Slot AS o ON (o.id = s.slot_id)
-JOIN RapsysAirBundle:Location AS l ON (l.id = s.location_id)
-WHERE ADDDATE(ADDTIME(ADDTIME(s.date, s.begin), s.length), INTERVAL IF(s.slot_id = 4, 1, 0) DAY) >= DATE(ADDDATE(NOW(), INTERVAL :accuhourly DAY)) AND ADDDATE(ADDTIME(ADDTIME(s.date, s.begin), s.length), INTERVAL IF(s.slot_id = 4, 1, 0) DAY) < DATE(ADDDATE(NOW(), INTERVAL :accudaily DAY))
+		//Select all sessions not locked without application or canceled application within attribution period
+		//XXX: DIFF(start, now) <= IF(DIFF(start, created) <= SENIOR_DELAY in DAY, DIFF(start, created) * 3 / 4, SENIOR_DELAY)
+		//TODO: remonter les données pour le mail ?
+		$req =<<<SQL
+SELECT s.id
+FROM RapsysAirBundle:Session as s
+LEFT JOIN RapsysAirBundle:Application AS a ON (a.id = s.application_id AND a.canceled IS NULL)
+JOIN RapsysAirBundle:Application AS a2 ON (a2.session_id = s.id AND a2.canceled IS NULL)
+WHERE s.locked IS NULL AND a.id IS NULL AND
+TIME_TO_SEC(TIMEDIFF(@dt_start := ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY), NOW())) <= IF(
+	TIME_TO_SEC(@td_sc := TIMEDIFF(@dt_start, s.created)) <= :seniordelay,
+	ROUND(TIME_TO_SEC(@td_sc) * :regulardelay / :seniordelay),
+	:seniordelay
+)
+GROUP BY s.id
+ORDER BY @dt_start ASC, s.created ASC
 SQL;
 
+
 		//Replace bundle entity name by table name
 		$req = str_replace(array_keys($tables), array_values($tables), $req);
 
@@ -876,30 +1096,11 @@ SQL;
 		$rsm
 			->addEntityResult('RapsysAirBundle:Session', 's')
 			->addFieldResult('s', 'id', 'id')
-			->addFieldResult('s', 'date', 'date')
-			->addFieldResult('s', 'begin', 'begin')
-			->addFieldResult('s', 'length', 'length')
-			->addFieldResult('s', 'rainfall', 'rainfall')
-			->addFieldResult('s', 'rainrisk', 'rainrisk')
-			->addFieldResult('s', 'realfeel', 'realfeel')
-			->addFieldResult('s', 'realfeelmin', 'realfeelmin')
-			->addFieldResult('s', 'realfeelmax', 'realfeelmax')
-			->addFieldResult('s', 'temperature', 'temperature')
-			->addFieldResult('s', 'temperaturemin', 'temperaturemin')
-			->addFieldResult('s', 'temperaturemax', 'temperaturemax')
-			->addJoinedEntityResult('RapsysAirBundle:Slot', 'o', 's', 'slot')
-			->addFieldResult('o', 'slot_id', 'id')
-			->addFieldResult('o', 'title', 'title')
-			->addJoinedEntityResult('RapsysAirBundle:Location', 'l', 's', 'location')
-			->addFieldResult('l', 'location_id', 'id')
-			->addFieldResult('l', 'zipcode', 'zipcode')
 			->addIndexBy('s', 'id');
 
 		//Send result
 		return $em
 			->createNativeQuery($req, $rsm)
-			->setParameter('accudaily', self::ACCUWEATHER_DAILY)
-			->setParameter('accuhourly', self::ACCUWEATHER_HOURLY)
 			->getResult();
 	}
 
@@ -921,81 +1122,154 @@ SQL;
 		//XXX: this allow to make this code table name independent
 		$tables = [
 			'RapsysAirBundle:Application' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Application'), $dp),
+			'RapsysAirBundle:GroupUser' => $qs->getJoinTableName($em->getClassMetadata('RapsysAirBundle:User')->getAssociationMapping('groups'), $em->getClassMetadata('RapsysAirBundle:User'), $dp),
+			'RapsysAirBundle:Location' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Location'), $dp),
 			'RapsysAirBundle:Session' => $qs->getTableName($em->getClassMetadata('RapsysAirBundle:Session'), $dp),
+			//XXX: Set limit used to workaround mariadb subselect optimization
+			':limit' => PHP_INT_MAX,
+			//Delay
+			':guestdelay' => self::GUEST_DELAY * 24 * 3600,
+			':regulardelay' => self::REGULAR_DELAY * 24 * 3600,
+			':seniordelay' => self::SENIOR_DELAY * 24 * 3600,
+			//Group
+			':guestid' => 2,
+			':regularid' => 3,
+			':seniorid' => 4,
+			//Slot
+			':afternoonid' => 2,
+			':eveningid' => 3,
+			':afterid' => 4,
+			//XXX: days since last session after which guest regain normal priority
+			':guestwait' => 30,
+			//XXX: session count until considered at regular delay
+			':scount' => 5,
+			//XXX: pn_ratio over which considered at regular delay
+			':pnratio' => 1,
+			//XXX: tr_ratio diff over which considered at regular delay
+			':trdiff' => 5,
 			"\t" => '',
 			"\n" => ' '
 		];
 
 		/**
-		 * Query session applications ranked by score, created and user_id
+		 * Query session applications ranked by location score, global score, created and user_id
 		 *
-		 * @xxx User with bad behaviour application are excluded until remaining <= baddelay:
-		 * - with (count(premium = 1)+1)/(count(premium = 0)+1) >= 1
-		 * - with count(sessions) <= 5
-		 * - with average(temperature) >= average(temperature other) + 10
+		 * @xxx guest (or less) with application on location within 30 day are only considered within guestdelay
 		 *
-		 * @xxx Magic happen on this line:
-		 * WHERE IF(d.pnp_rate >= 1, d.remaining <= SEC_TO_TIME(:baddelay), 1) AND IF(d.s_count <= 5, d.remaining <= SEC_TO_TIME(:baddelay), 1) AND IF(d.tr_rate >= (d.otr_rate + 10), d.remaining <= SEC_TO_TIME(:baddelay), 1)
+		 * @xxx regular (or less) premium application on hotspot are only considered within regulardelay
 		 *
-		 * @todo Limit score on last year only ???
-		 * AND DATEDIFF(s.date, NOW()) <= 365
+		 * @xxx senior (or less) with 5 or less session on location are only considered within seniordelay
+		 *
+		 * @xxx senior (or less) with l_pn_ratio >= 1 are only considered within seniordelay
+		 *
+		 * @xxx senior (or less) with l_tr_ratio >= (o_tr_ratio + 5) are only considered within seniordelay
+		 *
+		 * @xxx only consider session within one year (may be unaccurate by the day with after session)
+		 *
+		 * @xxx rainfall may not be accessible for previous session and other session at d-4 (only at d-2)
+		 *
+		 * @todo ??? feedback the data to inform the rejected users ???
 		 */
 		$req = <<<SQL
-SELECT d.id, d.score
+SELECT e.id, e.l_score AS score
 FROM (
 	SELECT
-		c.id,
-		c.session_id,
-		c.user_id,
-		c.score,
-		c.remaining,
-		c.created,
-		c.s_count,
-		c.tr_rate,
-		AVG(IF(a4.id IS NOT NULL, s4.temperature/(1+s4.rainfall), NULL)) AS otr_rate,
-		c.pnp_rate
+		d.id,
+		d.user_id,
+		d.l_count,
+		d.l_score,
+		d.l_tr_ratio,
+		d.l_pn_ratio,
+		d.l_previous,
+		d.g_score,
+		d.o_tr_ratio,
+		MAX(gu.group_id) AS group_id,
+		d.remaining,
+		d.premium,
+		d.hotspot,
+		d.created
 	FROM (
 		SELECT
-			b.id,
-			b.session_id,
-			b.user_id,
-			b.score,
-			b.remaining,
-			b.created,
-			COUNT(a3.id) AS s_count,
-			AVG(IF(a3.id IS NOT NULL AND s3.temperature IS NOT NULL AND s3.rainfall IS NOT NULL, s3.temperature/(1+s3.rainfall), NULL)) AS tr_rate,
-			(SUM(IF(a3.id IS NOT NULL AND s3.premium = 1, 1, 0))+1)/(SUM(IF(a3.id IS NOT NULL AND s3.premium = 0, 1, 0))+1) AS pnp_rate
+			c.id,
+			c.user_id,
+			c.l_count,
+			c.l_score,
+			c.l_tr_ratio,
+			c.l_pn_ratio,
+			c.l_previous,
+			c.g_score,
+			AVG(IF(a4.id IS NOT NULL AND s4.temperature IS NOT NULL AND s4.rainfall IS NOT NULL, s4.temperature/(1+s4.rainfall), NULL)) AS o_tr_ratio,
+			c.remaining,
+			c.premium,
+			c.hotspot,
+			c.created
 		FROM (
 			SELECT
-				a.id,
-				s.id AS session_id,
-				a.user_id,
-				SUM(IF(a2.id IS NOT NULL, 1/ABS(DATEDIFF(s.date, s2.date)), 0)) AS score,
-				TIMEDIFF(ADDTIME(s.date, s.begin), NOW()) AS remaining,
-				a.created
-			FROM sessions AS s
-			JOIN applications AS a ON (a.session_id = s.id AND a.canceled IS NULL)
-			LEFT JOIN sessions AS s2 ON (s2.id != s.id AND s2.location_id = s.location_id AND s2.slot_id = s.slot_id AND s2.application_id IS NOT NULL)
-			LEFT JOIN applications AS a2 ON (a2.id = s2.application_id AND a2.user_id = a.user_id AND (a2.canceled IS NULL OR TIMESTAMPDIFF(DAY, a2.canceled, ADDTIME(s2.date, s2.begin)) < 1))
-			WHERE s.id = :sid
-			GROUP BY a.id
+				b.id,
+				b.user_id,
+				b.session_id,
+				b.date,
+				b.location_id,
+				b.l_count,
+				b.l_score,
+				b.l_tr_ratio,
+				b.l_pn_ratio,
+				b.l_previous,
+				SUM(IF(a3.id IS NOT NULL, 1/ABS(DATEDIFF(ADDDATE(b.date, INTERVAL IF(b.slot_id = :afterid, 1, 0) DAY), ADDDATE(s3.date, INTERVAL IF(s3.slot_id = :afterid, 1, 0) DAY))), 0)) AS g_score,
+				b.remaining,
+				b.premium,
+				b.hotspot,
+				b.created
+			FROM (
+				SELECT
+					a.id,
+					a.user_id,
+					s.id AS session_id,
+					s.date AS date,
+					s.slot_id,
+					s.location_id,
+					COUNT(a2.id) AS l_count,
+					SUM(IF(a2.id IS NOT NULL, 1/ABS(DATEDIFF(ADDDATE(s.date, INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY), ADDDATE(s2.date, INTERVAL IF(s2.slot_id = :afterid, 1, 0) DAY))), 0)) AS l_score,
+					AVG(IF(a2.id IS NOT NULL AND s2.temperature IS NOT NULL AND s2.rainfall IS NOT NULL, s2.temperature/(1+s2.rainfall), NULL)) AS l_tr_ratio,
+					(SUM(IF(a2.id IS NOT NULL AND s2.premium = 1, 1, 0))+1)/(SUM(IF(a2.id IS NOT NULL AND s2.premium = 0, 1, 0))+1) AS l_pn_ratio,
+					MIN(IF(a2.id IS NOT NULL, DATEDIFF(ADDDATE(s.date, INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY), ADDDATE(s2.date, INTERVAL IF(s2.slot_id = :afterid, 1, 0) DAY)), NULL)) AS l_previous,
+					TIME_TO_SEC(TIMEDIFF(ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY), NOW())) AS remaining,
+					s.premium,
+					l.hotspot,
+					a.created
+				FROM RapsysAirBundle:Session AS s
+				JOIN RapsysAirBundle:Location AS l ON (l.id = s.location_id)
+				JOIN RapsysAirBundle:Application AS a ON (a.session_id = s.id AND a.canceled IS NULL)
+				LEFT JOIN RapsysAirBundle:Session AS s2 ON (s2.id != s.id AND s2.location_id = s.location_id AND s2.slot_id IN (:afternoonid, :eveningid) AND s2.application_id IS NOT NULL AND s2.locked IS NULL AND s2.date > s.date - INTERVAL 1 YEAR)
+				LEFT JOIN RapsysAirBundle:Application AS a2 ON (a2.id = s2.application_id AND a2.user_id = a.user_id AND (a2.canceled IS NULL OR TIMESTAMPDIFF(DAY, a2.canceled, ADDDATE(ADDTIME(s2.date, s2.begin), INTERVAL IF(s2.slot_id = :afterid, 1, 0) DAY)) < 1))
+				WHERE s.id = :sid
+				GROUP BY a.id
+				ORDER BY NULL
+				LIMIT 0, :limit
+			) AS b
+			LEFT JOIN RapsysAirBundle:Session AS s3 ON (s3.id != b.session_id AND s3.application_id IS NOT NULL AND s3.locked IS NULL AND s3.date > b.date - INTERVAL 1 YEAR)
+			LEFT JOIN RapsysAirBundle:Application AS a3 ON (a3.id = s3.application_id AND a3.user_id = b.user_id AND (a3.canceled IS NULL OR TIMESTAMPDIFF(DAY, a3.canceled, ADDDATE(ADDTIME(s3.date, s3.begin), INTERVAL IF(s3.slot_id = :afterid, 1, 0) DAY)) < 1))
+			GROUP BY b.id
 			ORDER BY NULL
 			LIMIT 0, :limit
-		) AS b
-		LEFT JOIN sessions AS s3 ON (s3.id != b.session_id AND s3.application_id IS NOT NULL)
-		LEFT JOIN applications AS a3 ON (a3.id = s3.application_id AND a3.user_id = b.user_id AND (a3.canceled IS NULL OR TIMESTAMPDIFF(DAY, a3.canceled, ADDTIME(s3.date, s3.begin)) < 1))
-		GROUP BY b.id
+		) AS c
+		LEFT JOIN RapsysAirBundle:Session AS s4 ON (s4.id != c.session_id AND s4.location_id = c.location_id AND s4.application_id IS NOT NULL AND s4.locked IS NULL AND s4.date > c.date - INTERVAL 1 YEAR)
+		LEFT JOIN RapsysAirBundle:Application AS a4 ON (a4.id = s4.application_id AND a4.user_id != c.user_id AND (a4.canceled IS NULL OR TIMESTAMPDIFF(DAY, a4.canceled, ADDDATE(ADDTIME(s4.date, s4.begin), INTERVAL IF(s4.slot_id = :afterid, 1, 0) DAY)) < 1))
+		GROUP BY c.id
 		ORDER BY NULL
 		LIMIT 0, :limit
-	) AS c
-	LEFT JOIN sessions AS s4 ON (s4.id != c.session_id AND s4.application_id IS NOT NULL AND s4.temperature IS NOT NULL AND s4.rainfall IS NOT NULL)
-	LEFT JOIN applications AS a4 ON (a4.id = s4.application_id AND a4.user_id != c.user_id AND (a4.canceled IS NULL OR TIMESTAMPDIFF(DAY, a4.canceled, ADDTIME(s4.date, s4.begin)) < 1))
-	GROUP BY c.id
-	ORDER BY NULL
+	) AS d
+	LEFT JOIN RapsysAirBundle:GroupUser AS gu ON (gu.user_id = d.user_id)
+	GROUP BY d.id
 	LIMIT 0, :limit
-) AS d
-WHERE IF(d.pnp_rate >= 1, d.remaining <= SEC_TO_TIME(:baddelay), 1) AND IF(d.s_count <= 5, d.remaining <= SEC_TO_TIME(:baddelay), 1) AND IF(d.tr_rate >= (d.otr_rate + 10), d.remaining <= SEC_TO_TIME(:baddelay), 1)
-ORDER BY d.score ASC, d.created ASC, d.user_id ASC
+) AS e
+WHERE
+	IF(e.group_id <= :guestid AND e.l_previous <= :guestwait, e.remaining <= :guestdelay, 1) AND
+	IF(e.group_id <= :regularid AND e.premium = 1 AND e.hotspot = 1, e.remaining <= :regulardelay, 1) AND
+	IF(e.group_id <= :seniorid AND e.l_count <= :scount, e.remaining <= :regulardelay, 1) AND
+	IF(e.group_id <= :seniorid AND e.l_pn_ratio >= :pnratio, e.remaining <= :regulardelay, 1) AND
+	IF(e.group_id <= :seniorid AND e.l_tr_ratio >= (e.o_tr_ratio + :trdiff), e.remaining <= :regulardelay, 1)
+ORDER BY e.l_score ASC, e.g_score ASC, e.created ASC, e.user_id ASC
 SQL;
 
 		//Replace bundle entity name by table name
@@ -1022,8 +1296,6 @@ SQL;
 		$applications = $em
 			->createNativeQuery($req, $rsm)
 			->setParameter('sid', $id)
-			->setParameter('baddelay', self::BAD_DELAY*24*3600)
-			->setParameter('limit', PHP_INT_MAX)
 			//XXX: removed, we update score before returning best candidate
 			//->getOneOrNullResult(Query::HYDRATE_SINGLE_SCALAR);
 			->getResult();