Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

add scripts to backfill undelegated fields in db #833

Merged
merged 12 commits into from
Sep 8, 2021
2 changes: 2 additions & 0 deletions MANIFEST
Original file line number Diff line number Diff line change
Expand Up @@ -56,9 +56,11 @@ share/patch_db_README.txt
share/patch_mysql_db_zonemaster_backend_ver_1.0.3.pl
share/patch_mysql_db_zonemaster_backend_ver_5.0.0.pl
share/patch_mysql_db_zonemaster_backend_ver_5.0.2.pl
share/patch_mysql_db_zonemaster_backend_ver_7.0.0.pl
share/patch_postgresql_db_zonemaster_backend_ver_1.0.3.pl
share/patch_postgresql_db_zonemaster_backend_ver_5.0.0.pl
share/patch_postgresql_db_zonemaster_backend_ver_7.0.0.pl
share/patch_sqlite_db_zonemaster_backend_ver_7.0.0.pl
share/tmpfiles.conf
share/travis_mysql_backend_config.ini
share/travis_postgresql_backend_config.ini
Expand Down
34 changes: 34 additions & 0 deletions share/patch_mysql_db_zonemaster_backend_ver_7.0.0.pl
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
use strict;
use warnings;
use utf8;
use Data::Dumper;
use Encode;
hannaeko marked this conversation as resolved.
Show resolved Hide resolved
use JSON::PP;

use DBI qw(:utils);

use Zonemaster::Backend::Config;
use Zonemaster::Backend::DB::MySQL;

my $config = Zonemaster::Backend::Config->load_config();
if ( $config->DB_engine ne 'MySQL' ) {
die "The configuration file does not contain the MySQL backend";
}
my $db = Zonemaster::Backend::DB::MySQL->from_config( $config );
my $dbh = $db->dbh;


sub patch_db {
my @arefs = $dbh->selectall_array('SELECT id, params from test_results', undef);
foreach my $row (@arefs) {
my $id = @$row[0];
my $raw_params = decode_json(@$row[1]);
my $ds_info_values = scalar( map { grep (!/^$/, values( %$_ ) ) } @{$raw_params->{ds_info}});
hannaeko marked this conversation as resolved.
Show resolved Hide resolved
my $nameservers_values = scalar( map { grep (!/^$/, values( %$_ ) ) } @{$raw_params->{nameservers}});
my $undelegated = $ds_info_values > 0 || $nameservers_values > 0 || 0;

$dbh->do('UPDATE test_results SET undelegated = ? where id = ?', undef, $undelegated, $id);
}
}

patch_db();
56 changes: 54 additions & 2 deletions share/patch_postgresql_db_zonemaster_backend_ver_7.0.0.pl
Original file line number Diff line number Diff line change
Expand Up @@ -20,8 +20,60 @@ sub patch_db {
####################################################################
# TEST RESULTS
####################################################################
$dbh->do( 'ALTER TABLE test_results ADD COLUMN undelegated integer NOT NULL DEFAULT 0' );
eval {
$dbh->do( 'ALTER TABLE test_results ADD COLUMN undelegated integer NOT NULL DEFAULT 0' );
};
print "Error while changing DB schema: " . $@;
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Shouldn't this be printed only if there are errors?

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yes indeed, fixed.


$dbh->do( qq[
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Could this be done using the much simpler for-loop from the MySQL and SQLite implementations?

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

It could but it has a impact on the performance. Processing 13K rows (about 1% of the zonemaster.net database) with the sql statement takes around 1 second and doing it with the while loop takes 17 seconds.

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

That's an impressive difference. But this is a one-time task.
And the SQL statement is quite complex. What are the chances that a bug has snuck into it?

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Fair enough, I can can change it to the other implementation.

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@blacksponge, have you addressed the comment from @mattias-p?

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

It has now been addressed.

update test_results set undelegated = test_results_undelegated.undelegated_bool::int
from (
select
test_results.id,
(
case when ds_filled.ds_filled is null then false else ds_filled.ds_filled end
or
case when ns_filled.ns_filled is null then false else ns_filled.ns_filled end
) as undelegated_bool
from test_results
left join (
select
count(*) > 0 as ds_filled,
id
from (
select
jd.value,
id
from
(
select json_array_elements(params->'ds_info') as ja, id
from test_results
) as s1,
json_each_text(ja) as jd
) as s2
where value is not null and value::text != ''::text
group by id
) as ds_filled on ds_filled.id = test_results.id
left join (
select
count(*) > 0 as ns_filled,
id
from (
select
jd.value,
id
from
(
select json_array_elements(params->'nameservers') as ja, id
from test_results
) as s1,
json_each_text(ja) as jd
) as s2
where value is not null and value::text != ''::text
group by id
) as ns_filled on ns_filled.id = test_results.id
) as test_results_undelegated where test_results.id = test_results_undelegated.id;
] );
}

patch_db();

34 changes: 34 additions & 0 deletions share/patch_sqlite_db_zonemaster_backend_ver_7.0.0.pl
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
use strict;
use warnings;
use utf8;
use Data::Dumper;
use Encode;
hannaeko marked this conversation as resolved.
Show resolved Hide resolved
use JSON::PP;

use DBI qw(:utils);

use Zonemaster::Backend::Config;
use Zonemaster::Backend::DB::SQLite;

my $config = Zonemaster::Backend::Config->load_config();
if ( $config->DB_engine ne 'SQLite' ) {
die "The configuration file does not contain the SQLite backend";
}
my $db = Zonemaster::Backend::DB::SQLite->from_config( $config );
my $dbh = $db->dbh;


sub patch_db {
my @arefs = $dbh->selectall_array('SELECT id, params from test_results', undef);
foreach my $row (@arefs) {
my $id = @$row[0];
my $raw_params = decode_json(@$row[1]);
my $ds_info_values = scalar( map { grep (!/^$/, values( %$_ ) ) } @{$raw_params->{ds_info}});
my $nameservers_values = scalar( map { grep (!/^$/, values( %$_ ) ) } @{$raw_params->{nameservers}});
my $undelegated = $ds_info_values > 0 || $nameservers_values > 0 || 0;

$dbh->do('UPDATE test_results SET undelegated = ? where id = ?', undef, $undelegated, $id);
}
}

patch_db();