Skip to content
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
4 changes: 2 additions & 2 deletions .vscode/settings.json
Original file line number Diff line number Diff line change
@@ -1,8 +1,8 @@
{
"commentTranslate.hover.enabled": true,
"chat.agent.enabled": true,
"chat.commandCenter.enabled": false,
"chat.notifyWindowOnConfirmation": false,
"telemetry.feedback.enabled": false,
"deno.enable": false
"deno.enable": false,
"sql-formatter.uppercase": false,
}
216 changes: 216 additions & 0 deletions src/assets/migration/v6.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,216 @@
-- create centralized tagged items table to simplify searching and tagging
begin;

create table TaggedItems (
id integer primary key,
tagId integer not null references Tags(id) on delete cascade,
fileId integer references FileRecords(id) on delete cascade,
folderId integer references Folders(id) on delete cascade,
-- items can only ever inherit tags from an ancestor folder. When this inherited folder is deleted, this tag should be removed too since it's no longer inherited
implicitFromId integer references Folders(id) on delete cascade default null,
-- make sure that either a file or a folder was tagged
check ((fileId is not null) != (folderId is not null))
);

-- partial unique to prevent the same tag from being applied to a tagged item
create unique index idx_tagged_items_unique_file on TaggedItems(tagId, fileId)
where
fileId is not null;

create unique index idx_tagged_items_unique_folder on TaggedItems(tagId, folderId)
where
folderId is not null;

-- migrate all direct tags for files
insert into
TaggedItems(tagId, fileId)
select
tagId,
fileRecordId
from
Files_Tags;

-- migrate all direct tags for folders
insert into
TaggedItems(tagId, folderId)
select
tagId,
folderId
from
Folders_Tags;

/*
populating inherited tags for folders (needs to be done first so that files work):
1. recursively get all parent folders along with how far needed to be traveled for that parent folder (depth)
2. get all tags for all parent folders
3. for any duplicate tags, take only the ancestor id with the lowest depth (lower depth = higher specificity)

if ai is helpful for anything, it's providing an example that I can adapt while I properly read how recursive sql queries work.
Previously, I was flailing around. It helps me if I think of it as a do while loop and temporary named queries / functions
*/
with recursive -- traverse the ancestor tree and track depth
ancestors(folderId, ancestorId, depth) as (
-- base case: select all folders that have a parent
select
id as folderId,
parentId as ancestorId,
1 as depth
from
folders
where
parentId is not null
union
all -- iteration: keep retrieving parents from base case until there are no more parents
select
a.folderId,
f.parentId as ancestorId,
a.depth + 1
from
ancestors a
join folders f on f.id = a.ancestorId
where
f.parentId is not null
),
-- include all tags with fetched ancestors
ancestorTags as (
select
a.folderId,
ft.tagId,
a.ancestorId,
a.depth
from
ancestors a
join folders_tags ft on ft.folderId = a.ancestorId
),
-- iterate through all retrieved ancestors. For each entry, find the tag on the ancestor with the lowest depth
nearestTags as (
select
at.folderId,
at.tagId,
at.ancestorId
from
ancestorTags at
where
at.ancestorId = (
-- compare on the current row and find the nearest ancestor
select
at2.ancestorId
from
ancestorTags at2
where
at2.folderId = at.folderId
and at2.tagId = at.tagId
order by
at2.depth asc
limit
1
)
) -- now that we have our functions, we can invoke nearestTags to get all the inherited tags and insert them
insert into
TaggedItems(tagId, folderId, implicitFromId)
select
n.tagId,
n.folderId,
n.ancestorId
from
nearestTags n -- important to not include tags that are directly on the folder
where
not exists (
select
1
from
TaggedItems ti
where
ti.tagId = n.tagId
and ti.folderId = n.folderId
);

-- populate inherited tags for files: for each file, walk its containing folder(s)' ancestor chain
-- and pick the nearest ancestor that provides a tag, then insert an inherited row for the file
with recursive ancestors(fileId, directFolderId, ancestorId, depth) as (
-- base: each file's direct containing folder is the first ancestor (so tags on the folder itself are inherited)
select
ff.fileId,
ff.folderId,
ff.folderId as ancestorId,
1 as depth
from
Folder_Files ff
union
all -- climb up the folder parent chain
select
fa.fileId,
fa.directFolderId,
f.parentId as ancestorId,
fa.depth + 1
from
ancestors fa
join Folders f on f.id = fa.ancestorId
where
f.parentId is not null
),
-- join the discovered ancestors to tags present on those ancestor folders
ancestorTags as (
select
fa.fileId,
ft.tagId,
fa.ancestorId,
fa.depth
from
ancestors fa
join Folders_Tags ft on ft.folderId = fa.ancestorId
),
-- for each (file,tag) choose the nearest ancestor (smallest depth)
nearestTags as (
select
cft.fileId,
cft.tagId,
cft.ancestorId
from
ancestorTags cft
where
cft.ancestorId = (
select
cft2.ancestorId
from
ancestorTags cft2
where
cft2.fileId = cft.fileId
and cft2.tagId = cft.tagId
order by
cft2.depth asc
limit
1
)
)
insert into
TaggedItems(tagId, fileId, implicitFromId)
select
n.tagId,
n.fileId,
n.ancestorId
from
nearestTags n
where
not exists (
select
1
from
TaggedItems ti
where
ti.tagId = n.tagId
and ti.fileId = n.fileId
);

drop table folders_tags;

drop table files_tags;

update
metadata
set
value = 6
where
name = 'version';

commit;
4 changes: 2 additions & 2 deletions src/assets/queries/file/get_files_by_all_tags.sql
Original file line number Diff line number Diff line change
Expand Up @@ -8,8 +8,8 @@ select
group_concat(t.title)
from
FileRecords f
join Files_Tags ft on f.id = ft.fileRecordId
join Tags t on ft.tagId = t.id
join TaggedItems ti on f.id = ti.fileId
join Tags t on ti.tagId = t.id
left join main.Folder_Files FF on f.id = FF.fileId
where
t.title in (?1)
Expand Down
19 changes: 13 additions & 6 deletions src/assets/queries/folder/get_folders_by_any_tag.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,13 @@
select f.id, f.name, f.parentId, group_concat(t.title)
from folders f
join Folders_Tags ft on f.id = ft.folderId
join tags t on t.id = ft.tagId
where t.title in (?1)
group by f.id;
select
f.id,
f.name,
f.parentId,
group_concat(t.title)
from
folders f
join TaggedItems ti on ti.folderId = f.id
join tags t on t.id = ti.tagId
where
t.title in (?1)
group by
f.id;
35 changes: 23 additions & 12 deletions src/assets/queries/folder/get_parent_folders_with_tags.sql
Original file line number Diff line number Diff line change
@@ -1,14 +1,25 @@
with recursive query(id) as (values (?1)
union
select parentId
from Folders,
query
where Folders.id = query.id)
select parentId, group_concat(t.title)
from Folders
left join folders_tags ft on ft.folderId = folders.parentId
left join tags t on t.id = ft.tagId
where Folders.parentId in query
with recursive query(id) as (
values
(?1)
union
select
parentId
from
Folders,
query
where
Folders.id = query.id
)
select
parentId,
group_concat(t.title)
from
Folders
left join TaggedItems ti on ti.folderId = folders.parentId
left join tags t on t.id = ti.tagId
where
Folders.parentId in query
and parentId <> ?1
and t.title in (?2)
group by parentId;
group by
parentId;
6 changes: 4 additions & 2 deletions src/assets/queries/tags/add_tag_to_file.sql
Original file line number Diff line number Diff line change
@@ -1,2 +1,4 @@
insert into Files_Tags(fileRecordId, tagId)
values(?1, ?2)
insert
or ignore into TaggedItems (fileId, tagId)
values
(?1, ?2)
6 changes: 4 additions & 2 deletions src/assets/queries/tags/add_tag_to_folder.sql
Original file line number Diff line number Diff line change
@@ -1,2 +1,4 @@
insert into Folders_Tags(folderId, tagId)
values (?1, ?2)
insert
or ignore into TaggedItems (folderId, tagId)
values
(?1, ?2)
16 changes: 12 additions & 4 deletions src/assets/queries/tags/get_tags_for_file.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,12 @@
select Tags.id, Tags.title
from Tags
join Files_Tags on Tags.id = Files_Tags.tagId
where Files_Tags.fileRecordId = ?1;
select
ti.id,
ti.fileId,
ti.folderId,
ti.implicitFromId,
t.id,
t.title
from
Tags t
join TaggedItems ti on t.id = ti.tagId
where
ti.fileId = ?1
16 changes: 12 additions & 4 deletions src/assets/queries/tags/get_tags_for_files.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,12 @@
select Files_Tags.fileRecordId, Tags.id, Tags.title
from Tags
join Files_Tags on Tags.id = Files_Tags.tagId
where Files_Tags.fileRecordId in ({});
select
ti.id,
ti.fileId,
ti.folderId,
ti.implicitFromId,
t.id,
t.title
from
Tags t
join TaggedItems ti on t.id = ti.tagId
where
ti.fileId in ({ })
16 changes: 12 additions & 4 deletions src/assets/queries/tags/get_tags_for_folder.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,12 @@
select Tags.id, Tags.title
from Tags
join Folders_Tags on Tags.id = Folders_Tags.tagId
where Folders_Tags.folderId = ?1;
select
ti.id,
ti.fileId,
ti.folderId,
ti.implicitFromId,
t.id,
t.title
from
Tags t
join TaggedItems ti on t.id = ti.tagId
where
ti.folderId = ?1
7 changes: 7 additions & 0 deletions src/assets/queries/tags/remove_explicit_tag_from_file.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
-- removes a single non-inherited tag from a file
delete from
TaggedItems
where
fileId = ?1
and tagId = ?2
and implicitFromId is null;
3 changes: 0 additions & 3 deletions src/assets/queries/tags/remove_tag_from_file.sql

This file was deleted.

10 changes: 7 additions & 3 deletions src/assets/queries/tags/remove_tag_from_folder.sql
Original file line number Diff line number Diff line change
@@ -1,3 +1,7 @@
delete from Folders_Tags
where folderId = ?1
and tagId = ?2
-- removes a single non-inherited tag from a folder
delete from
TaggedItems
where
folderId = ?1
and tagId = ?2
and implicitFromId is null;
Loading
Loading