improved start page performance; top rating statistics was very slow

needs a new database field with manual init, see db-changes.txt !

and fixed another recommendation bug:
- recommendations will not get lost when a user edits one of multiple logs
  for the same cache
This commit is contained in:
following
2012-08-24 23:58:18 +02:00
parent 038719fa3c
commit c32a4b06ff
6 changed files with 34 additions and 39 deletions

View File

@ -15,3 +15,7 @@ date commit ID change
- add caches.okapi_syncbase, initialize it and add corresponding index
- add and initialize cache_logs(_archived).okapi_syncbase
See installation instructions at http://code.google.com/p/opencaching-api
2012-08-24 added cache_rating.rating_date and index 'date'; must be initialized by:
UPDATE cache_rating SET rating_date = (SELECT MIN(`date`) FROM cache_logs WHERE cache_logs.cache_id=cache_rating.cache_id AND cache_logs.user_id=cache_rating.user_id AND cache_logs.type IN (1,7))
added trigger cacheRatingBeforeInsert

View File

@ -668,6 +668,13 @@
INSERT IGNORE INTO `removed_objects` (`localId`, `uuid`, `type`, `node`) VALUES (OLD.`id`, OLD.`uuid`, 1, OLD.`node`);
END;");
sql_dropTrigger('cacheRatingBeforeInsert');
sql("CREATE TRIGGER `cacheRatingBeforeInsert` BEFORE INSERT ON `cache_rating`
FOR EACH ROW
BEGIN
SET NEW.`rating_date` = NOW();
END;");
sql_dropTrigger('cacheRatingAfterInsert');
sql("CREATE TRIGGER `cacheRatingAfterInsert` AFTER INSERT ON `cache_rating`
FOR EACH ROW

View File

@ -79,7 +79,7 @@
$log_date_day = isset($_POST['logday']) ? $_POST['logday'] : date('d', strtotime($log_record['date']));
$log_date_month = isset($_POST['logmonth']) ? $_POST['logmonth'] : date('m', strtotime($log_record['date']));
$log_date_year = isset($_POST['logyear']) ? $_POST['logyear'] : date('Y', strtotime($log_record['date']));
$top_cache = isset($_POST['rating']) ? $_POST['rating']+0 : 0;
$top_cache = isset($_POST['rating']) ? $_POST['rating']+0 : null;
$log_pw = '';
$use_log_pw = (($log_record['logpw'] == NULL) || ($log_record['logpw'] == '')) ? false : true;
@ -98,7 +98,7 @@
{
if (($user_founds * rating_percentage/100) < 1)
{
$top_cache = 0;
$top_cache = null;
$anzahl = (1 - ($user_founds * rating_percentage/100)) / (rating_percentage/100);
if ($anzahl > 1)
{
@ -117,7 +117,7 @@
}
else
{
$top_cache = 0;
$top_cache = null;
$anzahl = ($user_tops + 1 - ($user_founds * rating_percentage/100)) / (rating_percentage/100);
if ($anzahl > 1)
{
@ -243,7 +243,7 @@
// not a found log? then ignore the rating
if ($log_type != 1 && $log_type != 7)
{
$top_cache = 0;
$top_cache = null;
}
@ -293,7 +293,7 @@
// update top-list
if ($top_cache == 1)
sql("INSERT IGNORE INTO `cache_rating` (`user_id`, `cache_id`) VALUES('&1', '&2')", $usr['userid'], $log_record['cache_id']);
else
else if ($top_cache === 0) // 0 but not null
sql("DELETE FROM `cache_rating` WHERE `user_id`='&1' AND `cache_id`='&2'", $usr['userid'], $log_record['cache_id']);
// do not use slave server for the next time ...

View File

@ -63,12 +63,6 @@
`user`.`username` `username`,
`caches`.`cache_id` `cache_id`,
`caches`.`name` `name`,
`caches`.`longitude` `longitude`,
`caches`.`latitude` `latitude`,
`caches`.`date_created` `date_created`,
`caches`.`country` `country`,
`caches`.`difficulty` `difficulty`,
`caches`.`terrain` `terrain`,
`caches`.`date_hidden`,
`cache_location`.`adm1`,
`cache_location`.`adm2`,
@ -91,13 +85,7 @@
`user`.`username` `username`,
`caches`.`cache_id` `cache_id`,
`caches`.`name` `name`,
`caches`.`longitude` `longitude`,
`caches`.`latitude` `latitude`,
`caches`.`date_created` `date_created`,
`caches`.`country` `country`,
`caches`.`difficulty` `difficulty`,
`caches`.`terrain` `terrain`,
`caches`.`date_hidden`,
`caches`.`type`,
`cache_location`.`adm1`,
`cache_location`.`adm2`,
@ -115,39 +103,33 @@
sql_free_result($rs);
// last 30 days' top ratings
$rs = sql_slave("SELECT COUNT(DISTINCT `cache_logs`.`user_id`) AS `cRatings`,
`cache_logs`.`cache_id`,
MAX(`cache_logs`.`date`) AS `dLastLog`,
//
// 2012-08-24 following
// optimized by adding rating_date field to cache_rating, so we don't need the log table.
$rs = sql_slave("SELECT COUNT(`cache_rating`.`user_id`) AS `cRatings`,
MAX(`cache_rating`.`rating_date`) AS `dLastLog`,
`user`.`user_id` AS `user_id`,
`user`.`username` AS `username`,
`caches`.`cache_id` AS `cache_id`,
`caches`.`name` AS `name`,
`caches`.`longitude` AS `longitude`,
`caches`.`latitude` AS `latitude`,
`caches`.`date_created` AS `date_created`,
`caches`.`country` AS `country`,
`caches`.`difficulty` AS `difficulty`,
`caches`.`terrain` AS `terrain`,
`caches`.`date_hidden`,
`caches`.`type`,
`cache_location`.`adm1`,
`cache_location`.`adm2`,
`cache_location`.`adm3`,
`cache_location`.`adm4`
FROM `cache_logs`
INNER JOIN `cache_rating` ON `cache_logs`.`cache_id`=`cache_rating`.`cache_id` AND
`cache_logs`.`user_id`=`cache_rating`.`user_id`
INNER JOIN `caches` ON `cache_logs`.`cache_id`=`caches`.`cache_id`
INNER JOIN `user` ON `user`.`user_id`=`caches`.`user_id`
LEFT JOIN `cache_location` ON `caches`.`cache_id`=`cache_location`.`cache_id`
FROM `cache_rating`
INNER JOIN `caches` ON `caches`.`cache_id`=`cache_rating`.`cache_id`
INNER JOIN `user` ON `user`.`user_id`=`cache_rating`.`user_id`
LEFT JOIN `cache_location` ON `cache_rating`.`cache_id`=`cache_location`.`cache_id`
WHERE `caches`.`country`='&1' AND
`cache_logs`.`type`=1 AND
`cache_logs`.`date`>DATE_SUB(NOW(), INTERVAL 30 DAY) AND
`cache_rating`.`rating_date`>DATE_SUB(NOW(), INTERVAL 30 DAY) AND
`caches`.`type`!=6 AND
`caches`.`status`=1
GROUP BY `cache_logs`.`cache_id`
GROUP BY `cache_rating`.`cache_id`
ORDER BY `cRatings` DESC,
`dLastLog` DESC
`dLastLog` DESC,
`cache_id` DESC
LIMIT 0, 10",
$sUserCountry);
$tpl->assign_rs('topratings', $rs);

View File

@ -20,6 +20,7 @@
</ul>
<p>Geändert / verbessert:</p>
<ul class="changelog">
<li class="changelogitem"><a href="./index.php">Startseite</a> beschleunigt</li>
<li class="changelogitem"><a href="./articles.php?page=cacheinfo">Cachebeschreibungs-Info</a> überarbeitet</li>
<li class="changelogitem">Empfehlungssterne erscheinen nur noch bei Gefunden- und Teilgenommen-Logs.</li>
<li class="changelogitem">Logtypreihenfolge bei Event-Caches umgedreht</li>
@ -36,7 +37,7 @@
<li class="changelogitem">Anzeige der Event-Teilnehmerzahl in der Logzusammenfassungszeile</li>
<li class="changelogitem">seltenen Fehler bei der Erzeugung von OC-Wegpunkten behoben</li>
<li class="changelogitem">Empfehlungen gehen beim mehrfachen Loggen eines Caches &ndash; z.B. Fund + Hinweis &ndash; nicht mehr verloren.</li>
<li class="changelogitem">Empfehlungen gehen beim Löschen eines von mehreren Logs des gleichen Benutzers nicht mehr verloren.</li>
<li class="changelogitem">Empfehlungen gehen beim Löschen eines von mehreren Logs des gleichen Benutzers oder beim Bearbeiten von einem der Logs nicht mehr verloren.</li>
<li class="changelogitem">Mehrfachlogs eines Benutzers zählen bei der Bewertungsübersicht auf der Startseite nur noch einmal.</li>
</ul>
<br />

View File

@ -21,6 +21,7 @@
</ul>
<p>Changed / improved:</p>
<ul class="changelog">
<li class="changelogitem">improved <a href="./index.php">Homepag</a> performance</li>
<li class="changelogitem">rewritten <a href="./articles.php?page=cacheinfo">cache description</a> info</li>
<li class="changelogitem">recommendations stars are display with Found and Attended logs only.</li>
<li class="changelogitem">reversed log type order for event caches</li>
@ -36,7 +37,7 @@
<li class="changelogitem">added missing event attendees count in log summary line</li>
<li class="changelogitem">fixed OC waypoint creation error</li>
<li class="changelogitem">Recommendations are no longer lost when logging a cache again, e.g. a note after a found log.</li>
<li class="changelogitem">Recommendations are no longer lost when deleting one of multiple logs of the same user.</li>
<li class="changelogitem">Recommendations are no longer lost when deleting one of multiple logs of the same user, or when editing one of them.</li>
<li class="changelogitem">Multiple logs by the same used only count once at the homepage top ratings list.</li>
</ul>
<br />