#!/usr/bin/perl # debbugs-installsql installs the SQL database using DBIx::Class::DeploymentHandler # and is released under the terms of the GNU GPL version 3, or any # later version, at your option. See the file README and COPYING for # more information. # Copyright 2013-2014 by Don Armstrong . use warnings; use strict; use Getopt::Long; use Pod::Usage; =head1 NAME debbugs-installsql - installs the SQL database using DBIx::Class::DeploymentHandler =head1 SYNOPSIS debbugs-installsql [ --upgrade | --install ] Options: --service postgresql service to connect to --sysconfdir postgresql system configuration directory --deployment-dir SQL deployment directory --debug, -d debugging level (Default 0) --help, -h display this help --man, -m display manual =head1 OPTIONS =over =item B<--service> Postgresl service to connect to (defaults to debbugs) =item B<--sysconfdir> Postgresql sysconf dir. May also be set using the PGSYSCONFDIR environmental variable (which this option overrides). =item B<--deployment-dir> Deployment directory (defaults to /usr/share/debbugs/sqldeployment) =item B<--drop> Drop tables before trying to create them. (Useful for --install, primarily). Defaults to not drop tables for safety. =item B<--debug, -d> Debug verbosity. (Default 0) =item B<--help, -h> Display brief usage information. =item B<--man, -m> Display this manual. =back =head1 EXAMPLES debbugs-installsql =cut use vars qw($DEBUG); # if we're running out of git, we want to use the git base directory as the # first INC directory. If you're not running out of git, or someone has given a # non-absolute INC, don't do that. use FindBin; use if (-d $FindBin::Bin.'/../.git/' && $INC[0] =~ m#^/#), lib => $FindBin::Bin.'/../'; use Debbugs::DB; use Debbugs::DB::Util qw(prepare_execute); use aliased 'DBIx::Class::DeploymentHandler' => 'DH'; my %options = (debug => 0, help => 0, man => 0, overwrite_deployment => 0, drop => 0, service => 'debbugs', deployment_dir => '/usr/share/debbugs/sqldeployment', ); GetOptions(\%options, 'service|s=s', 'dsn=s', 'sysconfdir|c=s', 'install', 'install_version_storage|install-version-storage', 'upgrade', 'drop', 'current_version|current-version', 'overwrite_deployment|overwrite-deployment|force_overwrite|force-overwrite', 'deployment_dir|deployment-dir=s', 'debug|d+','help|h|?','man|m'); pod2usage() if $options{help}; pod2usage({verbose=>2}) if $options{man}; $DEBUG = $options{debug}; my @USAGE_ERRORS; my @exclusive_options = qw(install upgrade current_version install_version_storage); if (1 < grep {exists $options{$_}} @exclusive_options) { push @USAGE_ERRORS,"You must only give one of the ". join(', ',map {s/_/-/g; "--".$_} @exclusive_options). " options"; } if (not grep {exists $options{$_}} @exclusive_options) { $options{current_version} = 1; } pod2usage(join("\n",@USAGE_ERRORS)) if @USAGE_ERRORS; if (exists $options{sysconfdir}) { if (not defined $options{sysconfdir} or not length $options{sysconfdir}) { delete $ENV{PGSYSCONFDIR}; } else { $ENV{PGSYSCONFDIR} = $options{sysconfdir}; } } if (not exists $options{dsn} or not defined $options{dsn} or not length $options{dsn}) { $options{dsn} = 'dbi:Pg:service='.$options{service}; } my $schema = Debbugs::DB->connect($options{dsn}) or die "Unable to connect to database"; my $dh = DH->new({schema => $schema, force_overwrite => $options{overwrite_deployment}, script_directory => $options{deployment_dir}, databases => 'PostgreSQL', sql_translator_args => {producer_args => {postgres_version => 8.1}, add_drop_table => $options{drop}, }, }); if ($options{current_version}) { print "The current database version is: ".$dh->database_version."\n"; exit 0; } elsif ($options{install}) { $dh->prepare_install; $schema->storage-> dbh_do(sub {my ($s,$dbh) = @_; prepare_execute($dbh,<<'SQL');}); CREATE OR REPLACE FUNCTION bin_ver_to_src_pkg(bin_ver INT) RETURNS INT AS $src_pkg_from_bin_ver$ DECLARE src_pkg int; BEGIN SELECT sv.src_pkg INTO STRICT src_pkg FROM bin_ver bv JOIN src_ver sv ON bv.src_ver=sv.id WHERE bv.id=bin_ver; RETURN src_pkg; END $src_pkg_from_bin_ver$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION src_ver_to_src_pkg(src_ver INT) RETURNS INT AS $src_ver_to_src_pkg$ DECLARE src_pkg int; BEGIN SELECT sv.src_pkg INTO STRICT src_pkg FROM src_ver sv WHERE sv.id=src_ver; RETURN src_pkg; END $src_ver_to_src_pkg$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION update_bin_pkg_src_pkg_bin_ver () RETURNS TRIGGER AS $update_bin_pkg_src_pkg_bin_ver$ DECLARE src_ver_rows integer; BEGIN IF (TG_OP = 'DELETE' OR TG_OP = 'UPDATE' ) THEN -- if there is still a bin_ver with this src_pkg, then do nothing PERFORM * FROM bin_ver bv JOIN src_ver sv ON bv.src_ver = sv.id WHERE sv.id = OLD.src_ver LIMIT 2; GET DIAGNOSTICS src_ver_rows = ROW_COUNT; IF (src_ver_rows <= 1) THEN DELETE FROM bin_pkg_src_pkg WHERE bin_pkg=OLD.bin_pkg AND src_pkg=src_ver_to_src_pkg(OLD.src_ver); END IF; END IF; IF (TG_OP = 'INSERT' OR TG_OP = 'UPDATE') THEN BEGIN INSERT INTO bin_pkg_src_pkg (bin_pkg,src_pkg) VALUES (NEW.bin_pkg,src_ver_to_src_pkg(NEW.src_ver)) ON CONFLICT (bin_pkg,src_pkg) DO NOTHING; END; END IF; RETURN NULL; END $update_bin_pkg_src_pkg_bin_ver$ LANGUAGE plpgsql; SQL $dh->install; ## this is lame, but because the current release of DeploymentHandler does ## not support WHERE or quoted indexes properly (fixed in git), we create ## these indexes manually here. $schema->storage-> dbh_do(sub{my ($s,$dbh) = @_; prepare_execute($dbh,<prepare_deploy; $dh->prepare_upgrade; $dh->upgrade; } elsif ($options{install_version_storage}) { $dh->prepare_version_storage_install; $dh->install_version_storage; } __END__