diff --git a/arkindex/project/mixins.py b/arkindex/project/mixins.py
index f94a620d8c8b6144371341e2deb94d75cac460e2..12f0c472cc3d103612e26d7145d37295713b8df9 100644
--- a/arkindex/project/mixins.py
+++ b/arkindex/project/mixins.py
@@ -1,6 +1,6 @@
 from django.conf import settings
 from django.core.exceptions import PermissionDenied
-from django.db.models import Case, IntegerField, Q, Value, When, functions
+from django.db.models import IntegerField, Q, Value, functions
 from django.db.models.query_utils import DeferredAttribute
 from django.shortcuts import get_object_or_404
 from django.views.decorators.cache import cache_page
@@ -44,7 +44,7 @@ class ACLMixin(object):
             .filter(public=True) \
             .annotate(max_level=Value(default_level, IntegerField()))
 
-    def rights_filter(self, model, level):
+    def rights_filter(self, model, level, public=False):
         """
         Return a model queryset matching a given access level for this user.
         """
@@ -64,52 +64,33 @@ class ACLMixin(object):
                 .annotate(max_level=Value(Role.Admin.value, IntegerField())) \
                 .order_by(*self.mixin_order_by_fields, 'id')
 
-        qs_filters = (
-            # Filter corpora with a right (direct or via a group)
-            Q(memberships__user=self.user)
-            # Note: in case of direct right, the group level will be skipped (Null value)
-            | Q(memberships__group__memberships__user=self.user)
-        )
-        if include_public:
-            # Also match public corpora for which this user has no right
-            qs_filters |= Q(
-                Q(public=True)
-                & ~Q(memberships__user=self.user)
-                & ~Q(memberships__group__memberships__user=self.user)
+        # Filter users rights and annotate the resulting level for those rights
+        queryset = model.objects \
+            .filter(
+                # Filter instances with rights concerning this user. This may create duplicates
+                Q(memberships__user=self.user)
+                | Q(memberships__group__memberships__user=self.user)
+            ) \
+            .annotate(
+                # Keep only the lowest level for each right via group
+                max_level=functions.Least(
+                    'memberships__level',
+                    # In case of direct right, the group level will be skipped (Null value)
+                    'memberships__group__memberships__level'
+                )
             )
 
-        # Annotate instances for each right. This may return duplicated instances
-        max_level_annotation = functions.Least(
-            'memberships__level',
-            # In case of direct right, group level will be skipped (Null value)
-            'memberships__group__memberships__level'
-        )
+        # Order by decreasing max_level to make sure we keep the max among all rights
+        queryset = queryset.filter(max_level__gte=level) \
+            .order_by(*self.mixin_order_by_fields, 'id', '-max_level') \
+            .distinct(*self.mixin_order_by_fields, 'id')
+
+        # Use a join to add public instances as this is the more elegant solution
         if include_public:
-            # Also annotate public instances with no member right
-            max_level_annotation = Case(
-                When(
-                    Q(
-                        Q(public=True)
-                        & ~Q(memberships__user=self.user)
-                        & ~Q(memberships__group__memberships__user=self.user)
-                    ),
-                    # Set the rôle to guest on public instances
-                    then=Value(Role.Guest.value)
-                ),
-                default=max_level_annotation,
-                output_field=IntegerField()
-            )
+            queryset = queryset.union(self.get_public_instances(model, Role.Guest.value))
 
         # Return distinct corpus with the max right level among matching rights
-        return model.objects \
-            .filter(qs_filters) \
-            .annotate(max_level=max_level_annotation) \
-            .filter(max_level__gte=level) \
-            .order_by(
-                # Order by decreasing max_level to make sure we keep the max among all rights
-                *self.mixin_order_by_fields, 'id', '-max_level'
-            ) \
-            .distinct(*self.mixin_order_by_fields, 'id')
+        return queryset.order_by(*self.mixin_order_by_fields, 'id')
 
     def has_access(self, instance, level):
         self._check_level(level)
diff --git a/arkindex/sql_validation/corpus_rights_filter.sql b/arkindex/sql_validation/corpus_rights_filter.sql
index b0b5f6ed6a6b143144388c027dce6ab7281d18ff..5f58b9c464271829af4cd05093c59bd4f65c3839 100644
--- a/arkindex/sql_validation/corpus_rights_filter.sql
+++ b/arkindex/sql_validation/corpus_rights_filter.sql
@@ -15,5 +15,4 @@ LEFT OUTER JOIN "users_right" T5 ON ("users_group"."id" = T5."content_id"
 WHERE (("users_right"."user_id" = {user_id}
         OR T5."user_id" = {user_id})
        AND LEAST("users_right"."level", T5."level") >= {level})
-ORDER BY "documents_corpus"."id" ASC,
-         "max_level" DESC
+ORDER BY "documents_corpus"."id" ASC
diff --git a/arkindex/sql_validation/corpus_rights_filter_public.sql b/arkindex/sql_validation/corpus_rights_filter_public.sql
index 090c1a9f798f3b9d494cbc4ae7674ec38f09738e..844eb63468435ee9cc691b4f8b5d0167c37795e8 100644
--- a/arkindex/sql_validation/corpus_rights_filter_public.sql
+++ b/arkindex/sql_validation/corpus_rights_filter_public.sql
@@ -1,49 +1,30 @@
-SELECT DISTINCT ON ("documents_corpus"."id") "documents_corpus"."created",
-                   "documents_corpus"."updated",
-                   "documents_corpus"."id",
-                   "documents_corpus"."name",
-                   "documents_corpus"."description",
-                   "documents_corpus"."repository_id",
-                   "documents_corpus"."public",
-                   CASE
-                       WHEN ("documents_corpus"."public"
-                             AND NOT ("users_right"."user_id" = {user_id}
-                                      AND "users_right"."user_id" IS NOT NULL)
-                             AND NOT (T5."user_id" = {user_id}
-                                      AND T5."user_id" IS NOT NULL)) THEN 10
-                       ELSE LEAST("users_right"."level", T5."level")
-                   END AS "max_level"
-FROM "documents_corpus"
-LEFT OUTER JOIN "users_right" ON ("documents_corpus"."id" = "users_right"."content_id"
+(SELECT DISTINCT ON ("documents_corpus"."id") "documents_corpus"."created",
+                        "documents_corpus"."updated",
+                        "documents_corpus"."id",
+                        "documents_corpus"."name",
+                        "documents_corpus"."description",
+                        "documents_corpus"."repository_id",
+                        "documents_corpus"."public",
+                        LEAST("users_right"."level", T5."level") AS "max_level"
+     FROM "documents_corpus"
+     INNER JOIN "users_right" ON ("documents_corpus"."id" = "users_right"."content_id"
                                   AND ("users_right"."content_type_id" = {corpus_type_id}))
-LEFT OUTER JOIN "users_group" ON ("users_right"."group_id" = "users_group"."id")
-LEFT OUTER JOIN "users_right" T5 ON ("users_group"."id" = T5."content_id"
-                                     AND (T5."content_type_id" = {group_type_id}))
-WHERE (("users_right"."user_id" = {user_id}
-        OR T5."user_id" = {user_id}
-        OR ("documents_corpus"."public"
-            AND NOT ("documents_corpus"."id" IN
-                         (SELECT U1."content_id"
-                          FROM "users_right" U1
-                          WHERE (U1."user_id" = {user_id}
-                                 AND U1."content_type_id" = {corpus_type_id}
-                                 AND U1."id" = "users_right"."id")))
-            AND NOT ("documents_corpus"."id" IN
-                         (SELECT U1."content_id"
-                          FROM "users_right" U1
-                          INNER JOIN "users_group" U2 ON (U1."group_id" = U2."id")
-                          INNER JOIN "users_right" U3 ON (U2."id" = U3."content_id"
-                                                          AND (U3."content_type_id" = {group_type_id}))
-                          WHERE (U3."user_id" = {user_id}
-                                 AND U1."content_type_id" = {corpus_type_id}
-                                 AND U1."id" = "users_right"."id")))))
-       AND CASE
-               WHEN ("documents_corpus"."public"
-                     AND NOT ("users_right"."user_id" = {user_id}
-                              AND "users_right"."user_id" IS NOT NULL)
-                     AND NOT (T5."user_id" = {user_id}
-                              AND T5."user_id" IS NOT NULL)) THEN 10
-               ELSE LEAST("users_right"."level", T5."level")
-           END >= 10)
-ORDER BY "documents_corpus"."id" ASC,
-         "max_level" DESC
+     LEFT OUTER JOIN "users_group" ON ("users_right"."group_id" = "users_group"."id")
+     LEFT OUTER JOIN "users_right" T5 ON ("users_group"."id" = T5."content_id"
+                                          AND (T5."content_type_id" = {group_type_id}))
+     WHERE (("users_right"."user_id" = {user_id}
+             OR T5."user_id" = {user_id})
+            AND LEAST("users_right"."level", T5."level") >= {level})
+     ORDER BY "documents_corpus"."id" ASC, "max_level" DESC)
+UNION
+    (SELECT "documents_corpus"."created",
+            "documents_corpus"."updated",
+            "documents_corpus"."id",
+            "documents_corpus"."name",
+            "documents_corpus"."description",
+            "documents_corpus"."repository_id",
+            "documents_corpus"."public",
+            10 AS "max_level"
+     FROM "documents_corpus"
+     WHERE "documents_corpus"."public")
+ORDER BY (3) ASC