[c5c522c] | 1 | -- $Id: purge-4.1.sql,v 1.11 2010/04/21 21:14:18 sbajic Exp $ |
---|
| 2 | |
---|
| 3 | -- |
---|
| 4 | -- This file contains statements for purging the DSPAM for MySQL 4.1 or greater. |
---|
| 5 | -- |
---|
| 6 | |
---|
| 7 | -- --------------------------------------------------------------------------- |
---|
| 8 | -- Note: Should you have modified your dspam.conf to have other intervals for |
---|
| 9 | -- the purging or you have modified the TrainingMode to be other then |
---|
| 10 | -- 'TEFT' then please modify this SQL file to be in sync with your |
---|
| 11 | -- dspam.conf. |
---|
| 12 | -- |
---|
| 13 | -- Note: It is difficult to purge neutral tokens with SQL clauses the same way |
---|
| 14 | -- as dspam_clean is doing it. So you should still run dspam_clean with |
---|
| 15 | -- the "-u" parameter from time to time. |
---|
| 16 | -- --------------------------------------------------------------------------- |
---|
| 17 | |
---|
| 18 | -- |
---|
| 19 | -- Set some defaults |
---|
| 20 | -- |
---|
| 21 | SET @TrainingMode = 'TEFT'; -- Default training mode |
---|
| 22 | SET @PurgeSignatures = 14; -- Stale signatures |
---|
| 23 | SET @PurgeUnused = 90; -- Unused tokens |
---|
| 24 | SET @PurgeHapaxes = 30; -- Tokens with less than 5 hits (hapaxes) |
---|
| 25 | SET @PurgeHits1S = 15; -- Tokens with only 1 spam hit |
---|
| 26 | SET @PurgeHits1I = 15; -- Tokens with only 1 innocent hit |
---|
| 27 | SET @today = to_days(current_date()); |
---|
| 28 | |
---|
| 29 | -- |
---|
| 30 | -- Delete tokens with less than 5 hits (hapaxes) |
---|
| 31 | -- |
---|
| 32 | START TRANSACTION; |
---|
| 33 | DELETE LOW_PRIORITY QUICK |
---|
| 34 | FROM dspam_token_data |
---|
| 35 | WHERE from_days(@today-@PurgeHapaxes) > last_hit |
---|
| 36 | AND (2*innocent_hits)+spam_hits < 5; |
---|
| 37 | COMMIT; |
---|
| 38 | |
---|
| 39 | -- |
---|
| 40 | -- Delete tokens with only 1 spam hit |
---|
| 41 | -- |
---|
| 42 | START TRANSACTION; |
---|
| 43 | DELETE LOW_PRIORITY QUICK |
---|
| 44 | FROM dspam_token_data |
---|
| 45 | WHERE from_days(@today-@PurgeHits1S) > last_hit |
---|
| 46 | AND innocent_hits = 0 AND spam_hits = 1; |
---|
| 47 | COMMIT; |
---|
| 48 | |
---|
| 49 | -- |
---|
| 50 | -- Delete tokens with only 1 innocent hit |
---|
| 51 | -- |
---|
| 52 | START TRANSACTION; |
---|
| 53 | DELETE LOW_PRIORITY QUICK |
---|
| 54 | FROM dspam_token_data |
---|
| 55 | WHERE from_days(@today-@PurgeHits1I) > last_hit |
---|
| 56 | AND innocent_hits = 1 AND spam_hits = 0; |
---|
| 57 | COMMIT; |
---|
| 58 | |
---|
| 59 | -- |
---|
| 60 | -- Delete unused tokens, except for TOE, TUM and NOTRAIN modes |
---|
| 61 | -- |
---|
| 62 | START TRANSACTION; |
---|
| 63 | DELETE LOW_PRIORITY QUICK |
---|
| 64 | FROM t USING dspam_token_data t |
---|
| 65 | LEFT JOIN dspam_preferences p ON (p.preference = 'trainingMode' AND p.uid = t.uid) |
---|
| 66 | LEFT JOIN dspam_preferences d ON (d.preference = 'trainingMode' AND d.uid = 0) |
---|
| 67 | WHERE COALESCE(CONVERT(p.value USING latin1) COLLATE latin1_general_ci,CONVERT(d.value USING latin1) COLLATE latin1_general_ci,CONVERT(@TrainingMode USING latin1) COLLATE latin1_general_ci) NOT IN (_latin1 'TOE',_latin1 'TUM',_latin1 'NOTRAIN') |
---|
| 68 | AND from_days(@today-@PurgeUnused) > last_hit; |
---|
| 69 | COMMIT; |
---|
| 70 | |
---|
| 71 | -- |
---|
| 72 | -- Delete TUM tokens seen no more than 50 times |
---|
| 73 | -- |
---|
| 74 | START TRANSACTION; |
---|
| 75 | DELETE LOW_PRIORITY QUICK |
---|
| 76 | FROM t USING dspam_token_data t |
---|
| 77 | LEFT JOIN dspam_preferences p ON (p.preference = 'trainingMode' AND p.uid = t.uid) |
---|
| 78 | LEFT JOIN dspam_preferences d ON (d.preference = 'trainingMode' AND d.uid = 0) |
---|
| 79 | WHERE COALESCE(CONVERT(p.value USING latin1) COLLATE latin1_general_ci,CONVERT(d.value USING latin1) COLLATE latin1_general_ci,CONVERT(@TrainingMode USING latin1) COLLATE latin1_general_ci) = _latin1 'TUM' |
---|
| 80 | AND from_days(@today-@PurgeUnused) > last_hit |
---|
| 81 | AND innocent_hits + spam_hits < 50; |
---|
| 82 | COMMIT; |
---|
| 83 | |
---|
| 84 | -- |
---|
| 85 | -- Delete stale signatures |
---|
| 86 | -- |
---|
| 87 | START TRANSACTION; |
---|
| 88 | DELETE LOW_PRIORITY QUICK |
---|
| 89 | FROM dspam_signature_data |
---|
| 90 | WHERE from_days(@today-@PurgeSignatures) > created_on; |
---|
| 91 | COMMIT; |
---|