Skip to content

Commit

Permalink
order by custom fields (#493)
Browse files Browse the repository at this point in the history
  • Loading branch information
ciur authored Oct 17, 2024
1 parent d83b409 commit adf9cff
Show file tree
Hide file tree
Showing 8 changed files with 377 additions and 49 deletions.
143 changes: 105 additions & 38 deletions papermerge/core/db/doc.py
Original file line number Diff line number Diff line change
Expand Up @@ -18,6 +18,7 @@
Page,
)
from papermerge.core.exceptions import InvalidDateFormat
from papermerge.core.types import OrderEnum

from .common import get_ancestors

Expand Down Expand Up @@ -239,54 +240,120 @@ def update_doc_cfv(
return items


STMT_WITH_ORDER_BY = """
SELECT node.title,
doc.basetreenode_ptr_id AS doc_id,
doc.document_type_id,
cf.cf_id AS cf_id,
cf.cf_name,
cf.cf_type AS cf_type,
cf.cf_extra_data,
cfv.value_monetary,
cfv.id AS cfv_id,
CASE
WHEN(cf.cf_type = 'monetary') THEN cfv.value_monetary
WHEN(cf.cf_type = 'text') THEN cfv.value_text
WHEN(cf.cf_type = 'date') THEN cfv.value_date
WHEN(cf.cf_type = 'boolean') THEN cfv.value_boolean
END AS cf_value
FROM core_document AS doc
JOIN (
SELECT sub2_doc.basetreenode_ptr_id AS doc_id,
CASE
WHEN(sub2_cf.type = 'monetary') THEN sub2_cfv.value_monetary
WHEN(sub2_cf.type = 'text') THEN sub2_cfv.value_text
WHEN(sub2_cf.type = 'date') THEN sub2_cfv.value_date
WHEN(sub2_cf.type = 'boolean') THEN sub2_cfv.value_boolean
END AS cf_value
FROM core_document AS sub2_doc
JOIN document_type_custom_field AS sub2_dtcf ON sub2_dtcf.document_type_id = sub2_doc.document_type_id
JOIN custom_fields AS sub2_cf ON sub2_cf.id = sub2_dtcf.custom_field_id
LEFT OUTER JOIN custom_field_values AS sub2_cfv
ON sub2_cfv.field_id = sub2_cf.id AND sub2_cfv.document_id = sub2_doc.basetreenode_ptr_id
WHERE sub2_doc.document_type_id = :document_type_id AND sub2_cf.name = :custom_field_name
) AS ordered_doc ON ordered_doc.doc_id = doc.basetreenode_ptr_id
JOIN core_basetreenode AS node
ON node.id == doc.basetreenode_ptr_id
JOIN document_type_custom_field AS dtcf ON dtcf.document_type_id = doc.document_type_id
JOIN(
SELECT
sub_cf1.id AS cf_id,
sub_cf1.name AS cf_name,
sub_cf1.type AS cf_type,
sub_cf1.extra_data AS cf_extra_data
FROM document_types AS sub_dt1
JOIN document_type_custom_field AS sub_dtcf1
ON sub_dtcf1.document_type_id = sub_dt1.id
JOIN custom_fields AS sub_cf1
ON sub_cf1.id = sub_dtcf1.custom_field_id
WHERE sub_dt1.id = :document_type_id
) AS cf ON cf.cf_id = dtcf.custom_field_id
LEFT OUTER JOIN custom_field_values AS cfv
ON cfv.field_id = cf.cf_id AND cfv.document_id = doc_id
WHERE doc.document_type_id = :document_type_id
ORDER BY ordered_doc.cf_value {order}
"""

STMT = """
SELECT node.title,
doc.basetreenode_ptr_id AS doc_id,
doc.document_type_id,
cf.cf_id AS cf_id,
cf.cf_name,
cf.cf_type AS cf_type,
cf.cf_extra_data,
cfv.id AS cfv_id,
CASE
WHEN(cf.cf_type = 'monetary') THEN cfv.value_monetary
WHEN(cf.cf_type = 'text') THEN cfv.value_text
WHEN(cf.cf_type = 'date') THEN cfv.value_date
WHEN(cf.cf_type = 'boolean') THEN cfv.value_boolean
END AS cf_value
FROM core_document AS doc
JOIN core_basetreenode AS node
ON node.id == doc.basetreenode_ptr_id
JOIN document_type_custom_field AS dtcf ON dtcf.document_type_id = doc.document_type_id
JOIN(
SELECT
sub_cf1.id AS cf_id,
sub_cf1.name AS cf_name,
sub_cf1.type AS cf_type,
sub_cf1.extra_data AS cf_extra_data
FROM document_types AS sub_dt1
JOIN document_type_custom_field AS sub_dtcf1
ON sub_dtcf1.document_type_id = sub_dt1.id
JOIN custom_fields AS sub_cf1
ON sub_cf1.id = sub_dtcf1.custom_field_id
WHERE sub_dt1.id = :document_type_id
) AS cf ON cf.cf_id = dtcf.custom_field_id
LEFT OUTER JOIN custom_field_values AS cfv
ON cfv.field_id = cf.cf_id AND cfv.document_id = doc_id
WHERE doc.document_type_id = :document_type_id
"""


def get_docs_by_type(
session: Session,
type_id: UUID,
user_id: UUID,
order_by: str | None = None,
order: OrderEnum = OrderEnum.desc,
) -> list[schemas.DocumentCFV]:
"""
Returns list of documents + doc CFv for all documents with of given type
"""
stmt = """
SELECT node.title,
doc.basetreenode_ptr_id AS doc_id,
doc.document_type_id,
cf.cf_id AS cf_id,
cf.cf_name,
cf.cf_type AS cf_type,
cf.cf_extra_data,
cfv.id AS cfv_id,
CASE
WHEN(cf.cf_type = 'monetary') THEN cfv.value_monetary
WHEN(cf.cf_type = 'text') THEN cfv.value_text
WHEN(cf.cf_type = 'date') THEN cfv.value_date
WHEN(cf.cf_type = 'boolean') THEN cfv.value_boolean
END AS cf_value
FROM core_document AS doc
JOIN core_basetreenode AS node
ON node.id == doc.basetreenode_ptr_id
JOIN document_type_custom_field AS dtcf ON dtcf.document_type_id = doc.document_type_id
JOIN(
SELECT
sub_cf1.id AS cf_id,
sub_cf1.name AS cf_name,
sub_cf1.type AS cf_type,
sub_cf1.extra_data AS cf_extra_data
FROM document_types AS sub_dt1
JOIN document_type_custom_field AS sub_dtcf1
ON sub_dtcf1.document_type_id = sub_dt1.id
JOIN custom_fields AS sub_cf1
ON sub_cf1.id = sub_dtcf1.custom_field_id
WHERE sub_dt1.id = :document_type_id
) AS cf ON cf.cf_id = dtcf.custom_field_id
LEFT OUTER JOIN custom_field_values AS cfv
ON cfv.field_id = cf.cf_id AND cfv.document_id = doc_id
WHERE doc.document_type_id = :document_type_id
"""
str_type_id = str(type_id).replace("-", "")
params = {"document_type_id": str_type_id}
results = []
rows = session.execute(text(stmt), params)

if order_by is None:
stmt = STMT
params = {"document_type_id": str_type_id}
rows = session.execute(text(stmt), params)
else:
stmt = STMT_WITH_ORDER_BY.format(order=order.value)
params = {"document_type_id": str_type_id, "custom_field_name": order_by}
rows = session.execute(text(stmt), params)

for document_id, group in itertools.groupby(rows, lambda r: r.doc_id):
items = list(group)
custom_fields = []
Expand Down
23 changes: 21 additions & 2 deletions papermerge/core/routers/documents.py
Original file line number Diff line number Diff line change
Expand Up @@ -3,7 +3,7 @@
from typing import Annotated

from celery.app import default_app as celery_app
from fastapi import APIRouter, Depends, HTTPException, Security, UploadFile
from fastapi import APIRouter, Depends, HTTPException, Query, Security, UploadFile
from pydantic import BaseModel
from sqlalchemy.exc import NoResultFound

Expand All @@ -12,6 +12,17 @@
from papermerge.core import db, schemas, utils
from papermerge.core.auth import get_current_user, scopes
from papermerge.core.models import Document
from papermerge.core.types import OrderEnum

OrderBy = Annotated[
str | None,
Query(
description="""
Name of custom field e.g. 'Total EUR' (without quotes). Note that
custom field name is case sensitive and may include spaces
"""
),
]

router = APIRouter(
prefix="/documents",
Expand All @@ -31,14 +42,22 @@ def get_documents_by_type(
schemas.User, Security(get_current_user, scopes=[scopes.NODE_VIEW])
],
db_session: db.Session = Depends(db.get_session),
order_by: OrderBy = None,
order: OrderEnum = OrderEnum.desc,
) -> list[schemas.DocumentCFV]:
"""
Get all documents of specific type with all custom field values
Required scope: `{scope}`
"""

docs = db.get_docs_by_type(db_session, type_id=document_type_id, user_id=user.id)
docs = db.get_docs_by_type(
db_session,
type_id=document_type_id,
user_id=user.id,
order_by=order_by,
order=order,
)

return docs

Expand Down
5 changes: 5 additions & 0 deletions papermerge/core/types.py
Original file line number Diff line number Diff line change
Expand Up @@ -36,3 +36,8 @@ class TokenData(BaseModel):

CFValueType: TypeAlias = str | int | date | bool | float | None
CFNameType: TypeAlias = str


class OrderEnum(str, Enum):
asc = "asc"
desc = "desc"
137 changes: 137 additions & 0 deletions tests/core/models/test_document.py
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,7 @@
from papermerge.core.db.models import CustomField, CustomFieldValue
from papermerge.core.models import Document, User
from papermerge.core.storage import abs_path
from papermerge.core.types import OrderEnum
from papermerge.test import TestCase
from papermerge.test.baker_recipes import document_recipe, folder_recipe, user_recipe
from papermerge.test.utils import breadcrumb_fmt
Expand Down Expand Up @@ -608,6 +609,142 @@ def test_get_docs_by_type_missmatching_type(db_session: Session, make_document_r
assert len(groceriesDocs) == 2


@pytest.mark.django_db(transaction=True)
def test_get_docs_by_type_order_by_cfv(db_session: Session, make_document_receipt):
"""
`db.get_docs_by_type` with order by parameter
"""
doc_1: Document = make_document_receipt(title="receipt_1.pdf")
doc_2 = make_document_receipt(title="receipt_2.pdf")
doc_3 = make_document_receipt(title="receipt_3.pdf")

user_id = doc_1.user.id
type_id = doc_1.document_type.id

input_data = [
{
"document_id": doc_1.id,
"custom_fields": {
"Shop": "rewe",
"EffectiveDate": "2024-07-01",
"Total": "34",
},
},
{
"document_id": doc_2.id,
"custom_fields": {
"Shop": "rewe",
"EffectiveDate": "2024-10-15",
"Total": "15.63",
},
},
{
"document_id": doc_3.id,
"custom_fields": {
"Shop": "lidl",
"EffectiveDate": "2024-02-25",
"Total": "18.63",
},
},
]
for data in input_data:
db.update_doc_cfv(
db_session,
document_id=data["document_id"],
custom_fields=data["custom_fields"],
)

# sort data by "EffectiveDate" in descending order
items: list[schemas.DocumentCFV] = db.get_docs_by_type(
db_session,
type_id=type_id,
user_id=user_id,
order_by="EffectiveDate", # !!! EffectiveDate !!!
order=OrderEnum.desc, # !!! DESC !!!
)

assert len(items) == 3

results_eff_date_desc = []
for i in range(0, 3):
# !!! EffectiveDate !!!
cf = dict(items[i].custom_fields)
results_eff_date_desc.append(cf["EffectiveDate"])

# !!! EffectiveDate DESC !!!
assert results_eff_date_desc == [
Date(2024, 10, 15),
Date(2024, 7, 1),
Date(2024, 2, 25),
]

# sort data by "EffectiveDate" in ASC order
items: list[schemas.DocumentCFV] = db.get_docs_by_type(
db_session,
type_id=type_id,
user_id=user_id,
order_by="EffectiveDate", # !!! EffectiveDate !!!
order=OrderEnum.asc, # !!! ASC !!!
)

results_eff_date_asc = []
for i in range(0, 3):
# !!! EffectiveDate !!!
cf = dict(items[i].custom_fields)
results_eff_date_asc.append(cf["EffectiveDate"])

# !!! ASC !!!
assert results_eff_date_asc == [
Date(2024, 2, 25),
Date(2024, 7, 1),
Date(2024, 10, 15),
]

# sort data by "Total" in DESC order
items: list[schemas.DocumentCFV] = db.get_docs_by_type(
db_session,
type_id=type_id,
user_id=user_id,
order_by="Total", # !!! Total !!!
order=OrderEnum.desc, # !!! desc !!!
)

results_total_desc = []
for i in range(0, 3):
# !!! Total !!!
cf = dict(items[i].custom_fields)
results_total_desc.append(cf["Total"])

# !!! DESC !!!
assert results_total_desc == [
34,
18.63,
15.63,
]

# sort data by "Total" in ASC order
items: list[schemas.DocumentCFV] = db.get_docs_by_type(
db_session,
type_id=type_id,
user_id=user_id,
order_by="Total", # !!! Total !!!
order=OrderEnum.asc, # !!! ASC !!!
)

results_total_asc = []
for i in range(0, 3):
# !!! Total !!!
cf = dict(items[i].custom_fields)
results_total_asc.append(cf["Total"])

# !!! ASC !!!
assert results_total_asc == [
15.63,
18.63,
34,
]


def test_str2date():
assert str2date("2024-10-30") == datetime(2024, 10, 30).date()
assert str2date("2024-10-30 00:00:00") == datetime(2024, 10, 30).date()
Loading

0 comments on commit adf9cff

Please sign in to comment.