# connect to database
my $dbh = $form->dbconnect($myconfig);
-
+ # TODO: extract information about income/expense accounts from new table taxzone_chart
my $query = qq|SELECT id, description,
inventory_accno_id,
- (SELECT accno FROM chart WHERE id = inventory_accno_id) AS inventory_accno,
- income_accno_id_0,
- (SELECT accno FROM chart WHERE id = income_accno_id_0) AS income_accno_0,
- expense_accno_id_0,
- (SELECT accno FROM chart WHERE id = expense_accno_id_0) AS expense_accno_0,
- income_accno_id_1,
- (SELECT accno FROM chart WHERE id = income_accno_id_1) AS income_accno_1,
- expense_accno_id_1,
- (SELECT accno FROM chart WHERE id = expense_accno_id_1) AS expense_accno_1,
- income_accno_id_2,
- (SELECT accno FROM chart WHERE id = income_accno_id_2) AS income_accno_2,
- expense_accno_id_2,
- (select accno FROM chart WHERE id = expense_accno_id_2) AS expense_accno_2,
- income_accno_id_3,
- (SELECT accno FROM chart WHERE id = income_accno_id_3) AS income_accno_3,
- expense_accno_id_3,
- (SELECT accno FROM chart WHERE id = expense_accno_id_3) AS expense_accno_3
+ (SELECT accno FROM chart WHERE id = inventory_accno_id) AS inventory_accno
FROM buchungsgruppen
ORDER BY sortkey|;
my $dbh = $form->dbconnect($myconfig);
if ($form->{id}) {
+ # TODO: extract information about income/expense accounts from new table taxzone_chart
$query =
qq|SELECT description, inventory_accno_id,
- (SELECT accno FROM chart WHERE id = inventory_accno_id) AS inventory_accno,
- income_accno_id_0,
- (SELECT accno FROM chart WHERE id = income_accno_id_0) AS income_accno_0,
- expense_accno_id_0,
- (SELECT accno FROM chart WHERE id = expense_accno_id_0) AS expense_accno_0,
- income_accno_id_1,
- (SELECT accno FROM chart WHERE id = income_accno_id_1) AS income_accno_1,
- expense_accno_id_1,
- (SELECT accno FROM chart WHERE id = expense_accno_id_1) AS expense_accno_1,
- income_accno_id_2,
- (SELECT accno FROM chart WHERE id = income_accno_id_2) AS income_accno_2,
- expense_accno_id_2,
- (select accno FROM chart WHERE id = expense_accno_id_2) AS expense_accno_2,
- income_accno_id_3,
- (SELECT accno FROM chart WHERE id = income_accno_id_3) AS income_accno_3,
- expense_accno_id_3,
- (SELECT accno FROM chart WHERE id = expense_accno_id_3) AS expense_accno_3
+ (SELECT accno FROM chart WHERE id = inventory_accno_id) AS inventory_accno
FROM buchungsgruppen
WHERE id = ?|;
my $sth = $dbh->prepare($query);
class => 'SL::DB::Chart',
column_map => { inventory_accno_id => 'id' },
},
- income_account_0 => {
- type => 'many to one',
- class => 'SL::DB::Chart',
- column_map => { income_accno_id_0 => 'id' },
- },
- income_account_1 => {
- type => 'many to one',
- class => 'SL::DB::Chart',
- column_map => { income_accno_id_1 => 'id' },
- },
- income_account_2 => {
- type => 'many to one',
- class => 'SL::DB::Chart',
- column_map => { income_accno_id_2 => 'id' },
- },
- income_account_3 => {
- type => 'many to one',
- class => 'SL::DB::Chart',
- column_map => { income_accno_id_3 => 'id' },
- },
- expense_account_0 => {
- type => 'many to one',
- class => 'SL::DB::Chart',
- column_map => { expense_accno_id_0 => 'id' },
- },
- expense_account_1 => {
- type => 'many to one',
- class => 'SL::DB::Chart',
- column_map => { expense_accno_id_1 => 'id' },
- },
- expense_account_2 => {
- type => 'many to one',
- class => 'SL::DB::Chart',
- column_map => { expense_accno_id_2 => 'id' },
- },
- expense_account_3 => {
- type => 'many to one',
- class => 'SL::DB::Chart',
- column_map => { expense_accno_id_3 => 'id' },
- },
);
__PACKAGE__->meta->initialize;
sub income_accno_id {
my ($self, $taxzone) = @_;
my $taxzone_id = ref $taxzone && $taxzone->isa('SL::DB::TaxZone') ? $taxzone->id : $taxzone;
- my $method = 'income_accno_id_' . $taxzone_id;
-
- return $self->$method;
+ my $taxzone_chart = SL::DB::Manager::TaxzoneChart->find_by(taxzone_id => $taxzone_id, buchungsgruppen_id => $self->id);
+ return $taxzone_chart->income_accno_id if $taxzone_chart;
}
sub expense_accno_id {
my ($self, $taxzone) = @_;
my $taxzone_id = ref $taxzone && $taxzone->isa('SL::DB::TaxZone') ? $taxzone->id : $taxzone;
- my $method = 'expense_accno_id_' . $taxzone_id;
-
- return $self->$method;
+ my $taxzone_chart = SL::DB::Manager::TaxzoneChart->find_by(taxzone_id => $taxzone_id, buchungsgruppen_id => $self->id);
+ return $taxzone_chart->expense_accno_id if $taxzone_chart;
}
sub income_account {
my ($self, $taxzone) = @_;
my $taxzone_id = ref $taxzone && $taxzone->isa('SL::DB::TaxZone') ? $taxzone->id : $taxzone;
- my $method = 'income_account_' . $taxzone_id;
-
- return $self->$method;
+ my $taxzone_chart = SL::DB::Manager::TaxzoneChart->find_by(taxzone_id => $taxzone_id, buchungsgruppen_id => $self->id);
+ return $taxzone_chart->income_accno if $taxzone_chart;
}
sub expense_account {
my ($self, $taxzone) = @_;
my $taxzone_id = ref $taxzone && $taxzone->isa('SL::DB::TaxZone') ? $taxzone->id : $taxzone;
- my $method = 'expense_account_' . $taxzone_id;
-
- return $self->$method;
+ my $taxzone_chart = SL::DB::Manager::TaxzoneChart->find_by(taxzone_id => $taxzone_id, buchungsgruppen_id => $self->id);
+ return $taxzone_chart->expense_accno if $taxzone_chart;
}
1;
use SL::DB::Tax;
use SL::DB::TaxKey;
use SL::DB::TaxZone;
+use SL::DB::TaxzoneChart;
use SL::DB::TodoUserConfig;
use SL::DB::TransferType;
use SL::DB::Translation;
tax => 'tax',
taxkeys => 'tax_key',
tax_zones => 'tax_zone',
+ taxzone_charts => 'taxzone_chart',
todo_user_config => 'todo_user_config',
transfer_type => 'transfer_type',
translation => 'translation',
__PACKAGE__->meta->columns(
description => { type => 'text' },
- expense_accno_id_0 => { type => 'integer' },
- expense_accno_id_1 => { type => 'integer' },
- expense_accno_id_2 => { type => 'integer' },
- expense_accno_id_3 => { type => 'integer' },
- id => { type => 'integer', not_null => 1, sequence => 'id' },
- income_accno_id_0 => { type => 'integer' },
- income_accno_id_1 => { type => 'integer' },
- income_accno_id_2 => { type => 'integer' },
- income_accno_id_3 => { type => 'integer' },
inventory_accno_id => { type => 'integer' },
sortkey => { type => 'integer', not_null => 1 },
);
--- /dev/null
+# This file has been auto-generated. Do not modify it; it will be overwritten
+# by rose_auto_create_model.pl automatically.
+package SL::DB::TaxzoneChart;
+
+use strict;
+
+use base qw(SL::DB::Object);
+
+__PACKAGE__->meta->table('taxzone_charts');
+
+__PACKAGE__->meta->columns(
+ id => { type => 'serial', not_null => 1 },
+ taxzone_id => { type => 'integer', not_null => 1 },
+ buchungsgruppen_id => { type => 'integer', not_null => 1 },
+ income_accno_id => { type => 'integer', not_null => 1 },
+ expense_accno_id => { type => 'integer', not_null => 1 },
+ itime => { type => 'timestamp', default => 'now()' },
+);
+
+__PACKAGE__->meta->primary_key_columns([ 'id' ]);
+
+__PACKAGE__->meta->allow_inline_column_values(1);
+
+__PACKAGE__->meta->foreign_keys(
+ buchungsgruppen => {
+ class => 'SL::DB::Buchungsgruppe',
+ key_columns => { buchungsgruppen_id => 'id' },
+ },
+
+ expense_accno => {
+ class => 'SL::DB::Chart',
+ key_columns => { expense_accno_id => 'id' },
+ },
+
+ income_accno => {
+ class => 'SL::DB::Chart',
+ key_columns => { income_accno_id => 'id' },
+ },
+);
+
+# __PACKAGE__->meta->initialize;
+
+1;
+;
require SL::DB::Buchungsgruppe;
my $bugru = SL::DB::Buchungsgruppe->load_cached($self->buchungsgruppen_id);
my $chart_id = ($type eq 'inventory') ? ($self->inventory_accno_id ? $bugru->inventory_accno_id : undef)
- : $bugru->call_sub("${type}_accno_id_${taxzone}");
+ : $bugru->call_sub("${type}_accno_id", $taxzone);
if ($chart_id) {
my $chart = $all_charts->{$chart_id} // SL::DB::Chart->load_cached($chart_id)->load;
--- /dev/null
+# This file has been auto-generated only because it didn't exist.
+# Feel free to modify it at will; it will not be overwritten automatically.
+
+package SL::DB::TaxzoneChart;
+
+use strict;
+
+use SL::DB::MetaSetup::TaxzoneChart;
+
+__PACKAGE__->meta->initialize;
+
+# Creates get_all, get_all_count, get_all_iterator, delete_all and update_all.
+__PACKAGE__->meta->make_manager_class;
+
+1;
if ($form->{"item"} ne "assembly") {
$subq_expense =
- qq|(SELECT bg.expense_accno_id_0
- FROM buchungsgruppen bg
- WHERE bg.id = | . conv_i($form->{"buchungsgruppen_id"}, 'NULL') . qq|)|;
+ qq|(SELECT tc.expense_accno_id
+ FROM taxzone_charts tc
+ WHERE tc.buchungsgruppen_id = | . conv_i($form->{"buchungsgruppen_id"}, 'NULL') . qq| and tc.taxzone_id = 0)|;
} else {
$subq_expense = "NULL";
}
buchungsgruppen_id = ?,
payment_id = ?,
inventory_accno_id = $subq_inventory,
- income_accno_id = (SELECT bg.income_accno_id_0 FROM buchungsgruppen bg WHERE bg.id = ?),
+ income_accno_id = (SELECT tc.income_accno_id FROM taxzone_charts tc WHERE tc.taxzone_id = 0 and tc.buchungsgruppen_id = ?),
expense_accno_id = $subq_expense,
obsolete = ?,
image = ?,
SELECT
p.id, p.inventory_accno_id AS is_part,
bg.inventory_accno_id,
- bg.income_accno_id_$form->{taxzone_id} AS income_accno_id,
- bg.expense_accno_id_$form->{taxzone_id} AS expense_accno_id,
+ tc.income_accno_id AS income_accno_id,
+ tc.expense_accno_id AS expense_accno_id,
c1.accno AS inventory_accno,
c2.accno AS income_accno,
c3.accno AS expense_accno
FROM parts p
LEFT JOIN buchungsgruppen bg ON p.buchungsgruppen_id = bg.id
+ LEFT JOIN taxzone_charts tc on bg.id = tc.buchungsgruppen_id
LEFT JOIN chart c1 ON bg.inventory_accno_id = c1.id
- LEFT JOIN chart c2 ON bg.income_accno_id_$form->{taxzone_id} = c2.id
- LEFT JOIN chart c3 ON bg.expense_accno_id_$form->{taxzone_id} = c3.id
- WHERE p.id IN ($in)
+ LEFT JOIN chart c2 ON tc.income_accno_id = c2.id
+ LEFT JOIN chart c3 ON tc.expense_accno_id = c3.id
+ WHERE
+ tc.taxzone_id = '$form->{taxzone_id}'
+ and
+ p.id IN ($in)
SQL
my $sth_tax = prepare_query($::form, $dbh, <<SQL);
my $taxzone = $form->{taxzone_id} * 1;
$query =
qq|SELECT i.id, i.qty, i.allocated, i.trans_id, i.base_qty,
- bg.inventory_accno_id, bg.expense_accno_id_${taxzone} AS expense_accno_id, a.transdate
- FROM invoice i, ar a, parts p, buchungsgruppen bg
+ bg.inventory_accno_id, tc.expense_accno_id AS expense_accno_id, a.transdate
+ FROM invoice i, ar a, parts p, buchungsgruppen bg, taxzone_charts tc
WHERE (i.parts_id = p.id)
AND (i.parts_id = ?)
AND ((i.base_qty + i.allocated) > 0)
AND (i.trans_id = a.id)
AND (p.buchungsgruppen_id = bg.id)
+ AND (tc.buchungsgruppen_id = p.buchungsgruppen_id)
+ AND (tc.taxzone_id = ${taxzone})
ORDER BY transdate|;
# ORDER BY transdate guarantees FIFO
FROM invoice i
JOIN parts p ON (i.parts_id = p.id)
LEFT JOIN chart c1 ON ((SELECT inventory_accno_id FROM buchungsgruppen WHERE id = p.buchungsgruppen_id) = c1.id)
- LEFT JOIN chart c2 ON ((SELECT income_accno_id_${taxzone_id} FROM buchungsgruppen WHERE id = p.buchungsgruppen_id) = c2.id)
- LEFT JOIN chart c3 ON ((SELECT expense_accno_id_${taxzone_id} FROM buchungsgruppen WHERE id = p.buchungsgruppen_id) = c3.id)
+ LEFT JOIN chart c2 ON ((SELECT tc.income_accno_id FROM taxzone_charts tc where tc.taxzone_id = '$taxzone_id' and tc.buchungsgruppen_id = p.buchungsgruppen_id) = c2.id)
+ LEFT JOIN chart c3 ON ((SELECT tc.expense_accno_id FROM taxzone_charts tc where tc.taxzone_id = '$taxzone_id' and tc.buchungsgruppen_id = p.buchungsgruppen_id) = c3.id)
LEFT JOIN project pr ON (i.project_id = pr.id)
LEFT JOIN partsgroup pg ON (pg.id = p.partsgroup_id)
FROM buchungsgruppen
WHERE id = p.buchungsgruppen_id) = c1.id)
LEFT JOIN chart c2 ON
- ((SELECT income_accno_id_${taxzone_id}
- FROM buchungsgruppen
- WHERE id = p.buchungsgruppen_id) = c2.id)
+ ((SELECT tc.income_accno_id
+ FROM taxzone_charts tc
+ WHERE tc.taxzone_id = '$taxzone_id' and tc.buchungsgruppen_id = p.buchungsgruppen_id) = c2.id)
LEFT JOIN chart c3 ON
- ((SELECT expense_accno_id_${taxzone_id}
- FROM buchungsgruppen
- WHERE id = p.buchungsgruppen_id) = c3.id)
+ ((SELECT tc.expense_accno_id
+ FROM taxzone_charts tc
+ WHERE tc.taxzone_id = '$taxzone_id' and tc.buchungsgruppen_id = p.buchungsgruppen_id) = c3.id)
LEFT JOIN partsgroup pg ON (pg.id = p.partsgroup_id)
LEFT JOIN price_factors pfac ON (pfac.id = p.price_factor_id)
WHERE $where|;
c3.accno AS expense_accno, c3.new_chart_id AS expense_new_chart, date($transdate) - c3.valid_from AS expense_valid
FROM invoice i, parts p
LEFT JOIN chart c1 ON ((SELECT inventory_accno_id FROM buchungsgruppen WHERE id = p.buchungsgruppen_id) = c1.id)
- LEFT JOIN chart c2 ON ((SELECT income_accno_id_${taxzone_id} FROM buchungsgruppen WHERE id = p.buchungsgruppen_id) = c2.id)
- LEFT JOIN chart c3 ON ((select expense_accno_id_${taxzone_id} FROM buchungsgruppen WHERE id = p.buchungsgruppen_id) = c3.id)
+ LEFT JOIN chart c2 ON ((SELECT tc.income_accno_id FROM taxzone_charts tc WHERE tc.taxzone_id = '$taxzone_id' and tc.buchungsgruppen_id = p.buchungsgruppen_id) = c2.id)
+ LEFT JOIN chart c3 ON ((SELECT tc.expense_accno_id FROM taxzone_charts tc WHERE tc.taxzone_id = '$taxzone_id' and tc.buchungsgruppen_id = p.buchungsgruppen_id) = c3.id)
WHERE (i.parts_id = p.id)
AND (i.parts_id = ?)
AND ((i.base_qty + i.allocated) < 0)
LEFT JOIN pricegroup prg ON (i.pricegroup_id = prg.id)
LEFT JOIN chart c1 ON ((SELECT inventory_accno_id FROM buchungsgruppen WHERE id = p.buchungsgruppen_id) = c1.id)
- LEFT JOIN chart c2 ON ((SELECT income_accno_id_${taxzone_id} FROM buchungsgruppen WHERE id = p.buchungsgruppen_id) = c2.id)
- LEFT JOIN chart c3 ON ((SELECT expense_accno_id_${taxzone_id} FROM buchungsgruppen WHERE id = p.buchungsgruppen_id) = c3.id)
+ LEFT JOIN chart c2 ON ((SELECT tc.income_accno_id FROM taxzone_charts tc WHERE tc.taxzone_id = '$taxzone_id' and tc.buchungsgruppen_id = p.buchungsgruppen_id) = c2.id)
+ LEFT JOIN chart c3 ON ((SELECT tc.expense_accno_id FROM taxzone_charts tc WHERE tc.taxzone_id = '$taxzone_id' and tc.buchungsgruppen_id = p.buchungsgruppen_id) = c3.id)
WHERE (i.trans_id = ?) AND NOT (i.assemblyitem = '1') ORDER BY i.id|;
FROM buchungsgruppen
WHERE id = p.buchungsgruppen_id) = c1.id)
LEFT JOIN chart c2 ON
- ((SELECT income_accno_id_${taxzone_id}
- FROM buchungsgruppen
- WHERE id = p.buchungsgruppen_id) = c2.id)
+ ((SELECT tc.income_accno_id
+ FROM taxzone_charts tc
+ WHERE tc.buchungsgruppen_id = p.buchungsgruppen_id and tc.taxzone_id = ${taxzone_id}) = c2.id)
LEFT JOIN chart c3 ON
- ((SELECT expense_accno_id_${taxzone_id}
- FROM buchungsgruppen
- WHERE id = p.buchungsgruppen_id) = c3.id)
+ ((SELECT tc.expense_accno_id
+ FROM taxzone_charts tc
+ WHERE tc.buchungsgruppen_id = p.buchungsgruppen_id and tc.taxzone_id = ${taxzone_id}) = c3.id)
LEFT JOIN partsgroup pg ON (pg.id = p.partsgroup_id)
LEFT JOIN price_factors pfac ON (pfac.id = p.price_factor_id)
WHERE $where|;
JOIN parts p ON (o.parts_id = p.id)
JOIN oe ON (o.trans_id = oe.id)
LEFT JOIN chart c1 ON ((SELECT inventory_accno_id FROM buchungsgruppen WHERE id=p.buchungsgruppen_id) = c1.id)
- LEFT JOIN chart c2 ON ((SELECT income_accno_id_$form->{taxzone_id} FROM buchungsgruppen WHERE id=p.buchungsgruppen_id) = c2.id)
- LEFT JOIN chart c3 ON ((SELECT expense_accno_id_$form->{taxzone_id} FROM buchungsgruppen WHERE id=p.buchungsgruppen_id) = c3.id)
+ LEFT JOIN chart c2 ON ((SELECT tc.income_accno_id FROM taxzone_charts tc WHERE tc.taxzone_id = '$form->{taxzone_id}' and tc.buchungsgruppen_id = p.buchungsgruppen_id) = c2.id)
+ LEFT JOIN chart c3 ON ((SELECT tc.expense_accno_id FROM taxzone_charts tc WHERE tc.taxzone_id = '$form->{taxzone_id}' and tc.buchungsgruppen_id = p.buchungsgruppen_id) = c3.id)
LEFT JOIN project pr ON (o.project_id = pr.id)
LEFT JOIN partsgroup pg ON (p.partsgroup_id = pg.id) | .
($form->{id}
--- /dev/null
+# @tag: convert_taxzone
+# @description: Setzt Fremdschlüssel und andere constraints auf die Tabellen tax und taxkeys
+# @depends: taxzone_charts
+package SL::DBUpgrade2::convert_taxzone;
+
+use strict;
+use utf8;
+
+use parent qw(SL::DBUpgrade2::Base);
+
+sub run {
+ my ($self) = @_;
+
+ # extract all buchungsgruppen data
+ my $buchungsgruppen_query = <<SQL;
+ SELECT * from buchungsgruppen;
+SQL
+
+ my $sth = $self->dbh->prepare($buchungsgruppen_query);
+ $sth->execute || $::form->dberror($buchungsgruppen_query);
+
+ $::form->{buchungsgruppen} = [];
+ while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
+ push @{ $::form->{buchungsgruppen} }, $ref;
+ }
+ $sth->finish;
+
+ # extract all tax_zone data
+ my $taxzone_query = <<SQL;
+ SELECT * from tax_zones;
+SQL
+
+ $sth = $self->dbh->prepare($taxzone_query);
+ $sth->execute || $::form->dberror($taxzone_query);
+
+ $::form->{taxzones} = [];
+ while (my $ref = $sth->fetchrow_hashref("NAME_lc")) {
+ push @{ $::form->{taxzones} }, $ref;
+ }
+ $sth->finish;
+
+ my $taxzone_charts_update_query;
+ foreach my $taxzone ( @{$::form->{taxzones}} ) {
+ foreach my $buchungsgruppe ( @{$::form->{buchungsgruppen}} ) {
+ my $id = $taxzone->{id};
+ my $income_accno_id = $buchungsgruppe->{"income_accno_id_$id"};
+ my $expense_accno_id = $buchungsgruppe->{"expense_accno_id_$id"};
+ # TODO: check if the variables have a value
+ $taxzone_charts_update_query .= "INSERT INTO taxzone_charts (taxzone_id, buchungsgruppen_id, income_accno_id, expense_accno_id) VALUES ('$taxzone->{id}', '$buchungsgruppe->{id}', $income_accno_id, $expense_accno_id);\n";
+ };
+ };
+ $self->db_query($taxzone_charts_update_query);
+
+ my $clean_buchungsgruppen_query = <<SQL;
+alter table buchungsgruppen drop column income_accno_id_0;
+alter table buchungsgruppen drop column income_accno_id_1;
+alter table buchungsgruppen drop column income_accno_id_2;
+alter table buchungsgruppen drop column income_accno_id_3;
+alter table buchungsgruppen drop column expense_accno_id_0;
+alter table buchungsgruppen drop column expense_accno_id_1;
+alter table buchungsgruppen drop column expense_accno_id_2;
+alter table buchungsgruppen drop column expense_accno_id_3;
+SQL
+ $sth = $self->dbh->prepare($clean_buchungsgruppen_query);
+ $sth->execute || $::form->dberror($clean_buchungsgruppen_query);
+ return 1;
+} # end run
+
+1;
--- /dev/null
+-- @tag: taxzone_charts
+-- @description: Neue Tabelle für Buchungskonten der Steuerzonen
+-- @depends: release_3_0_0
+-- @ignore: 0
+
+CREATE TABLE taxzone_charts (
+ id SERIAL PRIMARY KEY,
+ taxzone_id integer NOT NULL,
+ buchungsgruppen_id integer NOT NULL,
+ income_accno_id integer NOT NULL,
+ expense_accno_id integer NOT NULL,
+ itime timestamp DEFAULT now(),
+ FOREIGN KEY (taxzone_id) REFERENCES tax_zones (id),
+ FOREIGN KEY (income_accno_id) REFERENCES chart (id),
+ FOREIGN KEY (expense_accno_id) REFERENCES chart (id),
+ FOREIGN KEY (buchungsgruppen_id) REFERENCES buchungsgruppen (id)
+);
+
+