initial
This commit is contained in:
99
initial-create-schema.sql
Normal file
99
initial-create-schema.sql
Normal file
@ -0,0 +1,99 @@
|
|||||||
|
create database hausverwaltung;
|
||||||
|
|
||||||
|
use hausverwaltung;
|
||||||
|
|
||||||
|
create table objekt (
|
||||||
|
id integer unsigned not null auto_increment,
|
||||||
|
shortname varchar(32) not null,
|
||||||
|
flaeche decimal (20, 10) not null,
|
||||||
|
constraint primary key (id),
|
||||||
|
constraint unique key uk_objekt_shortname (shortname)
|
||||||
|
) engine=InnoDB;
|
||||||
|
|
||||||
|
create table wohnung (
|
||||||
|
id integer unsigned not null auto_increment,
|
||||||
|
objekt integer unsigned not null,
|
||||||
|
shortname varchar(64) not null,
|
||||||
|
flaeche decimal (20, 10) not null,
|
||||||
|
constraint primary key (id),
|
||||||
|
constraint unique key uk_wohnung_objekt_shortname (objekt, shortname),
|
||||||
|
constraint foreign key fk_wohnung_objekt (objekt)
|
||||||
|
references objekt (id)
|
||||||
|
on delete restrict
|
||||||
|
on update cascade
|
||||||
|
) engine=InnoDB;
|
||||||
|
|
||||||
|
create table mieter (
|
||||||
|
id integer unsigned not null auto_increment,
|
||||||
|
wohnung integer unsigned not null,
|
||||||
|
anrede varchar(128),
|
||||||
|
vorname varchar(128),
|
||||||
|
nachname varchar(128) not null,
|
||||||
|
strasse varchar(128),
|
||||||
|
plz varchar(10),
|
||||||
|
ort varchar(128),
|
||||||
|
telefon varchar(64),
|
||||||
|
einzug date not null,
|
||||||
|
auszug date,
|
||||||
|
constraint primary key (id),
|
||||||
|
constraint foreign key fk_mieter_wohnung (wohnung)
|
||||||
|
references wohnung (id)
|
||||||
|
on delete restrict
|
||||||
|
on update cascade
|
||||||
|
) engine=InnoDB;
|
||||||
|
|
||||||
|
create table zahlung (
|
||||||
|
id integer unsigned not null auto_increment,
|
||||||
|
mieter integer unsigned not null,
|
||||||
|
datum_ist date not null,
|
||||||
|
datum_soll date not null,
|
||||||
|
betrag decimal (20, 10) not null,
|
||||||
|
constraint primary key (id),
|
||||||
|
constraint foreign key fk_zahlung_mieter (mieter)
|
||||||
|
references mieter (id)
|
||||||
|
on delete restrict
|
||||||
|
on update cascade
|
||||||
|
) engine=InnoDB;
|
||||||
|
|
||||||
|
create table miete (
|
||||||
|
id integer unsigned not null auto_increment,
|
||||||
|
wohnung integer unsigned not null,
|
||||||
|
betrag decimal (20, 10) not null,
|
||||||
|
gueltig_ab date not null,
|
||||||
|
gueltig_bis date not null,
|
||||||
|
constraint primary key (id),
|
||||||
|
constraint unique key uk_miete_wohnung_gueltig_ab (wohnung, gueltig_ab),
|
||||||
|
constraint unique key uk_miete_wohnung_gueltig_bis (wohnung, gueltig_bis),
|
||||||
|
constraint foreign key fk_miete_wohnung (wohnung)
|
||||||
|
references wohnung (id)
|
||||||
|
on delete restrict
|
||||||
|
on update cascade
|
||||||
|
) engine=InnoDB;
|
||||||
|
|
||||||
|
create table betriebskosten_vorauszahlung (
|
||||||
|
id integer unsigned not null auto_increment,
|
||||||
|
objekt integer unsigned not null,
|
||||||
|
betrag decimal (20, 10) not null,
|
||||||
|
gueltig_ab date not null,
|
||||||
|
gueltig_bis date not null,
|
||||||
|
constraint primary key (id),
|
||||||
|
constraint unique key uk_betriebskosten_vorauszahlung_objekt_gueltig_ab (objekt, gueltig_ab),
|
||||||
|
constraint unique key uk_betriebskosten_vorauszahlung_objekt_gueltig_bis (objekt, gueltig_bis),
|
||||||
|
constraint foreign key fk_betriebskosten_vorauszahlung_objekt (objekt)
|
||||||
|
references objekt (id)
|
||||||
|
on delete restrict
|
||||||
|
on update cascade
|
||||||
|
) engine=InnoDB;
|
||||||
|
|
||||||
|
create table betriebskosten_abrechnung (
|
||||||
|
id integer unsigned not null auto_increment,
|
||||||
|
objekt integer unsigned not null,
|
||||||
|
jahr year not null,
|
||||||
|
betrag decimal (20, 10) not null,
|
||||||
|
constraint primary key (id),
|
||||||
|
constraint unique key uk_betriebskosten_abrechnung_objekt_jahr (objekt, jahr),
|
||||||
|
constraint foreign key fk_betriebskosten_abrechnung_objekt (objekt)
|
||||||
|
references objekt (id)
|
||||||
|
on delete restrict
|
||||||
|
on update cascade
|
||||||
|
) engine=InnoDB;
|
46
query-jahresabrechnung.sql
Normal file
46
query-jahresabrechnung.sql
Normal file
@ -0,0 +1,46 @@
|
|||||||
|
create or replace view abrechnung1 as
|
||||||
|
select b.jahr as jahr,
|
||||||
|
(b.betrag / o.flaeche * w.flaeche) as anteil,
|
||||||
|
o.shortname as objekt,
|
||||||
|
w.shortname as wohnung,
|
||||||
|
concat(m.vorname, ' ', m.nachname) as mieter,
|
||||||
|
m.id as mieter_id,
|
||||||
|
(timestampdiff(month,
|
||||||
|
if (year(m.einzug) = b.jahr, m.einzug, makedate(b.jahr, 1)),
|
||||||
|
if (m.auszug is not null, m.auszug, last_day(makedate(b.jahr, 365)))
|
||||||
|
) + 1) as nutzungszeit
|
||||||
|
from betriebskosten_abrechnung b,
|
||||||
|
objekt o,
|
||||||
|
wohnung w,
|
||||||
|
mieter m
|
||||||
|
where b.objekt = o.id and
|
||||||
|
w.objekt = o.id and
|
||||||
|
m.wohnung = w.id and
|
||||||
|
(year(m.einzug) = b.jahr or year(m.auszug) = b.jahr);
|
||||||
|
|
||||||
|
create or replace view abrechnung2 as
|
||||||
|
select jahr,
|
||||||
|
anteil / 12 * nutzungszeit as anteil,
|
||||||
|
objekt,
|
||||||
|
wohnung,
|
||||||
|
mieter,
|
||||||
|
mieter_id
|
||||||
|
from abrechnung1;
|
||||||
|
|
||||||
|
create or replace view abrechnung3 as
|
||||||
|
select a.jahr as jahr,
|
||||||
|
a.anteil as anteil,
|
||||||
|
a.objekt as objekt,
|
||||||
|
a.wohnung as wohnung,
|
||||||
|
m.vorname as vorname,
|
||||||
|
m.nachname as nachname,
|
||||||
|
m.anrede as anrede,
|
||||||
|
m.strasse as strasse,
|
||||||
|
m.plz as plz,
|
||||||
|
m.ort as ort
|
||||||
|
from abrechnung2 a,
|
||||||
|
mieter m
|
||||||
|
where m.id = a.mieter_id;
|
||||||
|
|
||||||
|
select * from abrechnung3 where jahr = '2020';
|
||||||
|
|
Reference in New Issue
Block a user