Bug 335 suppression sans validation du statut orange. Rajout de quelques tests supplé...
[platal.git] / bin / cron / checkdb.php
1 #!/usr/bin/php4 -q
2 <?php
3 /***************************************************************************
4 * Copyright (C) 2003-2004 Polytechnique.org *
5 * http://opensource.polytechnique.org/ *
6 * *
7 * This program is free software; you can redistribute it and/or modify *
8 * it under the terms of the GNU General Public License as published by *
9 * the Free Software Foundation; either version 2 of the License, or *
10 * (at your option) any later version. *
11 * *
12 * This program is distributed in the hope that it will be useful, *
13 * but WITHOUT ANY WARRANTY; without even the implied warranty of *
14 * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the *
15 * GNU General Public License for more details. *
16 * *
17 * You should have received a copy of the GNU General Public License *
18 * along with this program; if not, write to the Free Software *
19 * Foundation, Inc., *
20 * 59 Temple Place, Suite 330, Boston, MA 02111-1307 USA *
21 ***************************************************************************/
22 /*
23 * verifie qu'il n'y a pas d'incoherences dans les tables de jointures
24 *
25 */
26
27 require('./connect.db.inc.php');
28 require("Console/Getopt.php");
29
30 function check($sql, $commentaire='') {
31 $res = mysql_query($sql);
32 if ($err = mysql_error()) echo $err;
33 if (mysql_num_rows($res)>0) {
34 echo "Erreur pour la verification : $commentaire\n$sql\n\n";
35 echo "|";
36 while($col = mysql_fetch_field($res)) echo "\t".$col->name."\t|";
37 echo "\n";
38
39 while ($arr = mysql_fetch_row($res)) {
40 echo "|";
41 foreach ($arr as $val) echo "\t$val\t|";
42 echo "\n";
43 }
44 echo "\n";
45 }
46 }
47
48 function info($sql,$commentaire='') {
49 global $opt_verbose;
50 if ($opt_verbose)
51 check($sql,$commentaire);
52 }
53
54 /* on parse les options */
55 $opts = Console_GetOpt::getopt($argv, "v");
56 $opt_verbose=false;
57
58 if ( PEAR::isError($opts) ) {
59 echo $opts->getMessage();
60 } else {
61 $opts = $opts[0];
62 foreach ( $opts as $opt) {
63 switch ($opt[0]) {
64 case "v":
65 $opt_verbose=true;
66 echo "Mode verbeux\n";
67 break;
68 }
69 }
70 }
71
72 /* validite de adresses */
73 check("select uid, adrid from adresses where FIND_IN_SET('pro',statut)","Utilisateurs ayant encore une adresse pro dans leurs adresses");
74 check("select uid, adrid from adresses group by uid having count(adrid) > 7", "Utilisateurs ayant trop d'adresses");
75
76 /* Validite de entreprises */
77 check("select uid, entrid from entreprises group by uid having count(entrid) > 2","Utilisateurs ayant trop d'entreprises");
78
79 /* Validite des tables de langues, competences, mentoring*/
80 check("select uid, lid from langues_ins group by uid having count(lid) > 10","Utilisateurs ayant trop de langues");
81 check("select uid, cid from competences_ins group by uid having count(cid) > 20","Utilisateurs ayant trop de competences");
82
83 /* validite de aliases */
84 check("SELECT a.*
85 FROM aliases AS a
86 LEFT JOIN auth_user_md5 AS u ON u.user_id=a.id
87 WHERE (a.type='alias' OR a.type='a_vie') AND u.prenom is null");
88
89 /* validite de applis_ins */
90 check("select a.* from applis_ins as a left join auth_user_md5 as u on u.user_id=a.uid where u.prenom is null");
91 check("select a.* from applis_ins as a left join applis_def as ad on ad.id=a.aid where ad.text is null");
92
93 /* validite de binet_users */
94 check("select b.* from binets_ins as b left join auth_user_md5 as u on u.user_id=b.user_id where u.prenom is null");
95 check("select b.* from binets_ins as b left join binets_def as bd on bd.id=b.binet_id where bd.text is null");
96
97 /* validite de contacts */
98 check("select c.* from contacts as c left join auth_user_md5 as u on u.user_id=c.uid where u.prenom is null");
99 check("select c.* from contacts as c left join auth_user_md5 as u on u.user_id=c.contact where u.prenom is null");
100
101 /* validite de emails */
102 check("select e.* from emails as e left join auth_user_md5 as u on u.user_id=e.uid where e.uid and u.prenom is null");
103
104 /* validite de forums */
105 check("select f.* from forums.abos as f left join auth_user_md5 as u on u.user_id=f.uid where u.prenom is null");
106 check("select f.* from forums.abos as f left join forums.list as fd on fd.fid=f.fid where fd.nom is null");
107 check("select f.* from forums.respofaqs as f left join forums.list as fd on fd.fid=f.fid where fd.nom is null");
108 check("select f.* from forums.respofaqs as f left join auth_user_md5 as u on u.user_id=f.uid where u.prenom is null");
109
110 /* validite de groupesx_ins */
111 check("select g.* from groupesx_ins as g left join auth_user_md5 as u on u.user_id=g.guid where u.prenom is null");
112 check("select g.* from groupesx_ins as g left join groupesx_def as gd on g.gid=g.gid where gd.text is null");
113
114 /* validite de photo */
115 check("select p.* from photo as p left join auth_user_md5 as u on u.user_id=p.uid where u.prenom is null");
116
117 /* validite des champ pays et region */
118 check("SELECT a.uid, a.country FROM adresses AS a LEFT JOIN geoloc_pays AS gp ON a.country = gp.a2 WHERE gp.pays IS NULL","donne la liste des pays dans les profils qui n'ont pas d'entree correspondante dans geoloc_pays");
119 check("SELECT a.uid, a.country, a.region FROM adresses AS a LEFT JOIN geoloc_region AS gr ON (a.country = gr.a2 AND a.region = gr.region) WHERE a.region != '' AND gr.name IS NULL","donne la liste des regions dans les profils qui n'ont pas d'entree correspondante dans geoloc_region");
120
121 /* donne la liste des gens pour qui on a fait du marketing mais qui se sont inscrits depuis (nettoyage de envoidirect) */
122 info("select e.matricule,e.nom,e.prenom,e.promo from envoidirect as e inner join auth_user_md5 as a on (e.matricule = a.matricule and a.perms = 'user') order by promo,nom;");
123
124 /* donne la liste des emails qui apparaissent 2 fois dans la table emails pour des personnes différentes */
125 info("SELECT a1.alias, a2.alias, e1.email, e2.flags
126 FROM emails AS e1
127 INNER JOIN emails AS e2 ON(e1.email = e2.email AND e1.uid!=e2.uid AND
128 (e1.uid<e2.uid OR NOT FIND_IN_SET(e2.flags,'active'))
129 )
130 INNER JOIN aliases AS a1 ON(a1.id=e1.uid AND a1.type='a_vie')
131 INNER JOIN aliases AS a2 ON(a2.id=e2.uid AND a2.type='a_vie')
132 INNER JOIN auth_user_md5 AS u1 ON(a1.id=u1.user_id)
133 INNER JOIN auth_user_md5 AS u2 ON(a2.id=u2.user_id)
134 WHERE FIND_IN_SET(e1.flags,'active') AND u1.nom!=u2.nom_usage AND u2.nom!=u1.nom_usage
135 ORDER BY a1.alias",
136 "donne la liste des emails qui apparaissent 2 fois dans la table emails pour des personnes différentes");
137
138 /* vérif que tous les inscrits ont bien au moins un email actif */
139 check("SELECT u.user_id, a.alias
140 FROM auth_user_md5 AS u
141 INNER JOIN aliases AS a ON (u.user_id = a.id AND a.type='a_vie')
142 LEFT JOIN emails AS e ON(u.user_id=e.uid AND FIND_IN_SET('active',e.flags))
143 WHERE e.uid IS NULL AND u.deces = 0",
144 "donne les inscrits qui n'ont pas d'email actif");
145
146 /* donne la liste des homonymes qui ont un alias égal à leur loginbis depuis plus d'un mois */
147 check("SELECT a.alias AS username, b.alias AS loginbis, b.expire
148 FROM aliases AS a
149 INNER JOIN aliases AS b ON ( a.id=b.id AND b.type != 'homonyme' and b.expire < NOW() )
150 WHERE a.type = 'a_vie'",
151 "donne la liste des homonymes qui ont un alias égal à leur loginbis depuis plus d'un mois, il est temps de supprimer leur alias");
152
153 /* verifie qu'il n'y a pas de gens qui recrivent sur un alias qu'ils n'ont plus */
154
155 check("SELECT a.alias AS a_un_pb, email, rewrite AS broken
156 FROM aliases AS a
157 INNER JOIN emails AS e ON (a.id=e.uid AND rewrite!='')
158 LEFT JOIN aliases AS b ON (b.id=a.id AND rewrite LIKE CONCAT(b.alias,'@%') AND b.type!='homonyme')
159 WHERE a.type='a_vie' AND b.type IS NULL","gens qui ont des rewrite sur un alias perdu");
160
161 /* validite du champ matricule_ax de la table auth_user_md5 */
162 check("SELECT matricule,nom,prenom,matricule_ax,COUNT(matricule_ax) AS c
163 FROM auth_user_md5
164 WHERE matricule_ax != '0'
165 GROUP BY matricule_ax
166 having c > 1", "à chaque personne de l'annuaire de l'AX (identification_ax) doit correspondre AU PLUS UNE personne de notre annuaire (auth_user_md5) -> si ce n'est pas le cas il faut regarder en manuel ce qui ne va pas !");
167 ?>