feat(regional): Add master data to DATEV Export (#18755)

* Add master data to export

* add SQL statements to get customers and suppliers

* make data category a string

* fix SQL error

* fix SQL errors

* unique column names

* add encoding of constants

* get customer primary address and contact

* fix typo

* fix typo

* binary response

* add filename

* add filecontent

* rename account columns

* exclude account groups

* use compression, close file before transfer

* fix StringIO

* add basic tests

* fix assertion, merge test methods

* fix indentation

* relative import of constants

* fix path

* import os

* Add default currency to test company

* root accounts with parent = null

* move account-related things to setup()

* add: test headers

* company and filters become class properties

* add: test csv creation

* (fix): add missing account

* (fix): remove wrong space

* add items to sales invoice

* refactor: create test data

* fix: create cost center

* fix: doctype Accoutn

* fix: make sure account belongs to company

* fix: remove customer group and territory, save on a new line

* create default warehouses

* fix: make Item myself

* fix: item defaults are a list

* fix: use my own warehouse

* fix: use my own expense account

* fix: let you take care of the Sales Invoice Item

* fix: import zipfile

* add TODOs

* fix: workaround for pandas bug

* SQL: utf-8 everywhere to make conversion in tests unnecessary

* tests: zipfile must be encoded string

* fix(tests): invalid start byte

* fix(test): give is_zipfile() the file-like object it expects

* fix(test): fix encoding of colums

* fix(get_transactions): as_dict is 1 by default

* fix(tests): allow empty data

* refactor: rename columns in get_account_names

* fix(pandas): keep sorting columns

* fix: "lineterminator" must be a string

* fix(test): check if cost center exists

* fix: credit limit became a child table

* fix: save company after creation

* insert instead of save

* tests: setup_fiscal_year

* fix(test): import cstr

* fix(tests): fiscal year

* fix: can't concat str to bytes

* fix: make csv-encoding work for py2 and py3

* fix(test): use frappe.as_unicode instead of unicode

* fix: use BytesIO instead of StringIO for py3 compatibility

* fix(tests): use BytesIO instead of StringIO for py3 compatibility
This commit is contained in:
Raffael Meyer 2019-11-29 13:02:17 +01:00 committed by Nabin Hait
parent 750b3a5946
commit 0de066c3b1
3 changed files with 961 additions and 265 deletions

View File

@ -10,17 +10,26 @@ Provide a report and downloadable CSV according to the German DATEV format.
from __future__ import unicode_literals
import datetime
import json
import zlib
import zipfile
import six
from six import BytesIO
from six import string_types
import frappe
from frappe import _
import pandas as pd
from .datev_constants import DataCategory
from .datev_constants import Transactions
from .datev_constants import DebtorsCreditors
from .datev_constants import AccountNames
from .datev_constants import QUERY_REPORT_COLUMNS
def execute(filters=None):
"""Entry point for frappe."""
validate(filters)
result = get_gl_entries(filters, as_dict=0)
columns = get_columns()
result = get_transactions(filters, as_dict=0)
columns = QUERY_REPORT_COLUMNS
return columns, result
@ -41,65 +50,8 @@ def validate(filters):
except frappe.DoesNotExistError:
frappe.throw(_('Please create <b>DATEV Settings</b> for Company <b>{}</b>.').format(filters.get('company')))
def get_columns():
"""Return the list of columns that will be shown in query report."""
columns = [
{
"label": "Umsatz (ohne Soll/Haben-Kz)",
"fieldname": "Umsatz (ohne Soll/Haben-Kz)",
"fieldtype": "Currency",
},
{
"label": "Soll/Haben-Kennzeichen",
"fieldname": "Soll/Haben-Kennzeichen",
"fieldtype": "Data",
},
{
"label": "Kontonummer",
"fieldname": "Kontonummer",
"fieldtype": "Data",
},
{
"label": "Gegenkonto (ohne BU-Schlüssel)",
"fieldname": "Gegenkonto (ohne BU-Schlüssel)",
"fieldtype": "Data",
},
{
"label": "Belegdatum",
"fieldname": "Belegdatum",
"fieldtype": "Date",
},
{
"label": "Buchungstext",
"fieldname": "Buchungstext",
"fieldtype": "Text",
},
{
"label": "Beleginfo - Art 1",
"fieldname": "Beleginfo - Art 1",
"fieldtype": "Data",
},
{
"label": "Beleginfo - Inhalt 1",
"fieldname": "Beleginfo - Inhalt 1",
"fieldtype": "Data",
},
{
"label": "Beleginfo - Art 2",
"fieldname": "Beleginfo - Art 2",
"fieldtype": "Data",
},
{
"label": "Beleginfo - Inhalt 2",
"fieldname": "Beleginfo - Inhalt 2",
"fieldtype": "Data",
}
]
return columns
def get_gl_entries(filters, as_dict):
def get_transactions(filters, as_dict=1):
"""
Get a list of accounting entries.
@ -111,7 +63,7 @@ def get_gl_entries(filters, as_dict):
as_dict -- return as list of dicts [0,1]
"""
gl_entries = frappe.db.sql("""
select
SELECT
/* either debit or credit amount; always positive */
case gl.debit when 0 then gl.credit else gl.debit end as 'Umsatz (ohne Soll/Haben-Kz)',
@ -132,7 +84,7 @@ def get_gl_entries(filters, as_dict):
gl.against_voucher_type as 'Beleginfo - Art 2',
gl.against_voucher as 'Beleginfo - Inhalt 2'
from `tabGL Entry` gl
FROM `tabGL Entry` gl
/* Statistisches Konto (Debitoren/Kreditoren) */
left join `tabParty Account` pa
@ -155,15 +107,127 @@ def get_gl_entries(filters, as_dict):
left join `tabAccount` acc_against_pa
on pa.account = acc_against_pa.name
where gl.company = %(company)s
and DATE(gl.posting_date) >= %(from_date)s
and DATE(gl.posting_date) <= %(to_date)s
order by 'Belegdatum', gl.voucher_no""", filters, as_dict=as_dict)
WHERE gl.company = %(company)s
AND DATE(gl.posting_date) >= %(from_date)s
AND DATE(gl.posting_date) <= %(to_date)s
ORDER BY 'Belegdatum', gl.voucher_no""", filters, as_dict=as_dict, as_utf8=1)
return gl_entries
def get_datev_csv(data, filters):
def get_customers(filters):
"""
Get a list of Customers.
Arguments:
filters -- dict of filters to be passed to the sql query
"""
return frappe.db.sql("""
SELECT
acc.account_number as 'Konto',
cus.customer_name as 'Name (Adressatentyp Unternehmen)',
case cus.customer_type when 'Individual' then 1 when 'Company' then 2 else 0 end as 'Adressatentyp',
adr.address_line1 as 'Straße',
adr.pincode as 'Postleitzahl',
adr.city as 'Ort',
UPPER(country.code) as 'Land',
adr.address_line2 as 'Adresszusatz',
con.email_id as 'E-Mail',
coalesce(con.mobile_no, con.phone) as 'Telefon',
cus.website as 'Internet',
cus.tax_id as 'Steuernummer',
ccl.credit_limit as 'Kreditlimit (Debitor)'
FROM `tabParty Account` par
left join `tabAccount` acc
on acc.name = par.account
left join `tabCustomer` cus
on cus.name = par.parent
left join `tabAddress` adr
on adr.name = cus.customer_primary_address
left join `tabCountry` country
on country.name = adr.country
left join `tabContact` con
on con.name = cus.customer_primary_contact
left join `tabCustomer Credit Limit` ccl
on ccl.parent = cus.name
and ccl.company = par.company
WHERE par.company = %(company)s
AND par.parenttype = 'Customer'""", filters, as_dict=1, as_utf8=1)
def get_suppliers(filters):
"""
Get a list of Suppliers.
Arguments:
filters -- dict of filters to be passed to the sql query
"""
return frappe.db.sql("""
SELECT
acc.account_number as 'Konto',
sup.supplier_name as 'Name (Adressatentyp Unternehmen)',
case sup.supplier_type when 'Individual' then '1' when 'Company' then '2' else '0' end as 'Adressatentyp',
adr.address_line1 as 'Straße',
adr.pincode as 'Postleitzahl',
adr.city as 'Ort',
UPPER(country.code) as 'Land',
adr.address_line2 as 'Adresszusatz',
con.email_id as 'E-Mail',
coalesce(con.mobile_no, con.phone) as 'Telefon',
sup.website as 'Internet',
sup.tax_id as 'Steuernummer',
case sup.on_hold when 1 then sup.release_date else null end as 'Zahlungssperre bis'
FROM `tabParty Account` par
left join `tabAccount` acc
on acc.name = par.account
left join `tabSupplier` sup
on sup.name = par.parent
left join `tabDynamic Link` dyn_adr
on dyn_adr.link_name = sup.name
and dyn_adr.link_doctype = 'Supplier'
and dyn_adr.parenttype = 'Address'
left join `tabAddress` adr
on adr.name = dyn_adr.parent
and adr.is_primary_address = '1'
left join `tabCountry` country
on country.name = adr.country
left join `tabDynamic Link` dyn_con
on dyn_con.link_name = sup.name
and dyn_con.link_doctype = 'Supplier'
and dyn_con.parenttype = 'Contact'
left join `tabContact` con
on con.name = dyn_con.parent
and con.is_primary_contact = '1'
WHERE par.company = %(company)s
AND par.parenttype = 'Supplier'""", filters, as_dict=1, as_utf8=1)
def get_account_names(filters):
return frappe.get_list("Account",
fields=["account_number as Konto", "name as Kontenbeschriftung"],
filters={"company": filters.get("company"), "is_group": "0"})
def get_datev_csv(data, filters, csv_class):
"""
Fill in missing columns and return a CSV in DATEV Format.
@ -174,7 +238,46 @@ def get_datev_csv(data, filters):
Arguments:
data -- array of dictionaries
filters -- dict
csv_class -- defines DATA_CATEGORY, FORMAT_NAME and COLUMNS
"""
header = get_header(filters, csv_class)
empty_df = pd.DataFrame(columns=csv_class.COLUMNS)
data_df = pd.DataFrame.from_records(data)
result = empty_df.append(data_df, sort=True)
if csv_class.DATA_CATEGORY == DataCategory.TRANSACTIONS:
result['Belegdatum'] = pd.to_datetime(result['Belegdatum'])
if csv_class.DATA_CATEGORY == DataCategory.ACCOUNT_NAMES:
result['Sprach-ID'] = 'de-DE'
header = ';'.join(header).encode('latin_1')
data = result.to_csv(
# Reason for str(';'): https://github.com/pandas-dev/pandas/issues/6035
sep=str(';'),
# European decimal seperator
decimal=',',
# Windows "ANSI" encoding
encoding='latin_1',
# format date as DDMM
date_format='%d%m',
# Windows line terminator
line_terminator='\r\n',
# Do not number rows
index=False,
# Use all columns defined above
columns=csv_class.COLUMNS
)
if not six.PY2:
data = data.encode('latin_1')
return header + b'\r\n' + data
def get_header(filters, csv_class):
header = [
# A = DATEV format
# DTVF = created by DATEV software,
@ -185,18 +288,8 @@ def get_datev_csv(data, filters):
# 510 = 5.10,
# 720 = 7.20
"510",
# C = Data category
# 21 = Transaction batch (Buchungsstapel),
# 67 = Buchungstextkonstanten,
# 16 = Debitors/Creditors,
# 20 = Account names (Kontenbeschriftungen)
"21",
# D = Format name
# Buchungsstapel,
# Buchungstextkonstanten,
# Debitoren/Kreditoren,
# Kontenbeschriftungen
"Buchungsstapel",
csv_class.DATA_CATEGORY,
csv_class.FORMAT_NAME,
# E = Format version (regarding format name)
"",
# F = Generated on
@ -224,16 +317,17 @@ def get_datev_csv(data, filters):
# P = Transaction batch end date (YYYYMMDD)
frappe.utils.formatdate(filters.get('to_date'), "yyyyMMdd"),
# Q = Description (for example, "January - February 2019 Transactions")
"{} - {} Buchungsstapel".format(
frappe.utils.formatdate(filters.get('from_date'), "MMMM yyyy"),
frappe.utils.formatdate(filters.get('to_date'), "MMMM yyyy")
"{} - {} {}".format(
frappe.utils.formatdate(filters.get('from_date'), "MMMM yyyy"),
frappe.utils.formatdate(filters.get('to_date'), "MMMM yyyy"),
csv_class.FORMAT_NAME
),
# R = Diktatkürzel
"",
# S = Buchungstyp
# 1 = Transaction batch (Buchungsstapel),
# 2 = Annual financial statement (Jahresabschluss)
"1",
"1" if csv_class.DATA_CATEGORY == DataCategory.TRANSACTIONS else "",
# T = Rechnungslegungszweck
"",
# U = Festschreibung
@ -241,185 +335,8 @@ def get_datev_csv(data, filters):
# V = Kontoführungs-Währungskennzeichen des Geldkontos
frappe.get_value("Company", filters.get("company"), "default_currency")
]
columns = [
# All possible columns must tbe listed here, because DATEV requires them to
# be present in the CSV.
# ---
# Umsatz
"Umsatz (ohne Soll/Haben-Kz)",
"Soll/Haben-Kennzeichen",
"WKZ Umsatz",
"Kurs",
"Basis-Umsatz",
"WKZ Basis-Umsatz",
# Konto/Gegenkonto
"Kontonummer",
"Gegenkonto (ohne BU-Schlüssel)",
"BU-Schlüssel",
# Datum
"Belegdatum",
# Belegfelder
"Belegfeld 1",
"Belegfeld 2",
# Weitere Felder
"Skonto",
"Buchungstext",
# OPOS-Informationen
"Postensperre",
"Diverse Adressnummer",
"Geschäftspartnerbank",
"Sachverhalt",
"Zinssperre",
# Digitaler Beleg
"Beleglink",
# Beleginfo
"Beleginfo - Art 1",
"Beleginfo - Inhalt 1",
"Beleginfo - Art 2",
"Beleginfo - Inhalt 2",
"Beleginfo - Art 3",
"Beleginfo - Inhalt 3",
"Beleginfo - Art 4",
"Beleginfo - Inhalt 4",
"Beleginfo - Art 5",
"Beleginfo - Inhalt 5",
"Beleginfo - Art 6",
"Beleginfo - Inhalt 6",
"Beleginfo - Art 7",
"Beleginfo - Inhalt 7",
"Beleginfo - Art 8",
"Beleginfo - Inhalt 8",
# Kostenrechnung
"Kost 1 - Kostenstelle",
"Kost 2 - Kostenstelle",
"Kost-Menge",
# Steuerrechnung
"EU-Land u. UStID",
"EU-Steuersatz",
"Abw. Versteuerungsart",
# L+L Sachverhalt
"Sachverhalt L+L",
"Funktionsergänzung L+L",
# Funktion Steuerschlüssel 49
"BU 49 Hauptfunktionstyp",
"BU 49 Hauptfunktionsnummer",
"BU 49 Funktionsergänzung",
# Zusatzinformationen
"Zusatzinformation - Art 1",
"Zusatzinformation - Inhalt 1",
"Zusatzinformation - Art 2",
"Zusatzinformation - Inhalt 2",
"Zusatzinformation - Art 3",
"Zusatzinformation - Inhalt 3",
"Zusatzinformation - Art 4",
"Zusatzinformation - Inhalt 4",
"Zusatzinformation - Art 5",
"Zusatzinformation - Inhalt 5",
"Zusatzinformation - Art 6",
"Zusatzinformation - Inhalt 6",
"Zusatzinformation - Art 7",
"Zusatzinformation - Inhalt 7",
"Zusatzinformation - Art 8",
"Zusatzinformation - Inhalt 8",
"Zusatzinformation - Art 9",
"Zusatzinformation - Inhalt 9",
"Zusatzinformation - Art 10",
"Zusatzinformation - Inhalt 10",
"Zusatzinformation - Art 11",
"Zusatzinformation - Inhalt 11",
"Zusatzinformation - Art 12",
"Zusatzinformation - Inhalt 12",
"Zusatzinformation - Art 13",
"Zusatzinformation - Inhalt 13",
"Zusatzinformation - Art 14",
"Zusatzinformation - Inhalt 14",
"Zusatzinformation - Art 15",
"Zusatzinformation - Inhalt 15",
"Zusatzinformation - Art 16",
"Zusatzinformation - Inhalt 16",
"Zusatzinformation - Art 17",
"Zusatzinformation - Inhalt 17",
"Zusatzinformation - Art 18",
"Zusatzinformation - Inhalt 18",
"Zusatzinformation - Art 19",
"Zusatzinformation - Inhalt 19",
"Zusatzinformation - Art 20",
"Zusatzinformation - Inhalt 20",
# Mengenfelder LuF
"Stück",
"Gewicht",
# Forderungsart
"Zahlweise",
"Forderungsart",
"Veranlagungsjahr",
"Zugeordnete Fälligkeit",
# Weitere Felder
"Skontotyp",
# Anzahlungen
"Auftragsnummer",
"Buchungstyp",
"USt-Schlüssel (Anzahlungen)",
"EU-Land (Anzahlungen)",
"Sachverhalt L+L (Anzahlungen)",
"EU-Steuersatz (Anzahlungen)",
"Erlöskonto (Anzahlungen)",
# Stapelinformationen
"Herkunft-Kz",
# Technische Identifikation
"Buchungs GUID",
# Kostenrechnung
"Kost-Datum",
# OPOS-Informationen
"SEPA-Mandatsreferenz",
"Skontosperre",
# Gesellschafter und Sonderbilanzsachverhalt
"Gesellschaftername",
"Beteiligtennummer",
"Identifikationsnummer",
"Zeichnernummer",
# OPOS-Informationen
"Postensperre bis",
# Gesellschafter und Sonderbilanzsachverhalt
"Bezeichnung SoBil-Sachverhalt",
"Kennzeichen SoBil-Buchung",
# Stapelinformationen
"Festschreibung",
# Datum
"Leistungsdatum",
"Datum Zuord. Steuerperiode",
# OPOS-Informationen
"Fälligkeit",
# Konto/Gegenkonto
"Generalumkehr (GU)",
# Steuersatz für Steuerschlüssel
"Steuersatz",
"Land"
]
return header
empty_df = pd.DataFrame(columns=columns)
data_df = pd.DataFrame.from_records(data)
result = empty_df.append(data_df)
result['Belegdatum'] = pd.to_datetime(result['Belegdatum'])
header = ';'.join(header).encode('latin_1')
data = result.to_csv(
sep=b';',
# European decimal seperator
decimal=',',
# Windows "ANSI" encoding
encoding='latin_1',
# format date as DDMM
date_format='%d%m',
# Windows line terminator
line_terminator=b'\r\n',
# Do not number rows
index=False,
# Use all columns defined above
columns=columns
)
return header + b'\r\n' + data
@frappe.whitelist()
def download_datev_csv(filters=None):
@ -438,8 +355,31 @@ def download_datev_csv(filters=None):
filters = json.loads(filters)
validate(filters)
data = get_gl_entries(filters, as_dict=1)
frappe.response['result'] = get_datev_csv(data, filters)
frappe.response['doctype'] = 'EXTF_Buchungsstapel'
frappe.response['type'] = 'csv'
# This is where my zip will be written
zip_buffer = BytesIO()
# This is my zip file
datev_zip = zipfile.ZipFile(zip_buffer, mode='w', compression=zipfile.ZIP_DEFLATED)
transactions = get_transactions(filters)
transactions_csv = get_datev_csv(transactions, filters, csv_class=Transactions)
datev_zip.writestr('EXTF_Buchungsstapel.csv', transactions_csv)
account_names = get_account_names(filters)
account_names_csv = get_datev_csv(account_names, filters, csv_class=AccountNames)
datev_zip.writestr('EXTF_Kontenbeschriftungen.csv', account_names_csv)
customers = get_customers(filters)
customers_csv = get_datev_csv(customers, filters, csv_class=DebtorsCreditors)
datev_zip.writestr('EXTF_Kunden.csv', customers_csv)
suppliers = get_suppliers(filters)
suppliers_csv = get_datev_csv(suppliers, filters, csv_class=DebtorsCreditors)
datev_zip.writestr('EXTF_Lieferanten.csv', suppliers_csv)
# You must call close() before exiting your program or essential records will not be written.
datev_zip.close()
frappe.response['filecontent'] = zip_buffer.getvalue()
frappe.response['filename'] = 'DATEV.zip'
frappe.response['type'] = 'binary'

View File

@ -0,0 +1,512 @@
# coding: utf-8
"""Constants used in datev.py."""
TRANSACTION_COLUMNS = [
# All possible columns must tbe listed here, because DATEV requires them to
# be present in the CSV.
# ---
# Umsatz
"Umsatz (ohne Soll/Haben-Kz)",
"Soll/Haben-Kennzeichen",
"WKZ Umsatz",
"Kurs",
"Basis-Umsatz",
"WKZ Basis-Umsatz",
# Konto/Gegenkonto
"Kontonummer",
"Gegenkonto (ohne BU-Schlüssel)",
"BU-Schlüssel",
# Datum
"Belegdatum",
# Belegfelder
"Belegfeld 1",
"Belegfeld 2",
# Weitere Felder
"Skonto",
"Buchungstext",
# OPOS-Informationen
"Postensperre",
"Diverse Adressnummer",
"Geschäftspartnerbank",
"Sachverhalt",
"Zinssperre",
# Digitaler Beleg
"Beleglink",
# Beleginfo
"Beleginfo - Art 1",
"Beleginfo - Inhalt 1",
"Beleginfo - Art 2",
"Beleginfo - Inhalt 2",
"Beleginfo - Art 3",
"Beleginfo - Inhalt 3",
"Beleginfo - Art 4",
"Beleginfo - Inhalt 4",
"Beleginfo - Art 5",
"Beleginfo - Inhalt 5",
"Beleginfo - Art 6",
"Beleginfo - Inhalt 6",
"Beleginfo - Art 7",
"Beleginfo - Inhalt 7",
"Beleginfo - Art 8",
"Beleginfo - Inhalt 8",
# Kostenrechnung
"Kost 1 - Kostenstelle",
"Kost 2 - Kostenstelle",
"Kost-Menge",
# Steuerrechnung
"EU-Land u. UStID",
"EU-Steuersatz",
"Abw. Versteuerungsart",
# L+L Sachverhalt
"Sachverhalt L+L",
"Funktionsergänzung L+L",
# Funktion Steuerschlüssel 49
"BU 49 Hauptfunktionstyp",
"BU 49 Hauptfunktionsnummer",
"BU 49 Funktionsergänzung",
# Zusatzinformationen
"Zusatzinformation - Art 1",
"Zusatzinformation - Inhalt 1",
"Zusatzinformation - Art 2",
"Zusatzinformation - Inhalt 2",
"Zusatzinformation - Art 3",
"Zusatzinformation - Inhalt 3",
"Zusatzinformation - Art 4",
"Zusatzinformation - Inhalt 4",
"Zusatzinformation - Art 5",
"Zusatzinformation - Inhalt 5",
"Zusatzinformation - Art 6",
"Zusatzinformation - Inhalt 6",
"Zusatzinformation - Art 7",
"Zusatzinformation - Inhalt 7",
"Zusatzinformation - Art 8",
"Zusatzinformation - Inhalt 8",
"Zusatzinformation - Art 9",
"Zusatzinformation - Inhalt 9",
"Zusatzinformation - Art 10",
"Zusatzinformation - Inhalt 10",
"Zusatzinformation - Art 11",
"Zusatzinformation - Inhalt 11",
"Zusatzinformation - Art 12",
"Zusatzinformation - Inhalt 12",
"Zusatzinformation - Art 13",
"Zusatzinformation - Inhalt 13",
"Zusatzinformation - Art 14",
"Zusatzinformation - Inhalt 14",
"Zusatzinformation - Art 15",
"Zusatzinformation - Inhalt 15",
"Zusatzinformation - Art 16",
"Zusatzinformation - Inhalt 16",
"Zusatzinformation - Art 17",
"Zusatzinformation - Inhalt 17",
"Zusatzinformation - Art 18",
"Zusatzinformation - Inhalt 18",
"Zusatzinformation - Art 19",
"Zusatzinformation - Inhalt 19",
"Zusatzinformation - Art 20",
"Zusatzinformation - Inhalt 20",
# Mengenfelder LuF
"Stück",
"Gewicht",
# Forderungsart
"Zahlweise",
"Forderungsart",
"Veranlagungsjahr",
"Zugeordnete Fälligkeit",
# Weitere Felder
"Skontotyp",
# Anzahlungen
"Auftragsnummer",
"Buchungstyp",
"USt-Schlüssel (Anzahlungen)",
"EU-Land (Anzahlungen)",
"Sachverhalt L+L (Anzahlungen)",
"EU-Steuersatz (Anzahlungen)",
"Erlöskonto (Anzahlungen)",
# Stapelinformationen
"Herkunft-Kz",
# Technische Identifikation
"Buchungs GUID",
# Kostenrechnung
"Kost-Datum",
# OPOS-Informationen
"SEPA-Mandatsreferenz",
"Skontosperre",
# Gesellschafter und Sonderbilanzsachverhalt
"Gesellschaftername",
"Beteiligtennummer",
"Identifikationsnummer",
"Zeichnernummer",
# OPOS-Informationen
"Postensperre bis",
# Gesellschafter und Sonderbilanzsachverhalt
"Bezeichnung SoBil-Sachverhalt",
"Kennzeichen SoBil-Buchung",
# Stapelinformationen
"Festschreibung",
# Datum
"Leistungsdatum",
"Datum Zuord. Steuerperiode",
# OPOS-Informationen
"Fälligkeit",
# Konto/Gegenkonto
"Generalumkehr (GU)",
# Steuersatz für Steuerschlüssel
"Steuersatz",
"Land"
]
DEBTOR_CREDITOR_COLUMNS = [
# All possible columns must tbe listed here, because DATEV requires them to
# be present in the CSV.
# Columns "Leerfeld" have been replaced with "Leerfeld #" to not confuse pandas
# ---
"Konto",
"Name (Adressatentyp Unternehmen)",
"Unternehmensgegenstand",
"Name (Adressatentyp natürl. Person)",
"Vorname (Adressatentyp natürl. Person)",
"Name (Adressatentyp keine Angabe)",
"Adressatentyp",
"Kurzbezeichnung",
"EU-Land",
"EU-USt-IdNr.",
"Anrede",
"Titel/Akad. Grad",
"Adelstitel",
"Namensvorsatz",
"Adressart",
"Straße",
"Postfach",
"Postleitzahl",
"Ort",
"Land",
"Versandzusatz",
"Adresszusatz",
"Abweichende Anrede",
"Abw. Zustellbezeichnung 1",
"Abw. Zustellbezeichnung 2",
"Kennz. Korrespondenzadresse",
"Adresse gültig von",
"Adresse gültig bis",
"Telefon",
"Bemerkung (Telefon)",
"Telefon Geschäftsleitung",
"Bemerkung (Telefon GL)",
"E-Mail",
"Bemerkung (E-Mail)",
"Internet",
"Bemerkung (Internet)",
"Fax",
"Bemerkung (Fax)",
"Sonstige",
"Bemerkung (Sonstige)",
"Bankleitzahl 1",
"Bankbezeichnung 1",
"Bankkonto-Nummer 1",
"Länderkennzeichen 1",
"IBAN 1",
"Leerfeld 1",
"SWIFT-Code 1",
"Abw. Kontoinhaber 1",
"Kennz. Haupt-Bankverb. 1",
"Bankverb. 1 Gültig von",
"Bankverb. 1 Gültig bis",
"Bankleitzahl 2",
"Bankbezeichnung 2",
"Bankkonto-Nummer 2",
"Länderkennzeichen 2",
"IBAN 2",
"Leerfeld 2",
"SWIFT-Code 2",
"Abw. Kontoinhaber 2",
"Kennz. Haupt-Bankverb. 2",
"Bankverb. 2 gültig von",
"Bankverb. 2 gültig bis",
"Bankleitzahl 3",
"Bankbezeichnung 3",
"Bankkonto-Nummer 3",
"Länderkennzeichen 3",
"IBAN 3",
"Leerfeld 3",
"SWIFT-Code 3",
"Abw. Kontoinhaber 3",
"Kennz. Haupt-Bankverb. 3",
"Bankverb. 3 gültig von",
"Bankverb. 3 gültig bis",
"Bankleitzahl 4",
"Bankbezeichnung 4",
"Bankkonto-Nummer 4",
"Länderkennzeichen 4",
"IBAN 4",
"Leerfeld 4",
"SWIFT-Code 4",
"Abw. Kontoinhaber 4",
"Kennz. Haupt-Bankverb. 4",
"Bankverb. 4 Gültig von",
"Bankverb. 4 Gültig bis",
"Bankleitzahl 5",
"Bankbezeichnung 5",
"Bankkonto-Nummer 5",
"Länderkennzeichen 5",
"IBAN 5",
"Leerfeld 5",
"SWIFT-Code 5",
"Abw. Kontoinhaber 5",
"Kennz. Haupt-Bankverb. 5",
"Bankverb. 5 gültig von",
"Bankverb. 5 gültig bis",
"Leerfeld 6",
"Briefanrede",
"Grußformel",
"Kundennummer",
"Steuernummer",
"Sprache",
"Ansprechpartner",
"Vertreter",
"Sachbearbeiter",
"Diverse-Konto",
"Ausgabeziel",
"Währungssteuerung",
"Kreditlimit (Debitor)",
"Zahlungsbedingung",
"Fälligkeit in Tagen (Debitor)",
"Skonto in Prozent (Debitor)",
"Kreditoren-Ziel 1 (Tage)",
"Kreditoren-Skonto 1 (%)",
"Kreditoren-Ziel 2 (Tage)",
"Kreditoren-Skonto 2 (%)",
"Kreditoren-Ziel 3 Brutto (Tage)",
"Kreditoren-Ziel 4 (Tage)",
"Kreditoren-Skonto 4 (%)",
"Kreditoren-Ziel 5 (Tage)",
"Kreditoren-Skonto 5 (%)",
"Mahnung",
"Kontoauszug",
"Mahntext 1",
"Mahntext 2",
"Mahntext 3",
"Kontoauszugstext",
"Mahnlimit Betrag",
"Mahnlimit %",
"Zinsberechnung",
"Mahnzinssatz 1",
"Mahnzinssatz 2",
"Mahnzinssatz 3",
"Lastschrift",
"Verfahren",
"Mandantenbank",
"Zahlungsträger",
"Indiv. Feld 1",
"Indiv. Feld 2",
"Indiv. Feld 3",
"Indiv. Feld 4",
"Indiv. Feld 5",
"Indiv. Feld 6",
"Indiv. Feld 7",
"Indiv. Feld 8",
"Indiv. Feld 9",
"Indiv. Feld 10",
"Indiv. Feld 11",
"Indiv. Feld 12",
"Indiv. Feld 13",
"Indiv. Feld 14",
"Indiv. Feld 15",
"Abweichende Anrede (Rechnungsadresse)",
"Adressart (Rechnungsadresse)",
"Straße (Rechnungsadresse)",
"Postfach (Rechnungsadresse)",
"Postleitzahl (Rechnungsadresse)",
"Ort (Rechnungsadresse)",
"Land (Rechnungsadresse)",
"Versandzusatz (Rechnungsadresse)",
"Adresszusatz (Rechnungsadresse)",
"Abw. Zustellbezeichnung 1 (Rechnungsadresse)",
"Abw. Zustellbezeichnung 2 (Rechnungsadresse)",
"Adresse Gültig von (Rechnungsadresse)",
"Adresse Gültig bis (Rechnungsadresse)",
"Bankleitzahl 6",
"Bankbezeichnung 6",
"Bankkonto-Nummer 6",
"Länderkennzeichen 6",
"IBAN 6",
"Leerfeld 7",
"SWIFT-Code 6",
"Abw. Kontoinhaber 6",
"Kennz. Haupt-Bankverb. 6",
"Bankverb 6 gültig von",
"Bankverb 6 gültig bis",
"Bankleitzahl 7",
"Bankbezeichnung 7",
"Bankkonto-Nummer 7",
"Länderkennzeichen 7",
"IBAN 7",
"Leerfeld 8",
"SWIFT-Code 7",
"Abw. Kontoinhaber 7",
"Kennz. Haupt-Bankverb. 7",
"Bankverb 7 gültig von",
"Bankverb 7 gültig bis",
"Bankleitzahl 8",
"Bankbezeichnung 8",
"Bankkonto-Nummer 8",
"Länderkennzeichen 8",
"IBAN 8",
"Leerfeld 9",
"SWIFT-Code 8",
"Abw. Kontoinhaber 8",
"Kennz. Haupt-Bankverb. 8",
"Bankverb 8 gültig von",
"Bankverb 8 gültig bis",
"Bankleitzahl 9",
"Bankbezeichnung 9",
"Bankkonto-Nummer 9",
"Länderkennzeichen 9",
"IBAN 9",
"Leerfeld 10",
"SWIFT-Code 9",
"Abw. Kontoinhaber 9",
"Kennz. Haupt-Bankverb. 9",
"Bankverb 9 gültig von",
"Bankverb 9 gültig bis",
"Bankleitzahl 10",
"Bankbezeichnung 10",
"Bankkonto-Nummer 10",
"Länderkennzeichen 10",
"IBAN 10",
"Leerfeld 11",
"SWIFT-Code 10",
"Abw. Kontoinhaber 10",
"Kennz. Haupt-Bankverb. 10",
"Bankverb 10 gültig von",
"Bankverb 10 gültig bis",
"Nummer Fremdsystem",
"Insolvent",
"SEPA-Mandatsreferenz 1",
"SEPA-Mandatsreferenz 2",
"SEPA-Mandatsreferenz 3",
"SEPA-Mandatsreferenz 4",
"SEPA-Mandatsreferenz 5",
"SEPA-Mandatsreferenz 6",
"SEPA-Mandatsreferenz 7",
"SEPA-Mandatsreferenz 8",
"SEPA-Mandatsreferenz 9",
"SEPA-Mandatsreferenz 10",
"Verknüpftes OPOS-Konto",
"Mahnsperre bis",
"Lastschriftsperre bis",
"Zahlungssperre bis",
"Gebührenberechnung",
"Mahngebühr 1",
"Mahngebühr 2",
"Mahngebühr 3",
"Pauschalberechnung",
"Verzugspauschale 1",
"Verzugspauschale 2",
"Verzugspauschale 3",
"Alternativer Suchname",
"Status",
"Anschrift manuell geändert (Korrespondenzadresse)",
"Anschrift individuell (Korrespondenzadresse)",
"Anschrift manuell geändert (Rechnungsadresse)",
"Anschrift individuell (Rechnungsadresse)",
"Fristberechnung bei Debitor",
"Mahnfrist 1",
"Mahnfrist 2",
"Mahnfrist 3",
"Letzte Frist"
]
ACCOUNT_NAME_COLUMNS = [
# Account number
"Konto",
# Account name
"Kontenbeschriftung",
# Language of the account name
# "de-DE" or "en-GB"
"Sprach-ID"
]
QUERY_REPORT_COLUMNS = [
{
"label": "Umsatz (ohne Soll/Haben-Kz)",
"fieldname": "Umsatz (ohne Soll/Haben-Kz)",
"fieldtype": "Currency",
},
{
"label": "Soll/Haben-Kennzeichen",
"fieldname": "Soll/Haben-Kennzeichen",
"fieldtype": "Data",
},
{
"label": "Kontonummer",
"fieldname": "Kontonummer",
"fieldtype": "Data",
},
{
"label": "Gegenkonto (ohne BU-Schlüssel)",
"fieldname": "Gegenkonto (ohne BU-Schlüssel)",
"fieldtype": "Data",
},
{
"label": "Belegdatum",
"fieldname": "Belegdatum",
"fieldtype": "Date",
},
{
"label": "Buchungstext",
"fieldname": "Buchungstext",
"fieldtype": "Text",
},
{
"label": "Beleginfo - Art 1",
"fieldname": "Beleginfo - Art 1",
"fieldtype": "Data",
},
{
"label": "Beleginfo - Inhalt 1",
"fieldname": "Beleginfo - Inhalt 1",
"fieldtype": "Data",
},
{
"label": "Beleginfo - Art 2",
"fieldname": "Beleginfo - Art 2",
"fieldtype": "Data",
},
{
"label": "Beleginfo - Inhalt 2",
"fieldname": "Beleginfo - Inhalt 2",
"fieldtype": "Data",
}
]
class DataCategory():
"""Field of the CSV Header."""
DEBTORS_CREDITORS = "16"
ACCOUNT_NAMES = "20"
TRANSACTIONS = "21"
POSTING_TEXT_CONSTANTS = "67"
class FormatName():
"""Field of the CSV Header, corresponds to DataCategory."""
DEBTORS_CREDITORS = "Debitoren/Kreditoren"
ACCOUNT_NAMES = "Kontenbeschriftungen"
TRANSACTIONS = "Buchungsstapel"
POSTING_TEXT_CONSTANTS = "Buchungstextkonstanten"
class Transactions():
DATA_CATEGORY = DataCategory.TRANSACTIONS
FORMAT_NAME = FormatName.TRANSACTIONS
COLUMNS = TRANSACTION_COLUMNS
class DebtorsCreditors():
DATA_CATEGORY = DataCategory.DEBTORS_CREDITORS
FORMAT_NAME = FormatName.DEBTORS_CREDITORS
COLUMNS = DEBTOR_CREDITOR_COLUMNS
class AccountNames():
DATA_CATEGORY = DataCategory.ACCOUNT_NAMES
FORMAT_NAME = FormatName.ACCOUNT_NAMES
COLUMNS = ACCOUNT_NAME_COLUMNS

View File

@ -0,0 +1,244 @@
# coding=utf-8
from __future__ import unicode_literals
import os
import json
import zipfile
from six import BytesIO
from unittest import TestCase
import frappe
from frappe.utils import getdate, today, now_datetime, cstr
from frappe.test_runner import make_test_objects
from erpnext.accounts.doctype.sales_invoice.test_sales_invoice import create_sales_invoice
from erpnext.accounts.doctype.account.chart_of_accounts.chart_of_accounts import create_charts
from erpnext.regional.report.datev.datev import validate
from erpnext.regional.report.datev.datev import get_transactions
from erpnext.regional.report.datev.datev import get_customers
from erpnext.regional.report.datev.datev import get_suppliers
from erpnext.regional.report.datev.datev import get_account_names
from erpnext.regional.report.datev.datev import get_datev_csv
from erpnext.regional.report.datev.datev import get_header
from erpnext.regional.report.datev.datev import download_datev_csv
from erpnext.regional.report.datev.datev_constants import DataCategory
from erpnext.regional.report.datev.datev_constants import Transactions
from erpnext.regional.report.datev.datev_constants import DebtorsCreditors
from erpnext.regional.report.datev.datev_constants import AccountNames
from erpnext.regional.report.datev.datev_constants import QUERY_REPORT_COLUMNS
def make_company(company_name, abbr):
if not frappe.db.exists("Company", company_name):
company = frappe.get_doc({
"doctype": "Company",
"company_name": company_name,
"abbr": abbr,
"default_currency": "EUR",
"country": "Germany",
"create_chart_of_accounts_based_on": "Standard Template",
"chart_of_accounts": "SKR04 mit Kontonummern"
})
company.insert()
else:
company = frappe.get_doc("Company", company_name)
# indempotent
company.create_default_warehouses()
if not frappe.db.get_value("Cost Center", {"is_group": 0, "company": company.name}):
company.create_default_cost_center()
company.save()
return company
def setup_fiscal_year():
fiscal_year = None
year = cstr(now_datetime().year)
if not frappe.db.get_value("Fiscal Year", {"year": year}, "name"):
try:
fiscal_year = frappe.get_doc({
"doctype": "Fiscal Year",
"year": year,
"year_start_date": "{0}-01-01".format(year),
"year_end_date": "{0}-12-31".format(year)
})
fiscal_year.insert()
except frappe.NameError:
pass
if fiscal_year:
fiscal_year.set_as_default()
def make_customer_with_account(customer_name, company):
acc_name = frappe.db.get_value("Account", {
"account_name": customer_name,
"company": company.name
}, "name")
if not acc_name:
acc = frappe.get_doc({
"doctype": "Account",
"parent_account": "1 - Forderungen aus Lieferungen und Leistungen - _TG",
"account_name": customer_name,
"company": company.name,
"account_type": "Receivable",
"account_number": "10001"
})
acc.insert()
acc_name = acc.name
if not frappe.db.exists("Customer", customer_name):
customer = frappe.get_doc({
"doctype": "Customer",
"customer_name": customer_name,
"customer_type": "Company",
"accounts": [{
"company": company.name,
"account": acc_name
}]
})
customer.insert()
else:
customer = frappe.get_doc("Customer", customer_name)
return customer
def make_item(item_code, company):
warehouse_name = frappe.db.get_value("Warehouse", {
"warehouse_name": "Stores",
"company": company.name
}, "name")
if not frappe.db.exists("Item", item_code):
item = frappe.get_doc({
"doctype": "Item",
"item_code": item_code,
"item_name": item_code,
"description": item_code,
"item_group": "All Item Groups",
"is_stock_item": 0,
"is_purchase_item": 0,
"is_customer_provided_item": 0,
"item_defaults": [{
"default_warehouse": warehouse_name,
"company": company.name
}]
})
item.insert()
else:
item = frappe.get_doc("Item", item_code)
return item
def make_datev_settings(company):
if not frappe.db.exists("DATEV Settings", company.name):
frappe.get_doc({
"doctype": "DATEV Settings",
"client": company.name,
"client_number": "12345",
"consultant_number": "67890"
}).insert()
class TestDatev(TestCase):
def setUp(self):
self.company = make_company("_Test GmbH", "_TG")
self.customer = make_customer_with_account("_Test Kunde GmbH", self.company)
self.filters = {
"company": self.company.name,
"from_date": today(),
"to_date": today()
}
make_datev_settings(self.company)
item = make_item("_Test Item", self.company)
setup_fiscal_year()
warehouse = frappe.db.get_value("Item Default", {
"parent": item.name,
"company": self.company.name
}, "default_warehouse")
income_account = frappe.db.get_value("Account", {
"account_number": "4200",
"company": self.company.name
}, "name")
tax_account = frappe.db.get_value("Account", {
"account_number": "3806",
"company": self.company.name
}, "name")
si = create_sales_invoice(
company=self.company.name,
customer=self.customer.name,
currency=self.company.default_currency,
debit_to=self.customer.accounts[0].account,
income_account="4200 - Erlöse - _TG",
expense_account="6990 - Herstellungskosten - _TG",
cost_center=self.company.cost_center,
warehouse=warehouse,
item=item.name,
do_not_save=1
)
si.append("taxes", {
"charge_type": "On Net Total",
"account_head": tax_account,
"description": "Umsatzsteuer 19 %",
"rate": 19
})
si.save()
si.submit()
def test_columns(self):
def is_subset(get_data, allowed_keys):
"""
Validate that the dict contains only allowed keys.
Params:
get_data -- Function that returns a list of dicts.
allowed_keys -- List of allowed keys
"""
data = get_data(self.filters)
if data == []:
# No data and, therefore, no columns is okay
return True
actual_set = set(data[0].keys())
# allowed set must be interpreted as unicode to match the actual set
allowed_set = set({frappe.as_unicode(key) for key in allowed_keys})
return actual_set.issubset(allowed_set)
self.assertTrue(is_subset(get_transactions, Transactions.COLUMNS))
self.assertTrue(is_subset(get_customers, DebtorsCreditors.COLUMNS))
self.assertTrue(is_subset(get_suppliers, DebtorsCreditors.COLUMNS))
self.assertTrue(is_subset(get_account_names, AccountNames.COLUMNS))
def test_header(self):
self.assertTrue(Transactions.DATA_CATEGORY in get_header(self.filters, Transactions))
self.assertTrue(AccountNames.DATA_CATEGORY in get_header(self.filters, AccountNames))
self.assertTrue(DebtorsCreditors.DATA_CATEGORY in get_header(self.filters, DebtorsCreditors))
def test_csv(self):
test_data = [{
"Umsatz (ohne Soll/Haben-Kz)": 100,
"Soll/Haben-Kennzeichen": "H",
"Kontonummer": "4200",
"Gegenkonto (ohne BU-Schlüssel)": "10000",
"Belegdatum": today(),
"Buchungstext": "No remark",
"Beleginfo - Art 1": "Sales Invoice",
"Beleginfo - Inhalt 1": "SINV-0001"
}]
get_datev_csv(data=test_data, filters=self.filters, csv_class=Transactions)
def test_download(self):
"""Assert that the returned file is a ZIP file."""
download_datev_csv(self.filters)
# zipfile.is_zipfile() expects a file-like object
zip_buffer = BytesIO()
zip_buffer.write(frappe.response['filecontent'])
self.assertTrue(zipfile.is_zipfile(zip_buffer))