procedure for monatl. forderungen
This commit is contained in:
@ -24,3 +24,109 @@ create or replace view monatl_forderung_heute as
|
||||
mz.gueltig_ab <= now() and
|
||||
(mz.gueltig_bis is null or mz.gueltig_bis >= now());
|
||||
|
||||
|
||||
create table logging (
|
||||
id integer unsigned not null auto_increment,
|
||||
ts timestamp default current_timestamp,
|
||||
entry varchar(2048),
|
||||
constraint primary key (id)
|
||||
) engine=InnoDB;
|
||||
|
||||
|
||||
delimiter //
|
||||
|
||||
create or replace procedure log(in p_entry varchar(2048))
|
||||
begin
|
||||
insert into logging (entry) values(p_entry);
|
||||
end;
|
||||
//
|
||||
|
||||
alter table miete drop constraint uk_miete_wohnung_gueltig_bis;
|
||||
alter table miete modify column gueltig_bis date null;
|
||||
alter table wohnung add column wohnungsnummer integer;
|
||||
alter table wohnung add constraint unique key uk_wohnung_objekt_wohnungsnummer (objekt, wohnungsnummer);
|
||||
alter table wohnung modify column wohnungsnummer integer not null;
|
||||
alter table betriebskosten_vorauszahlung drop constraint uk_betriebskosten_vorauszahlung_objekt_gueltig_bis;
|
||||
alter table betriebskosten_vorauszahlung modify gueltig_bis date null;
|
||||
alter table forderung modify column betrag decimal(20, 2) not null;
|
||||
alter table zahlung modify column betrag decimal(20, 2) not null;
|
||||
|
||||
create or replace procedure insert_monatl_miet_forderung(in p_date date)
|
||||
modifies sql data
|
||||
begin
|
||||
declare v_date date;
|
||||
declare v_miete_per_squaremeter decimal(20, 10);
|
||||
declare v_miete decimal(20, 10);
|
||||
declare v_betriebskosten_vorauszahlung_per_squaremeter decimal(20, 10);
|
||||
declare v_betriebskosten_vorauszahlung decimal(20, 10);
|
||||
declare v_forderung decimal(20, 10);
|
||||
declare v_flaeche decimal(20, 10);
|
||||
declare v_kommentar varchar(128);
|
||||
declare c_mieter
|
||||
cursor (cp_date date) for
|
||||
select id, wohnung
|
||||
from mieter
|
||||
where einzug <= cp_date and
|
||||
(auszug is null or auszug > cp_date);
|
||||
|
||||
if p_date is null then
|
||||
set v_date = curdate();
|
||||
else
|
||||
set v_date = p_date;
|
||||
end if;
|
||||
call log(concat('date is ', cast(v_date as char)));
|
||||
|
||||
for rec in c_mieter(v_date) do
|
||||
select m.betrag into v_miete_per_squaremeter
|
||||
from miete m,
|
||||
wohnung w
|
||||
where w.id = rec.wohnung and
|
||||
w.id = m.wohnung and
|
||||
m.gueltig_ab <= v_date and
|
||||
(m.gueltig_bis is null or m.gueltig_bis > v_date);
|
||||
select b.betrag into v_betriebskosten_vorauszahlung_per_squaremeter
|
||||
from betriebskosten_vorauszahlung b,
|
||||
wohnung w,
|
||||
objekt o
|
||||
where w.id = rec.wohnung and
|
||||
o.id = w.objekt and
|
||||
o.id = b.objekt and
|
||||
b.gueltig_ab <= v_date and
|
||||
(b.gueltig_bis is null or b.gueltig_bis > v_date);
|
||||
select flaeche into v_flaeche
|
||||
from wohnung
|
||||
where id = rec.wohnung;
|
||||
set v_miete = v_miete_per_squaremeter * v_flaeche;
|
||||
set v_betriebskosten_vorauszahlung = v_betriebskosten_vorauszahlung_per_squaremeter * v_flaeche;
|
||||
set v_forderung = v_miete + v_betriebskosten_vorauszahlung;
|
||||
set lc_time_names = 'de_DE';
|
||||
set v_kommentar = concat('Miete ', monthname(v_date), ' ', year(v_date));
|
||||
|
||||
insert into forderung (mieter, datum, betrag, kommentar, ref_wohnung)
|
||||
values(rec.id, v_date, v_forderung, v_kommentar, rec.wohnung);
|
||||
|
||||
call log(concat('Mieter: ', cast(rec.id as char),
|
||||
', Wohnung: ',
|
||||
cast(rec.wohnung as char),
|
||||
', Flaeche: ',
|
||||
cast(v_flaeche as char),
|
||||
', Miete: ',
|
||||
cast(v_miete_per_squaremeter as char),
|
||||
', ',
|
||||
cast(v_miete as char),
|
||||
', BKV: ',
|
||||
cast(v_betriebskosten_vorauszahlung_per_squaremeter as char),
|
||||
', ',
|
||||
cast(v_betriebskosten_vorauszahlung as char),
|
||||
', Forderung: ',
|
||||
cast(v_forderung as char),
|
||||
', Kommentar: ',
|
||||
v_kommentar
|
||||
)
|
||||
);
|
||||
end for;
|
||||
end;
|
||||
//
|
||||
|
||||
|
||||
|
||||
|
Reference in New Issue
Block a user