Commit 75b88752 authored by bensinober's avatar bensinober Committed by Benjamin
Browse files

DEICH-5758 koha : add extra data quality report with borrower lastseen as arg

parent 93c38410
......@@ -29,6 +29,7 @@ our %REPORTS = (
"test_find_riksen_patrons" => ["Deichman::Reports::TestFindRiksenPatrons", "TEST: for å finne pasientlånere "],
"canceled_and_expired_reserves" => ["Deichman::Reports::CanceledAndExpiredReserves", "Rapport på utløpt og avbestilt materiale på hentehylle"],
"data_quality_report" => ["Deichman::Reports::DataQualityReport", "Samlerapport over datakvalitet"],
"data_quality_report_active_users" => ["Deichman::Reports::DataQualityReportActiveUsers", "Samlerapport over datakvalitet med aktivitet siste X dager"],
"users_invalid_cardnumber" => ["Deichman::Reports::UsersInvalidCardnumber", "Lånere med feil, manglende eller rare kortnummer"],
"users_duplicate_ssn" => ["Deichman::Reports::UsersDuplicateSSN", "Lånere registrert flere ganger med samme personnummer"],
"users_duplicate_name_birth" => ["Deichman::Reports::UsersDuplicateNameBirth", "Lånere registrert flere ganger med samme navn og fødselsdato"],
......
package Deichman::Reports::DataQualityReportActiveUsers;
use parent "Deichman::Reports";
use Time::Piece;
use Try::Tiny;
use Time::HiRes qw( time );
use utf8;
=encoding=utf8
=head1
Collection of reports on data quality
Only considering patrons seen last x days
=cut
sub Run {
my ($self) = @_;
my $dbh = $self->dbh;
my $days = $self->{args}->{days} // 365 * 5;
our @queries = (
{ id => "total_users",
type => "gauge",
desc => "Antall lånere totalt",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE deleted_at IS NULL AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "total_users_categories",
type => "summary",
desc => "Antall lånere i ulike kategorier",
query => <<'EOF',
SELECT CASE categorycode
WHEN 'V' then 'Voksen'
WHEN 'B' then 'Barn'
WHEN 'PAS' THEN 'Pasientlånere'
WHEN 'SSO' THEN 'SSO-brukere'
WHEN 'ADMIN' THEN 'Administrator'
WHEN 'ANS' THEN 'Ansatt'
WHEN 'API' THEN 'API-bruker'
WHEN 'BHG' THEN 'Barnehage'
WHEN 'IL' THEN 'Fjernlån'
END AS kategori, COUNT(1) AS num
FROM borrowers WHERE deleted_at IS NULL
AND categorycode IN ('V','B','PAS','SSO','ADMIN','ANS','BHG','API','IL')
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
GROUP BY categorycode
EOF
},
{ id => "total_users_institution",
type => "gauge",
desc => "Antall institusjoner",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE deleted_at IS NULL AND categorycode IN ('BGH','BIB','I','IL','KL','SKO')
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "patrons_verified_IDporten",
type => "gauge",
desc => "Lånere verifisert mot IDporten",
query => "SELECT COUNT(DISTINCT borrowernumber) AS num FROM borrower_attributes JOIN borrowers b USING(borrowernumber)
WHERE code='idporten' AND attribute=1 AND b.lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "patrons_accepted_krr_sync",
type => "gauge",
desc => "Lånere samtykket til KRR-synk",
query => "SELECT COUNT(DISTINCT borrowernumber) AS num FROM borrower_attributes JOIN borrowers b USING(borrowernumber)
WHERE code='krr' AND attribute=1 AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "patrons_rejected_krr_sync",
type => "gauge",
desc => "Lånere ikke samtykket til KRR-synk",
query => "SELECT COUNT(DISTINCT borrowernumber) AS num FROM borrower_attributes JOIN borrowers b USING(borrowernumber)
WHERE code='krr' AND attribute=0 AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_last_seen_by_year",
type => "summary",
desc => "Sist sett Fordelt på år",
query => "SELECT YEAR(lastseen) AS year, COUNT(1) AS num FROM borrowers WHERE deleted_at IS NULL AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
GROUP BY year",
},
{ id => "users_invalid_ssn",
type => "gauge",
desc => "Lånere med lånekategori voksen eller barn med ugyldige fødselsnummer",
query => <<'EOF',
SELECT COUNT(DISTINCT b.borrowernumber) AS num
FROM borrowers b JOIN borrower_attributes ba ON b.borrowernumber = ba.borrowernumber AND ba.code = 'fnr'
WHERE categorycode IN ('B','V') AND b.deleted_at IS NULL AND (
ba.attribute not regexp '[0-9]+'
OR ba.attribute regexp '[.a-zA-Z():?-]+'
OR LENGTH(ba.attribute) NOT IN (11,12)
) AND b.lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
EOF
},
{ id => "users_missing_ssn",
desc => "Lånere med lånekategori voksen eller barn som mangler fødselsnummer",
query => <<'EOF',
SELECT COUNT(DISTINCT b.borrowernumber) AS num
FROM borrowers b LEFT JOIN borrower_attributes ba ON b.borrowernumber = ba.borrowernumber and ba.code = 'fnr'
WHERE categorycode IN ('B','V') AND b.deleted_at IS NULL AND (
ba.attribute IS NULL OR
ba.attribute = ''
) AND b.lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
EOF
},
{ id => "users_missing_dateofbirth",
type => "gauge",
desc => "Lånere med lånekategori voksen eller barn som mangler fødseldato",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE categorycode IN ('B','V') AND deleted_at IS NULL
AND (dateofbirth IS NULL or dateofbirth = '') AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_duplicate_ssn",
type => "summary",
desc => "Lånere med samme personnummer",
query => <<'EOF',
SELECT COUNT(DISTINCT(fnr)) AS num FROM
( SELECT b.borrowernumber,b.cardnumber,ba.attribute AS fnr, b.lastseen FROM borrowers b
JOIN borrower_attributes ba ON (ba.borrowernumber=b.borrowernumber AND ba.code='fnr')
WHERE b.deleted_at IS NULL ) t1
JOIN
( SELECT b.borrowernumber,b.cardnumber,ba.attribute AS fnr, b.lastseen FROM borrowers b
JOIN borrower_attributes ba ON (ba.borrowernumber=b.borrowernumber AND ba.code='fnr')
WHERE b.deleted_at IS NULL ) t2 USING(fnr)
WHERE t1.cardnumber != t2.cardnumber
AND t1.lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
EOF
},
{ id => "users_duplicate_name_birth",
desc => "Lånere registrert flere ganger, med samme fornavn, etternavn og fødselsdato",
query => <<'EOF',
SELECT COUNT(1) AS num FROM (
SELECT firstname,surname,dateofbirth, COUNT(1) AS num FROM borrowers
WHERE deleted_at IS NULL AND categorycode IN ('B','V','REGVOKSEN','REGBARN','REGBARNWEB')
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
GROUP BY firstname,surname,dateofbirth HAVING num > 1
) tmp
EOF
},
{ id => "users_missing_cardnumber",
type => "summary",
desc => "Manglende lånekortnummer",
query => "SELECT categorycode, COUNT(1) AS num FROM borrowers WHERE cardnumber IS NULL OR cardnumber=''
AND deleted_at IS NULL AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY) GROUP BY categorycode",
},
{ id => "users_invalid_cardnumber",
type => "gauge",
desc => "Voksne og barn med feil, manglende eller rare kortnummer",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE cardnumber regexp '[^a-zA-Z0-9]' AND deleted_at IS NULL
AND categorycode IN ('V','B') AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_cardnumber_not_national",
type => "gauge",
desc => "Lånere som har lånekortnummer som avviker fra mønsteret N001234567 (Voksne og barn)",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE cardnumber not regexp 'N00\\\d{7}' AND deleted_at IS NULL
AND categorycode IN ('V','B') AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_adult_juvenile_different_cardnumber_userid",
type => "gauge",
desc => "Lånere som har lånekortnummer som er forskjellig fra brukerid (Voksne og barn)",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE cardnumber != userid AND deleted_at IS NULL
AND categorycode IN ('V','B') AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_kl_wrong_home_library",
type => "gauge",
desc => "Lånere med lånerkategori Klasselåner og et annet hjemmebibliotek enn Skoletjenesten",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE categorycode='KL' AND branchcode != 'hsko'
AND deleted_at IS NULL AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "non_users_with_ssn",
type => "summary",
desc => "Lånere med lånekategori andre enn voksen, barn eller selvregistrert barn (registrert på nett, ID må verifiseres) som har fødselsnummer",
query => <<'EOF',
SELECT categorycode, COUNT(1) AS num FROM borrowers b JOIN
borrower_attributes ba ON b.borrowernumber = ba.borrowernumber and ba.code = 'fnr'
WHERE categorycode NOT IN ('B','V','REGBARN','REGBARNWEB','REGVOKSEN') AND b.deleted_at IS NULL AND b.lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
GROUP BY categorycode
EOF
},
{ id => "non_users_with_dateofbirth",
type => "summary",
desc => "Lånere med lånekategori andre enn voksen, barn eller selvregistrert barn (registrert på nett, ID må verifiseres) som har fødselsdato",
query => <<'EOF',
SELECT categorycode, COUNT(1) AS num FROM borrowers b JOIN
borrower_attributes ba ON b.borrowernumber = ba.borrowernumber and ba.code = 'fnr'
WHERE categorycode NOT IN ('B','V','REGBARN','REGBARNWEB','REGVOKSEN')
AND b.dateofbirth IS NOT NULL
AND b.deleted_at IS NULL
AND b.lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
GROUP BY categorycode;
EOF
},
{ id => "users_juvenile_but_really_adult",
type => "gauge",
desc => "Lånere med lånekategori barn med alder større eller lik 15 år",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE categorycode='B' AND TIMESTAMPDIFF(YEAR, dateofbirth, now()) >= 15
AND deleted_at IS NULL
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_adult_but_really_juvenile",
type => "gauge",
desc => "Lånere med lånekategori voksen med alder mindre enn 15 år",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE categorycode='V' AND TIMESTAMPDIFF(YEAR, dateofbirth, now()) < 15
AND deleted_at IS NULL
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_selfreg_with_cardnumber",
type => "summary",
desc => "Lånere med lånekategori selvregistrert barn (registrert på nett, ID må verifiseres) eller selvregistrert voksen som har lånekortnummer",
query => <<'EOF',
SELECT categorycode, COUNT(1) AS num FROM borrowers
WHERE categorycode IN ('REGBARN','REGBARNWEB','REGVOKSEN') AND cardnumber IS NOT NULL
AND deleted_at IS NULL
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
GROUP BY categorycode
EOF
},
{ id => "ill_users_missing_endpoint",
type => "gauge",
desc => "Lånere med lånekategori Fjernlan som mangler innhold i NNCIP endpoint",
query => <<'EOF',
SELECT COUNT(1) AS num FROM borrowers b
LEFT JOIN borrower_attributes ba ON (ba.borrowernumber=b.borrowernumber AND ba.code='nncip_uri')
WHERE b.categorycode="IL" AND ba.attribute IS NULL
AND b.deleted_at IS NULL AND b.lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
EOF
},
{ id => "users_category_temporary_location",
type => "gauge",
desc => "Lånere med lånerkategori midlertidig bosatt",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE categorycode='MDL' AND deleted_at IS NULL AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_category_maxlaan",
type => "gauge",
desc => "Lånere med lånerkategori maxlån",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE categorycode='MAXLAAN' AND deleted_at IS NULL AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_weird_test_address",
type => "gauge",
desc => "Lånere med adresse «Forvaltning felles kunderegister» Utviklings- og kompetanseetaten Postboks 6538 Etterstad",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE address like '%Forvaltning felles kunderegister%' AND deleted_at IS NULL
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_missing_smsalertnumber",
type => "gauge",
desc => "Lånere uten sms",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE (smsalertnumber IS NULL OR smsalertnumber = '') AND deleted_at IS NULL
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_missing_alertemail",
type => "gauge",
desc => "Lånere uten epost",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE (alertemail IS NULL OR alertemail = '') AND deleted_at IS NULL
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_missing_alertsms_and_alertemail",
type => "gauge",
desc => "Lånere uten sms og epost",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE (smsalertnumber IS NULL OR smsalertnumber = '') AND (alertemail IS NULL OR alertemail = '')
AND deleted_at IS NULL AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_invalid_sms_number",
type => "summary",
desc => "Sms-nummer som er kortere eller lengre enn 8 siffer",
query => "SELECT length(smsalertnumber) AS length, COUNT(borrowernumber) AS num FROM borrowers WHERE deleted_at IS NULL
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY) GROUP BY length HAVING length != 8",
},
{ id => "users_invalid_sms_number_with_national_prefix",
type => "gauge",
desc => "Mobilnumre med nasjonalt prefix (eks +47)",
query => "SELECT COUNT(1) AS num FROM borrowers WHERE smsalertnumber like '+%' AND deleted_at IS NULL AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)",
},
{ id => "users_sms_alert_missing_number",
type => "gauge",
desc => "SMS-avhuking når låner ikke har sms-nummer",
query => <<'EOF',
SELECT COUNT(DISTINCT borrowernumber) AS num FROM borrowers
JOIN borrower_message_preferences USING(borrowernumber)
JOIN borrower_message_transport_preferences USING (borrower_message_preference_id)
WHERE message_transport_type='sms' AND (smsalertnumber IS NULL OR smsalertnumber = '') AND deleted_at IS NULL
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
EOF
},
{ id => "users_email_alert_missing_email",
type => "gauge",
desc => "E-post-avhuking når låner ikke har epostadresse",
query => <<'EOF',
SELECT COUNT(DISTINCT borrowernumber) AS num FROM borrowers
JOIN borrower_message_preferences USING(borrowernumber)
JOIN borrower_message_transport_preferences USING (borrower_message_preference_id)
WHERE message_transport_type='email' AND (alertemail IS NULL or alertemail = '') AND deleted_at IS NULL
AND lastseen > DATE_SUB(CURDATE(), INTERVAL ? DAY)
EOF
},
);
my @results;
my $t0 = time();
foreach my $q (@queries) {
my $t1 = time();
my $start = Time::Piece->new();
$self->{logger}->info("Executing report id $q->{id}");
my $sth = $dbh->prepare($q->{query});
$sth->execute($days) or Deichman::Exception->throw($dbh->errstr);
my $res = {
type => $q->{type},
id => $q->{id},
desc => $q->{desc},
result => $sth->fetchall_arrayref({}),
};
if ($self->{args} and $self->{args}->{summary} and ($res->{type} ne "summary") ) {
# if summary is wanted and result is more than one row, we override type to summary and return number of rows
if (scalar(@{$res->{result}}) != 1) {
$res->{type} => "summary";
$res->{result} = [{
num => scalar(@{$res->{result}}),
}];
}
}
push @results, $res;
my $elapsed = sprintf("%0.03f s", time() - $t1);
$self->{logger}->info("Finished report " . $q->{id} . " successfully : spent " . $elapsed);
}
$self->{logger}->info("Finished all reports. Total query time: " . $elapsed);
$self->{result} = \@results;
return $self;
}
1;
\ No newline at end of file
Markdown is supported
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment