From: Moritz Bunkus Date: Thu, 11 Jul 2013 15:44:35 +0000 (+0200) Subject: Abhängigkeiten von Lieferscheinen und Aufträgen/Angeboten in der Datenbank löschen X-Git-Tag: release-3.1.0beta1~175^2~8 X-Git-Url: http://wagnertech.de/git?a=commitdiff_plain;h=3b9c2119792ae678e9368a0141d7f8646fd6ef42;p=kivitendo-erp.git Abhängigkeiten von Lieferscheinen und Aufträgen/Angeboten in der Datenbank löschen und nicht mehr programmseitig. Das geschieht durch Verwendung von sinnvollen 'ON DELETE CASCADE/SET NULL'-Foreign-Key-Anweisungen und Triggern, die aus diejenigen Tabellen löschen, in denen eine trans_id-Spalte auf mehrere Tabellen verweisen kann (status, ship_to). --- diff --git a/SL/DO.pm b/SL/DO.pm index fb8672c6a..15f1c8d08 100644 --- a/SL/DO.pm +++ b/SL/DO.pm @@ -39,6 +39,8 @@ use YAML; use SL::AM; use SL::Common; use SL::CVar; +use SL::DB::DeliveryOrder; +use SL::DB::Status; use SL::DBUtils; use SL::RecordLinks; use SL::IC; @@ -507,59 +509,16 @@ sub delete { my $form = $main::form; my $spool = $::lx_office_conf{paths}->{spool}; - # connect to database - my $dbh = $form->get_standard_dbh($myconfig); - - # delete spool files - my $query = qq|SELECT s.spoolfile FROM status s WHERE s.trans_id = ?|; - my $sth = prepare_execute_query($form, $dbh, $query, conv_i($form->{id})); - - my $spoolfile; - my @spoolfiles = (); - my @values; - - while (($spoolfile) = $sth->fetchrow_array) { - push @spoolfiles, $spoolfile; - } - $sth->finish(); - - # delete-values - @values = (conv_i($form->{id})); - - # delete status entries - $query = qq|DELETE FROM status - WHERE trans_id = ?|; - do_query($form, $dbh, $query, @values); + my $rc = SL::DB::Order->new->db->with_transaction(sub { + my @spoolfiles = grep { $_ } map { $_->spoolfile } @{ SL::DB::Manager::Status->get_all(where => [ trans_id => $form->{id} ]) }; - # delete individual entries - $query = qq|DELETE FROM delivery_order_items_stock - WHERE delivery_order_item_id IN ( - SELECT id FROM delivery_order_items - WHERE delivery_order_id = ? - )|; - do_query($form, $dbh, $query, @values); - - # delete individual entries - $query = qq|DELETE FROM delivery_order_items - WHERE delivery_order_id = ?|; - do_query($form, $dbh, $query, @values); - - # delete DO record - $query = qq|DELETE FROM delivery_orders - WHERE id = ?|; - do_query($form, $dbh, $query, @values); + SL::DB::DeliveryOrder->new(id => $form->{id})->delete; - $query = qq|DELETE FROM shipto - WHERE trans_id = ? AND module = 'DO'|; - do_query($form, $dbh, $query, @values); - - my $rc = $dbh->commit(); + my $spool = $::lx_office_conf{paths}->{spool}; + unlink map { "$spool/$_" } @spoolfiles if $spool; - if ($rc) { - foreach $spoolfile (@spoolfiles) { - unlink "$spool/$spoolfile" if $spoolfile; - } - } + 1; + }); $main::lxdebug->leave_sub(); diff --git a/SL/OE.pm b/SL/OE.pm index fec7507ca..694732e1d 100644 --- a/SL/OE.pm +++ b/SL/OE.pm @@ -40,7 +40,9 @@ use YAML; use SL::AM; use SL::Common; use SL::CVar; +use SL::DB::Order; use SL::DB::PeriodicInvoicesConfig; +use SL::DB::Status; use SL::DBUtils; use SL::IC; @@ -660,59 +662,16 @@ sub delete { my ($self, $myconfig, $form) = @_; - # connect to database - my $dbh = $form->get_standard_dbh; - $dbh->begin_work; - - # delete spool files - my $query = qq|SELECT s.spoolfile FROM status s | . - qq|WHERE s.trans_id = ?|; - my @values = (conv_i($form->{id})); - my $sth = $dbh->prepare($query); - $sth->execute(@values) || $self->dberror($query); - - my $spoolfile; - my @spoolfiles = (); - - while (($spoolfile) = $sth->fetchrow_array) { - push @spoolfiles, $spoolfile; - } - $sth->finish; - - # delete-values - @values = (conv_i($form->{id})); - - # periodic invoices and their configuration - do_query($form, $dbh, qq|DELETE FROM periodic_invoices WHERE config_id IN (SELECT id FROM periodic_invoices_configs WHERE oe_id = ?)|, @values); - do_query($form, $dbh, qq|DELETE FROM periodic_invoices_configs WHERE oe_id = ?|, @values); - - # delete status entries - $query = qq|DELETE FROM status | . - qq|WHERE trans_id = ?|; - do_query($form, $dbh, $query, @values); - - # delete individual entries - $query = qq|DELETE FROM orderitems | . - qq|WHERE trans_id = ?|; - do_query($form, $dbh, $query, @values); + my $rc = SL::DB::Order->new->db->with_transaction(sub { + my @spoolfiles = grep { $_ } map { $_->spoolfile } @{ SL::DB::Manager::Status->get_all(where => [ trans_id => $form->{id} ]) }; - $query = qq|DELETE FROM shipto | . - qq|WHERE trans_id = ? AND module = 'OE'|; - do_query($form, $dbh, $query, @values); - - # delete OE record - $query = qq|DELETE FROM oe | . - qq|WHERE id = ?|; - do_query($form, $dbh, $query, @values); + SL::DB::Order->new(id => $form->{id})->delete; - my $rc = $dbh->commit; - - if ($rc) { my $spool = $::lx_office_conf{paths}->{spool}; - foreach $spoolfile (@spoolfiles) { - unlink "$spool/$spoolfile" if $spoolfile; - } - } + unlink map { "$spool/$_" } @spoolfiles if $spool; + + 1; + }); $main::lxdebug->leave_sub(); diff --git a/sql/Pg-upgrade2/oe_do_delete_via_trigger.pl b/sql/Pg-upgrade2/oe_do_delete_via_trigger.pl new file mode 100644 index 000000000..34f4a2a40 --- /dev/null +++ b/sql/Pg-upgrade2/oe_do_delete_via_trigger.pl @@ -0,0 +1,77 @@ +# @tag: oe_do_delete_via_trigger +# @description: Aus oe/delivery_orders via Trigger löschen können +# @depends: release_3_0_0 + +package SL::DBUpgrade2::oe_do_delete_via_trigger; + +use utf8; +use strict; + +use parent qw(SL::DBUpgrade2::Base); + +sub run { + my ($self) = @_; + + $self->drop_constraints(table => $_) for qw(periodic_invoices periodic_invoices_configs orderitems delivery_order_items delivery_order_items_stock); + + my @queries = ( + q|ALTER TABLE periodic_invoices ADD CONSTRAINT periodic_invoices_ar_id_fkey FOREIGN KEY (ar_id) REFERENCES ar (id) ON DELETE CASCADE|, + q|ALTER TABLE periodic_invoices ADD CONSTRAINT periodic_invoices_config_id_fkey FOREIGN KEY (config_id) REFERENCES periodic_invoices_configs (id) ON DELETE CASCADE|, + + q|ALTER TABLE periodic_invoices_configs ADD CONSTRAINT periodic_invoices_configs_ar_chart_id_fkey FOREIGN KEY (ar_chart_id) REFERENCES chart (id) ON DELETE RESTRICT|, + q|ALTER TABLE periodic_invoices_configs ADD CONSTRAINT periodic_invoices_configs_oe_id_fkey FOREIGN KEY (oe_id) REFERENCES oe (id) ON DELETE CASCADE|, + q|ALTER TABLE periodic_invoices_configs ADD CONSTRAINT periodic_invoices_configs_printer_id_fkey FOREIGN KEY (printer_id) REFERENCES printers (id) ON DELETE SET NULL|, + + q|ALTER TABLE orderitems ADD CONSTRAINT orderitems_parts_id_fkey FOREIGN KEY (parts_id) REFERENCES parts (id) ON DELETE RESTRICT|, + q|ALTER TABLE orderitems ADD CONSTRAINT orderitems_price_factor_id_fkey FOREIGN KEY (price_factor_id) REFERENCES price_factors (id) ON DELETE RESTRICT|, + q|ALTER TABLE orderitems ADD CONSTRAINT orderitems_pricegroup_id_fkey FOREIGN KEY (pricegroup_id) REFERENCES pricegroup (id) ON DELETE RESTRICT|, + q|ALTER TABLE orderitems ADD CONSTRAINT orderitems_project_id_fkey FOREIGN KEY (project_id) REFERENCES project (id) ON DELETE SET NULL|, + q|ALTER TABLE orderitems ADD CONSTRAINT orderitems_trans_id_fkey FOREIGN KEY (trans_id) REFERENCES oe (id) ON DELETE CASCADE|, + + q|ALTER TABLE delivery_order_items ADD CONSTRAINT delivery_order_items_delivery_order_id_fkey FOREIGN KEY (delivery_order_id) REFERENCES delivery_orders (id) ON DELETE CASCADE|, + q|ALTER TABLE delivery_order_items ADD CONSTRAINT delivery_order_items_parts_id_fkey FOREIGN KEY (parts_id) REFERENCES parts (id) ON DELETE RESTRICT|, + q|ALTER TABLE delivery_order_items ADD CONSTRAINT delivery_order_items_price_factor_id_fkey FOREIGN KEY (price_factor_id) REFERENCES price_factors (id) ON DELETE RESTRICT|, + q|ALTER TABLE delivery_order_items ADD CONSTRAINT delivery_order_items_pricegroup_id_fkey FOREIGN KEY (pricegroup_id) REFERENCES pricegroup (id) ON DELETE RESTRICT|, + q|ALTER TABLE delivery_order_items ADD CONSTRAINT delivery_order_items_project_id_fkey FOREIGN KEY (project_id) REFERENCES project (id) ON DELETE SET NULL|, + + q|ALTER TABLE delivery_order_items_stock ADD CONSTRAINT delivery_order_items_stock_bin_id_fkey FOREIGN KEY (bin_id) REFERENCES bin (id) ON DELETE RESTRICT|, + q|ALTER TABLE delivery_order_items_stock ADD CONSTRAINT delivery_order_items_stock_delivery_order_item_id_fkey FOREIGN KEY (delivery_order_item_id) REFERENCES delivery_order_items (id) ON DELETE CASCADE|, + q|ALTER TABLE delivery_order_items_stock ADD CONSTRAINT delivery_order_items_stock_warehouse_id_fkey FOREIGN KEY (warehouse_id) REFERENCES warehouse (id) ON DELETE RESTRICT|, + + q|CREATE OR REPLACE FUNCTION oe_before_delete_trigger() RETURNS trigger AS $$ + BEGIN + DELETE FROM status WHERE trans_id = OLD.id; + DELETE FROM shipto WHERE (trans_id = OLD.id) AND (module = 'OE'); + + RETURN OLD; + END; + $$ LANGUAGE plpgsql|, + + q|DROP TRIGGER IF EXISTS delete_oe_dependencies ON oe|, + + q|CREATE TRIGGER delete_oe_dependencies + BEFORE DELETE ON oe + FOR EACH ROW EXECUTE PROCEDURE oe_before_delete_trigger()|, + + q|CREATE OR REPLACE FUNCTION delivery_orders_before_delete_trigger() RETURNS trigger AS $$ + BEGIN + DELETE FROM status WHERE trans_id = OLD.id; + DELETE FROM delivery_order_items_stock WHERE delivery_order_item_id IN (SELECT id FROM delivery_order_items WHERE delivery_order_id = OLD.id); + DELETE FROM shipto WHERE (trans_id = OLD.id) AND (module = 'OE'); + + RETURN OLD; + END; + $$ LANGUAGE plpgsql|, + + q|DROP TRIGGER IF EXISTS delete_delivery_orders_dependencies ON delivery_orders|, + + q|CREATE TRIGGER delete_delivery_orders_dependencies + BEFORE DELETE ON delivery_orders + FOR EACH ROW EXECUTE PROCEDURE delivery_orders_before_delete_trigger()|); + + $self->db_query($_) for @queries; + + return 1; +} + +1;