From 090ecc275fbf6b7fc876268db4492b365f8dc4c3 Mon Sep 17 00:00:00 2001
From: Cayo Puigdefabregas <cayo@puigdefabregas.eu>
Date: Wed, 16 Oct 2024 14:17:35 +0200
Subject: [PATCH] fix bug of tag

---
 dashboard/views.py |  12 ++----
 device/models.py   | 102 +++++++++++++++++++++++++++++++++++++++++----
 evidence/models.py |  22 ++++++++++
 3 files changed, 120 insertions(+), 16 deletions(-)

diff --git a/dashboard/views.py b/dashboard/views.py
index b34e2a6..f056523 100644
--- a/dashboard/views.py
+++ b/dashboard/views.py
@@ -69,23 +69,17 @@ class SearchView(InventaryMixin):
         if not matches.size():
             return self.search_hids(query, offset, limit)
 
-        annotations = []
+        devices = []
         for x in matches:
-            annotations.extend(self.get_annotations(x))
+            devices.append(self.get_annotations(x))
 
-        devices = [Device(id=x) for x in set(annotations)]
         count = matches.size()
         return devices, count
 
     def get_annotations(self, xp):
         snap = xp.document.get_data()
         uuid = json.loads(snap).get('uuid')
-
-        return Annotation.objects.filter(
-            type=Annotation.Type.SYSTEM,
-            owner=self.request.user.institution,
-            uuid=uuid
-        ).values_list("value", flat=True).distinct()
+        return Device.get_annotation_from_uuid(uuid, self.request.user.institution)
 
     def search_hids(self, query, offset, limit):
         qry = Q()
diff --git a/device/models.py b/device/models.py
index 926e447..6169f2e 100644
--- a/device/models.py
+++ b/device/models.py
@@ -118,9 +118,32 @@ class Device:
     def get_unassigned(cls, institution, offset=0, limit=None):
 
         sql = """
-              SELECT DISTINCT t1.value from evidence_annotation as t1
-                left join lot_devicelot as t2 on t1.value = t2.device_id
-              where t2.device_id is null and owner_id=={institution} and type=={type}
+            WITH RankedAnnotations AS (
+                SELECT
+                    t1.value,
+                    t1.key,
+                    ROW_NUMBER() OVER (
+                        PARTITION BY t1.uuid
+                        ORDER BY
+                            CASE
+                                WHEN t1.key = 'CUSTOM_ID' THEN 1
+                                WHEN t1.key = 'hidalgo1' THEN 2
+                                ELSE 3
+                            END,
+                            t1.created DESC
+                    ) AS row_num
+                FROM evidence_annotation AS t1
+                LEFT JOIN lot_devicelot AS t2 ON t1.value = t2.device_id
+                WHERE t2.device_id IS NULL
+                  AND t1.owner_id = {institution}
+                  AND t1.type = {type}
+            )
+            SELECT DISTINCT
+                value
+            FROM
+                RankedAnnotations
+            WHERE
+                row_num = 1
         """.format(
             institution=institution.id,
             type=Annotation.Type.SYSTEM,
@@ -144,18 +167,83 @@ class Device:
     def get_unassigned_count(cls, institution):
 
         sql = """
-              SELECT count(DISTINCT t1.value) from evidence_annotation as t1
-                left join lot_devicelot as t2 on t1.value = t2.device_id
-              where t2.device_id is null and owner_id=={institution} and type=={type};
+            WITH RankedAnnotations AS (
+                SELECT
+                    t1.value,
+                    t1.key,
+                    ROW_NUMBER() OVER (
+                        PARTITION BY t1.uuid
+                        ORDER BY
+                            CASE
+                                WHEN t1.key = 'CUSTOM_ID' THEN 1
+                                WHEN t1.key = 'hidalgo1' THEN 2
+                                ELSE 3
+                            END,
+                            t1.created DESC
+                    ) AS row_num
+                FROM evidence_annotation AS t1
+                LEFT JOIN lot_devicelot AS t2 ON t1.value = t2.device_id
+                WHERE t2.device_id IS NULL
+                  AND t1.owner_id = {institution}
+                  AND t1.type = {type}
+            )
+            SELECT
+                COUNT(DISTINCT value)
+            FROM
+                RankedAnnotations
+            WHERE
+                row_num = 1
         """.format(
             institution=institution.id,
             type=Annotation.Type.SYSTEM,
         )
-
         with connection.cursor() as cursor:
             cursor.execute(sql)
             return cursor.fetchall()[0][0]
 
+    @classmethod
+    def get_annotation_from_uuid(cls, uuid, institution):
+        sql = """
+            WITH RankedAnnotations AS (
+                SELECT
+                    t1.value,
+                    t1.key,
+                    ROW_NUMBER() OVER (
+                        PARTITION BY t1.uuid
+                        ORDER BY
+                            CASE
+                                WHEN t1.key = 'CUSTOM_ID' THEN 1
+                                WHEN t1.key = 'hidalgo1' THEN 2
+                                ELSE 3
+                            END,
+                            t1.created DESC
+                    ) AS row_num
+                FROM evidence_annotation AS t1
+                LEFT JOIN lot_devicelot AS t2 ON t1.value = t2.device_id
+                WHERE t2.device_id IS NULL
+                  AND t1.owner_id = {institution}
+                  AND t1.type = {type}
+                  AND t1.uuid = '{uuid}'
+            )
+            SELECT DISTINCT
+                value
+            FROM
+                RankedAnnotations
+            WHERE
+                row_num = 1;
+        """.format(
+            uuid=uuid.replace("-", ""),
+            institution=institution.id,
+            type=Annotation.Type.SYSTEM,
+        )
+
+        annotations = []
+        with connection.cursor() as cursor:
+            cursor.execute(sql)
+            annotations = cursor.fetchall()
+
+        return cls(id=annotations[0][0])
+
     @property
     def is_websnapshot(self):
         if not self.last_evidence:
diff --git a/evidence/models.py b/evidence/models.py
index 667945f..ffc0d84 100644
--- a/evidence/models.py
+++ b/evidence/models.py
@@ -126,8 +126,30 @@ class Evidence:
         return Annotation.objects.filter(
             owner=user.institution,
             type=Annotation.Type.SYSTEM,
+            key="hidalgo1",
         ).order_by("-created").values_list("uuid", flat=True).distinct()
 
+        # annotations = Annotation.objects.filter(
+        #     owner=user.institution,
+        #     type=Annotation.Type.SYSTEM
+        # )
+
+        # annotations = annotations.annotate(
+        #     priority=models.Case(
+        #         models.When(key="CUSTOM_ID", then=1),
+        #         models.When(key="hidalgo1", then=2),
+        #         default=3,
+        #         output_field=models.IntegerField(),
+        #     )
+        # )
+
+        # # sqlite not soport distinct('uuid')
+        # # filtered_uuids = annotations.order_by('uuid', 'priority', '-created').distinct(
+        # #     'uuid').values_list("uuid", flat=True)
+        # filtered_uuids = annotations.order_by('uuid', 'priority', '-created').distinct(
+        #     ).values_list("uuid", flat=True)
+        # return set(filtered_uuids)
+
     def set_components(self):
         snapshot = ParseSnapshot(self.doc).snapshot_json
         self.components = snapshot['components']