238 lines
6.8 KiB
Python
238 lines
6.8 KiB
Python
"""
|
|
This file is part of Accountant.
|
|
|
|
Accountant is free software: you can redistribute it and/or modify
|
|
it under the terms of the GNU Affero General Public License as published by
|
|
the Free Software Foundation, either version 3 of the License, or
|
|
(at your option) any later version.
|
|
|
|
Accountant is distributed in the hope that it will be useful,
|
|
but WITHOUT ANY WARRANTY; without even the implied warranty of
|
|
MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
|
|
GNU Affero General Public License for more details.
|
|
|
|
You should have received a copy of the GNU Affero General Public License
|
|
along with Accountant. If not, see <http://www.gnu.org/licenses/>.
|
|
"""
|
|
from datetime import date
|
|
|
|
import arrow
|
|
|
|
# pylint: disable=no-member,too-few-public-methods
|
|
from . import db
|
|
|
|
|
|
# pylint: disable=too-many-instance-attributes
|
|
class Operation(db.Model):
|
|
"Class used to handle operations."
|
|
# pylint: disable=invalid-name
|
|
id = db.Column(db.Integer, primary_key=True)
|
|
|
|
operation_date = db.Column(
|
|
db.Date,
|
|
nullable=False,
|
|
default=date.today,
|
|
server_default=db.func.current_date(),
|
|
index=True
|
|
)
|
|
label = db.Column(db.String(500), nullable=False)
|
|
value = db.Column(db.Numeric(15, 2), nullable=False)
|
|
|
|
scheduled_operation_id = db.Column(
|
|
db.Integer,
|
|
db.ForeignKey('scheduled_operation.id'),
|
|
index=True
|
|
)
|
|
|
|
scheduled_operation = db.relationship(
|
|
"ScheduledOperation", backref=db.backref('operations', lazy="dynamic")
|
|
)
|
|
|
|
account_id = db.Column(db.Integer, db.ForeignKey('account.id'), index=True)
|
|
|
|
account = db.relationship(
|
|
'Account', backref=db.backref('operations', lazy="dynamic")
|
|
)
|
|
|
|
category = db.Column(db.String(100), nullable=True, index=True)
|
|
|
|
pointed = db.Column(
|
|
db.Boolean,
|
|
nullable=False,
|
|
default=False,
|
|
server_default=db.false()
|
|
)
|
|
|
|
confirmed = db.Column(
|
|
db.Boolean,
|
|
nullable=False,
|
|
default=True,
|
|
server_default=db.true()
|
|
)
|
|
|
|
canceled = db.Column(
|
|
db.Boolean,
|
|
nullable=False,
|
|
default=False,
|
|
server_default=db.false()
|
|
)
|
|
|
|
sold = db.column_property(
|
|
db.func.sum(
|
|
db.case(
|
|
whens={canceled: db.text("0")},
|
|
else_=value
|
|
)
|
|
).over(
|
|
partition_by=[account_id],
|
|
order_by=[
|
|
"operation_date",
|
|
db.desc("value"),
|
|
db.desc("label"),
|
|
id
|
|
]
|
|
).label("sold")
|
|
)
|
|
|
|
def __init__(self, label, value, account_id, operation_date=None,
|
|
category=None, pointed=False, confirmed=True, canceled=False,
|
|
scheduled_operation_id=None):
|
|
self.operation_date = operation_date
|
|
self.label = label
|
|
self.value = value
|
|
self.category = category
|
|
self.account_id = account_id
|
|
self.scheduled_operation_id = scheduled_operation_id
|
|
self.pointed = pointed
|
|
self.confirmed = confirmed
|
|
self.canceled = canceled
|
|
|
|
@classmethod
|
|
def query(cls, begin=None, end=None):
|
|
# We have to use a join because the sold is not computed from the
|
|
# begining.
|
|
base_query = db.session.query(
|
|
cls.id,
|
|
cls.sold
|
|
).subquery()
|
|
|
|
query = db.session.query(
|
|
cls.id,
|
|
cls.operation_date,
|
|
cls.label,
|
|
cls.value,
|
|
base_query.c.sold,
|
|
cls.category,
|
|
cls.scheduled_operation_id,
|
|
cls.account_id,
|
|
cls.pointed,
|
|
cls.confirmed,
|
|
cls.canceled
|
|
).join(
|
|
base_query, base_query.c.id == cls.id
|
|
).order_by(
|
|
db.desc(cls.operation_date),
|
|
cls.value,
|
|
cls.label,
|
|
)
|
|
|
|
if begin:
|
|
query = query.filter(cls.operation_date >= str(begin))
|
|
|
|
if end:
|
|
query = query.filter(cls.operation_date <= str(end))
|
|
|
|
return query
|
|
|
|
@classmethod
|
|
def get_categories_for_range(cls, account, begin, end):
|
|
if isinstance(account, int) or isinstance(account, str):
|
|
account_id = account
|
|
else:
|
|
account_id = account.id
|
|
|
|
query = db.session.query(
|
|
cls.category,
|
|
db.func.sum(
|
|
db.case([(db.func.sign(cls.value) == -1, cls.value)], else_=0)
|
|
).label("expenses"),
|
|
db.func.sum(
|
|
db.case([(db.func.sign(cls.value) == 1, cls.value)], else_=0)
|
|
).label("revenues"),
|
|
db.func.sum(cls.value).label("balance")
|
|
).filter(
|
|
cls.account_id == account_id
|
|
).order_by(
|
|
cls.category
|
|
).group_by(
|
|
cls.category
|
|
)
|
|
|
|
if begin:
|
|
query = query.filter(cls.operation_date >= str(begin))
|
|
|
|
if end:
|
|
query = query.filter(cls.operation_date <= str(end))
|
|
|
|
return query
|
|
|
|
@classmethod
|
|
def get_ohlc_per_day_for_range(cls, account, begin=None, end=None):
|
|
if isinstance(account, int) or isinstance(account, str):
|
|
account_id = account
|
|
else:
|
|
account_id = account.id
|
|
|
|
end = end if end else arrow.now().ceil('month').date()
|
|
|
|
sold = db.func.sum(cls.value).over(
|
|
order_by=[cls.operation_date, db.desc(cls.value), cls.label]
|
|
)
|
|
|
|
previous = sold - cls.value
|
|
|
|
subquery = db.session.query(
|
|
cls.operation_date,
|
|
sold.label("sold"),
|
|
previous.label("previous")
|
|
).filter(
|
|
cls.account_id == account_id,
|
|
cls.canceled == db.false()
|
|
).subquery()
|
|
|
|
query = db.session.query(
|
|
subquery.c.operation_date,
|
|
db.func.first_value(subquery.c.previous).over(
|
|
partition_by=subquery.c.operation_date
|
|
).label("open"),
|
|
db.func.max(
|
|
db.func.greatest(
|
|
subquery.c.previous, subquery.c.sold
|
|
)
|
|
).over(
|
|
partition_by=subquery.c.operation_date
|
|
).label('high'),
|
|
db.func.min(
|
|
db.func.least(
|
|
subquery.c.previous, subquery.c.sold
|
|
)
|
|
).over(
|
|
partition_by=subquery.c.operation_date
|
|
).label('low'),
|
|
db.func.last_value(subquery.c.sold).over(
|
|
partition_by=subquery.c.operation_date
|
|
).label('close')
|
|
).distinct()
|
|
|
|
if begin:
|
|
query = query.filter(subquery.c.operation_date >= str(begin))
|
|
|
|
if end:
|
|
query = query.filter(subquery.c.operation_date <= str(end))
|
|
|
|
query = query.order_by(
|
|
subquery.c.operation_date
|
|
)
|
|
|
|
return query
|