This project aims to give tools to extract data from Moodle cron's log files in such a way they can be easily analysed inside a database, using SQL language.
## Script import_into_DB.sh
### Prerequistes
The supplied script, `import_into_DB.sh`, has been designed considering :
* sqlite3 is intalled on the server and executed calling `sqlite3` command (without speciying its path)
* Moodle cron log files are stored in a folder `/var/log/mmodle`
* these files are named `cron_hhmm.log` (for example 'cron_1013.log' is the log file associated with the cron launched at 10h13)
* the shell command `ls -l $f | cut -d ' ' -f 6,7,8` is efficient to extract the file creation date
### Principle of operation
This script
1. extracts recursively, from all cron log files in the directory, all interesting datas as a unique temporary csv file. This one contains a set of lines (one per task), and for each a set of columns (separated by a ';' character) for each data.
2. creates a SQLite database, `moodle-logs.db`, and import inside it this csv as a table, `tasks`
3. creates inside this database another table, `slots`, with all minutes that compose a day
4. creates a table, `tasks_per_slot`, from the joins of both preceeding tables, supplying therefore, minute after minute, the list of task running or still in progress during that minute
5. creates a table, `known_failures`, containing predefined failures description in order to give more informations inside final statistics
6. excutes a final query to get statistics about detected task failures
### Limitations
The script should be seen as an **alpha version**. It is too young to be considered "mature".
The table, `known_failures`, has been created considering failures seen recently in our university. Its content is not exhaustive, and probably needs to be extended.
### Database description
The resulting database own 4 tables
* Table `tasks` : 1 ligne par exécution de tache, avec les colonnes :
*`file` = name of the cron log file from which the task execution has been extracted
*`date` = file creation date
*`ligne1` = the 1st interesting line in the file about the task execution (several usefull datas)
*`ligne2` = the second (should contains the starting time of the execution)
*`ligne3` = the third line or another in between first and last (the first that may contains some exception notice)
*`ligne4` = the next-to-last interesting line (including duration)
*`ligne5` = the last (contains result and sometime failure message)
*`type` = '//scheduled//' or '//adhoc//' (first are planified, seconds are executed when possible)
*`classname` = task name (as seen in Moodle code or in administration pages)
*`started` = starting time
*`stopped` = stoping time
*`duration` = duration (in seconds)
*`failed` = 0 (task ended without problem) ou 1 (failing task)
*`exception` = 0 (no problem) ou 1 (at least 1 exception raised)
* Table `slots` : 1 line per minute in the day
* Table `tasks_per_slot` : (joins between both previous tables) 1 line per executed task or task still in progress, within the relevant minute (if a task execution last for instance 6 minutes, then 6 lines will be generated for it in this table)
* Table `known_failures` : 1 ligne per failure known type
*`composant` = the impacted element
*`name` = a name for this kind of error
*`filtre` = a filtering string that could be used as is, inside a SQL query (with a `LIKE` operator), to get relevant lines
### Queries examples
Below, some examples of what could be done with this database.
The first example, statistics of failures, can be found at the end of the script.
Duration statistics for a specific task that may contains a specific word in the error message ('redis' for instance) :
Display, minute by minute, the number of tasks that were running or still in progress in that minute (successively in a single cron or simultaneously in several or both) :
# et peuplement des colonnes non encore renseignées
# par extraction des données depuis le texte des 5 lignes originelles (colonnes ligne1 à ligne5)
rm-v$BDD
sqlite3 $BDD<<eof
.mode csv
.separator ;
create table tasks(
file text,
date text,
ligne1 text,
ligne2 text,
ligne3 text,
ligne4 text,
ligne5 text,
type text,
classname text,
started text,
stopped text,
duration text,
failed text,
exception text);
.import $CSV tasks
-- type
update tasks
set type = 'scheduled'
where ligne1 like 'scheduled%';
update tasks
set type = 'adhoc'
where ligne1 like 'adhoc%';
-- rq
-- classname
update tasks
set classname = trim(
substr(
ligne1,
instr(ligne1, '('))
, '()')
where type = 'scheduled';
update tasks
set classname = replace(ligne1, 'adhoc task: ', '')
where type = 'adhoc';
-- started
update tasks
set started = substr(
substr(ligne2,
1,
instr(ligne2, '. Current')-1),
-8);
-- duration
update tasks
set duration = replace(replace(ligne4, ' seconds', ''), '... used ', '');
update tasks
set duration = null
where not ligne4 like '%second%';
-- stopped
update tasks
set stopped = time(started, '+' || duration || ' seconds');
update tasks
set stopped = null
where not ligne4 like '%second%';
-- failed
update tasks
set failed = 0
where ligne5 like '%task complete:%';
update tasks
set failed = 1
where ligne5 like '%task failed:%';
-- exception
update tasks
set exception = 0;
update tasks
set exception = 1
where ligne3 like '%Exception%';
.exit
eof
rm-v$CSV
echo
echo"Generation des slots dans $BDD..."
# generation d'une table slots possédant 1 ligne par minute de la journée
# generation d'un csv temporaire :
for h in{0..23}
do
echo"de $h:00 à $h:59"
for m in{0..59}
do
t="$(printf'%02d'$h):$(printf'%02d'$m):00"
echo"$t;0">>$CSV
done
done
# import de ce csv :
sqlite3 $BDD<<eof
.mode csv
.separator ;
create table slots (start text, stop text);
.import $CSV slots
update slots set stop = time(start, '+1 minutes');
.exit
eof
rm-v$CSV
echo
echo"Génération des tables et vues supplémentaires..."
# Génération des tables et vues pour analyse répartition des exécutions dans le temps
sqlite3 $BDD<<eof
create table if not exists tasks_per_slot as
select *
from slots s
join tasks t
on t.started < s.stop and t.stopped >= s.start;
eof
echo
echo"Statistiques d'échec et affichage final..."
sqlite3 $BDD<<eof
-- Table des types d erreur connues :
create table known_failures (
composant text,
name text,
filtre text)
;
-- Definition des types d erreurs connues :
insert into known_failures (composant, name, filtre) values
('redis', 'read error', '%read error on connection to ecampus-redis.unicaen.fr%'),
('redis', 'went away', '%Redis server % went away%'),
('système de fichiers', 'droits pool fichiers', '%Impossible de créer les dossiers du pool de fichiers locaux. Veuillez vérifier les droits%'),
('base de données', 'erreur lecture', '%Erreur de lecture de la base de données%'),
(null, 'course could not be deleted', '%Erreur de programmation détectée. Ceci doit être corrigé par un programmeur : The course module%could not be deleted%'),
(null, 'Id module invalide', '%Identifiant de module de cours non valide%')
;
-- Statistiques :
.header on
.mode column
select t.date,
t.classname,
e.composant,
e.name,
sum(failed) as nbre_failed,
sum(exception) as nbre_exception,
a.sur
from tasks t -- les taches
left join known_failures e
on t.ligne5 like e.filtre
or t.ligne3 like e.filtre -- les erreurs typiques
join (
select date, classname, count(*) as sur
from tasks
group by date, classname
) as a -- all (nbre d'executions réussies ou pas, par date et tache)