+
+ /**
+ * Find all session pending hourly weather
+ *
+ * @return array The sessions to update
+ */
+ public function findAllPendingHourlyWeather(): array {
+ //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
+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
+ $req = str_replace($this->tableKeys, $this->tableValues, $req);
+
+ //Get result set mapping instance
+ $rsm = new ResultSetMapping();
+
+ //Declare all fields
+ $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 $this->_em
+ ->createNativeQuery($req, $rsm)
+ ->getResult();
+ }
+
+ /**
+ * Find all session pending daily weather
+ *
+ * @return array The sessions to update
+ */
+ public function findAllPendingDailyWeather(): array {
+ //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
+FROM RapsysAirBundle:Session AS s
+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 = :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
+ $req = str_replace($this->tableKeys, $this->tableValues, $req);
+
+ //Get result set mapping instance
+ $rsm = new ResultSetMapping();
+
+ //Declare all fields
+ $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 $this->_em
+ ->createNativeQuery($req, $rsm)
+ ->getResult();
+ }
+
+ /**
+ * Find every session pending application
+ *
+ * @return array The sessions to update
+ */
+ public function findAllPendingApplication(): array {
+ //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 s.application_id IS NULL AND
+(UNIX_TIMESTAMP(@dt_start := ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY)) - UNIX_TIMESTAMP()) <= IF(
+ (@td_sc := UNIX_TIMESTAMP(@dt_start) - UNIX_TIMESTAMP(s.created)) <= :seniordelay,
+ ROUND(@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($this->tableKeys, $this->tableValues, $req);
+
+ //Get result set mapping instance
+ $rsm = new ResultSetMapping();
+
+ //Declare all fields
+ $rsm
+ ->addEntityResult('RapsysAirBundle:Session', 's')
+ ->addFieldResult('s', 'id', 'id')
+ ->addIndexBy('s', 'id');
+
+ //Send result
+ return $this->_em
+ ->createNativeQuery($req, $rsm)
+ ->getResult();
+ }
+
+ /**
+ * Fetch session best application by session id
+ *
+ * @param int $id The session id
+ * @return ?Application The application or null
+ */
+ public function findBestApplicationById(int $id): ?Application {
+ /**
+ * Query session applications ranked by location score, global score, created and user_id
+ *
+ * @xxx guest (or less) with application on location within 30 day are only considered within guestdelay
+ *
+ * @xxx regular (or less) premium application on hotspot are only considered within regulardelay
+ *
+ * @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 e.id, e.l_score AS score
+FROM (
+ SELECT
+ 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(ug.group_id) AS group_id,
+ d.remaining,
+ d.premium,
+ d.hotspot,
+ d.created
+ FROM (
+ SELECT
+ 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
+ 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,
+ UNIX_TIMESTAMP(ADDDATE(ADDTIME(s.date, s.begin), INTERVAL IF(s.slot_id = :afterid, 1, 0) DAY)) - UNIX_TIMESTAMP() 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 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 d
+ LEFT JOIN RapsysAirBundle:UserGroup AS ug ON (ug.user_id = d.user_id)
+ GROUP BY d.id
+ LIMIT 0, :limit
+) 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
+ $req = str_replace($this->tableKeys, $this->tableValues, $req);
+
+ //Set update request
+ $upreq = 'UPDATE RapsysAirBundle:Application SET score = :score, updated = NOW() WHERE id = :id';
+
+ //Replace bundle entity name by table name
+ $upreq = str_replace($this->tableKeys, $this->tableValues, $upreq);
+
+ //Get result set mapping instance
+ $rsm = new ResultSetMapping();
+
+ //Declare all fields
+ $rsm
+ ->addEntityResult('RapsysAirBundle:Application', 'a')
+ ->addFieldResult('a', 'id', 'id')
+ ->addFieldResult('a', 'score', 'score')
+ ->addIndexBy('a', 'id');
+
+ //Get result
+ //XXX: setting limit in subqueries is required to prevent mariadb optimisation
+ $applications = $this->_em
+ ->createNativeQuery($req, $rsm)
+ ->setParameter('sid', $id)
+ ->getResult();
+
+ //Init ret
+ $ret = null;
+
+ //Update score
+ foreach($applications as $application) {
+ //Check if we already saved best candidate
+ if ($ret === null) {
+ //Return first application
+ $ret = $application;
+ }
+
+ //Update application updated field
+ //XXX: updated field is not modified for user with bad behaviour as application is not retrieved until delay is reached
+ $this->_em->getConnection()->executeUpdate($upreq, ['id' => $application->getId(), 'score' => $application->getScore()], ['id' => Types::INTEGER, 'score' => Types::FLOAT]);
+ }
+
+ //Return best ranked application
+ return $ret;
+ }
+
+ /**
+ * Rekey sessions and applications by chronological session id
+ *
+ * @return bool The rekey success or failure
+ */
+ function rekey(): bool {
+ //Get connection
+ $cnx = $this->_em->getConnection();
+
+ //Set the request
+ $req = <<<SQL
+SELECT
+ a.id,
+ a.sa_id
+FROM (
+ SELECT
+ s.id,
+ s.date,
+ s.begin,
+ s.slot_id,
+ GROUP_CONCAT(sa.id ORDER BY sa.id SEPARATOR "\\n") AS sa_id
+ FROM RapsysAirBundle:Session AS s
+ LEFT JOIN RapsysAirBundle:Application AS sa ON (sa.session_id = s.id)
+ GROUP BY s.id
+ ORDER BY NULL
+) AS a
+ORDER BY ADDDATE(ADDTIME(a.date, a.begin), INTERVAL IF(a.slot_id = :afterid, 1, 0) DAY) ASC
+SQL;
+
+ //Replace bundle entity name by table name
+ $req = str_replace($this->tableKeys, $this->tableValues, $req);
+
+ //Get result set mapping instance
+ //XXX: DEBUG: see ../blog.orig/src/Rapsys/BlogBundle/Repository/ArticleRepository.php
+ $rsm = new ResultSetMapping();
+
+ //Declare all fields
+ //XXX: see vendor/doctrine/dbal/lib/Doctrine/DBAL/Types/Types.php
+ //addScalarResult($sqlColName, $resColName, $type = 'string');
+ $rsm->addScalarResult('id', 'id', 'integer')
+ ->addScalarResult('sa_id', 'sa_id', 'string');
+ #->addIndexByScalar('id');
+
+ //Fetch result
+ $rnq = $this->_em->createNativeQuery($req, $rsm);
+
+ //Get result set
+ $res = $rnq->getResult();
+
+ //Start transaction
+ $cnx->beginTransaction();
+
+ //Set update session request
+ $sreq = <<<SQL
+UPDATE RapsysAirBundle:Session
+SET id = :nid, updated = NOW()
+WHERE id = :id
+SQL;
+
+ //Replace bundle entity name by table name
+ $sreq = str_replace($this->tableKeys, $this->tableValues, $sreq);
+
+ //Set update application request
+ $areq = <<<SQL
+UPDATE RapsysAirBundle:Application
+SET session_id = :nid, updated = NOW()
+WHERE session_id = :id
+SQL;
+
+ //Replace bundle entity name by table name
+ $areq = str_replace($this->tableKeys, $this->tableValues, $areq);
+
+ //Set max value
+ $max = max(array_keys($res));
+
+ try {
+ //Prepare session to update
+ foreach($res as $id => $data) {
+ //Set temp id
+ $res[$id]['t_id'] = $max + $id + 1;
+
+ //Set new id
+ $res[$id]['n_id'] = $id + 1;
+
+ //Explode application ids
+ $res[$id]['sa_id'] = explode("\n", $data['sa_id']);
+
+ //Without change
+ if ($res[$id]['n_id'] == $res[$id]['id']) {
+ //Remove unchanged session
+ unset($res[$id]);
+ }
+ }
+
+ //With changes
+ if (!empty($res)) {
+ //Disable foreign key checks
+ $cnx->prepare('SET foreign_key_checks = 0')->execute();
+
+ //Update to temp id
+ foreach($res as $id => $data) {
+ //Run session update
+ $cnx->executeUpdate($sreq, ['nid' => $res[$id]['t_id'], 'id' => $res[$id]['id']]);
+
+ //Run applications update
+ $cnx->executeUpdate($areq, ['nid' => $res[$id]['t_id'], 'id' => $res[$id]['id']]);
+ }
+
+ //Update to new id
+ foreach($res as $id => $data) {
+ //Run session update
+ $cnx->executeUpdate($sreq, ['nid' => $res[$id]['n_id'], 'id' => $res[$id]['t_id']]);
+
+ //Run applications update
+ $cnx->executeUpdate($areq, ['nid' => $res[$id]['n_id'], 'id' => $res[$id]['t_id']]);
+ }
+
+ //Restore foreign key checks
+ $cnx->prepare('SET foreign_key_checks = 1')->execute();
+
+ //Commit transaction
+ $cnx->commit();
+
+ //Set update auto_increment request
+ $ireq = <<<SQL
+ALTER TABLE RapsysAirBundle:Session
+auto_increment = 1
+SQL;
+
+ //Replace bundle entity name by table name
+ $ireq = str_replace($this->tableKeys, $this->tableValues, $ireq);
+
+ //Reset auto_increment
+ $cnx->exec($ireq);
+ //Without changes
+ } else {
+ //Rollback transaction
+ $cnx->rollback();
+ }
+ } catch(\Exception $e) {
+ //Rollback transaction
+ $cnx->rollback();
+
+ //Throw exception
+ throw $e;
+ }
+
+ //Return success
+ return true;
+ }