George S. Baugh před 4 roky
rodič
revize
8fe4343d20
4 změnil soubory, kde provedl 53 přidání a 13 odebrání
  1. 1 1
      lib/Trog/DataModule.pm
  2. 4 1
      lib/Trog/SQLite.pm
  3. 37 6
      lib/Trog/SQLite/TagIndex.pm
  4. 11 5
      schema/flatfile.schema

+ 1 - 1
lib/Trog/DataModule.pm

@@ -250,6 +250,7 @@ sub add ($self, @posts) {
             push(@{$post->{aliases}}, "/posts/$post->{id}", "/series/$post->{id}" );
         }
 
+        $post->{callback}   //= 'Trog::Routes::HTML::posts';
         # If this is a user creation post, add in the /user/ route
         if ($post->{callback} eq 'Trog::Routes::HTML::users') {
             $post->{local_href} = "/users/$post->{user}";
@@ -257,7 +258,6 @@ sub add ($self, @posts) {
 
         $post->{local_href} //= "/posts/$post->{id}";
         $post->{method}     //= 'GET';
-        $post->{callback}   //= 'Trog::Routes::HTML::posts';
         $post->{created}    = time();
         my @existing_posts = $self->get( id => $post->{id} );
         if (@existing_posts) {

+ 4 - 1
lib/Trog/SQLite.pm

@@ -20,9 +20,12 @@ sub dbh {
     my $qq = read_text($schema);
     my $db = DBI->connect("dbi:SQLite:dbname=$dbname","","");
     $db->{sqlite_allow_multiple_statements} = 1;
-    $db->do($qq) or die "Could not ensure auth database consistency";
+    $db->do($qq) or die "Could not ensure database consistency";
     $db->{sqlite_allow_multiple_statements} = 0;
     $dbh->{$schema} = $db;
+
+    # Turn on fkeys
+    $db->do("PRAGMA foreign_keys = ON");
     return $db;
 }
 

+ 37 - 6
lib/Trog/SQLite/TagIndex.pm

@@ -47,36 +47,67 @@ sub aliases {
 
 sub add_post ($post,$data_obj) {
     my $dbh = _dbh();
+    build_index($data_obj,[$post]);
     build_routes($data_obj,[$post]);
-    return build_index($data_obj,[$post]);
+    return 1;
 }
 
 sub remove_post ($post) {
     my $dbh = _dbh();
-    $dbh->do("DELETE FROM routes WHERE route=?", undef, $post->{local_href});
-    return $dbh->do("DELETE FROM posts_index WHERE post_id=?", undef, $post->{id});
+
+    # Deleting the post will cascade to the post index & primary route, which cascades to the aliases
+    $dbh->do("DELETE FROM post WHERE uuid=?", undef, $post->{id});
+
+    # Now that we've wasted the routes and post, let's reap any dangling tags or callbacks.
+    # We won't ever reap methods, because they're just HTTP methods in an enum table.
+    $dbh->do("DELETE from callbacks WHERE id NOT IN (SELECT DISTINCT callback_id FROM routes)");
+    $dbh->do("DELETE from tag WHERE id NOT IN (SELECT DISTINCT tag_id FROM posts_index)");
+    return 1;
 }
 
 sub build_index($data_obj,$posts=[]) {
     my $dbh = _dbh();
     $posts = $data_obj->read({ limit => 0, acls => ['admin'] }) unless @$posts;
 
+    # First, slap in the UUIDs
+    my @uuids = map { $_->{id} } @$posts;
+    Trog::SQLite::bulk_insert($dbh,'post',['uuid'],'IGNORE', @uuids);
+    my $pids = _id_for_uuid($dbh,@uuids);
+    foreach my $post (@$posts) {
+        $post->{post_id} = $pids->{$post->{id}}{id};
+    }
+
+    # Slap in the tags
     my @tags = uniq map { @{$_->{tags}} } @$posts;
     Trog::SQLite::bulk_insert($dbh,'tag', ['name'], 'IGNORE', @tags);
+    #TODO restrict query to only the specific tags we care about
     my $t = $dbh->selectall_hashref("SELECT id,name FROM tag", 'name');
     foreach my $k (keys(%$t)) { $t->{$k} = $t->{$k}->{id} };
 
+    # Finally, index the posts
     Trog::SQLite::bulk_insert($dbh,'posts_index',[qw{post_id post_time tag_id}], 'IGNORE', map {
         my $subj = $_;
-        map { ( $subj->{id}, $subj->{created}, $t->{$_} ) } @{$subj->{tags}}
+        map { ( $subj->{post_id}, $subj->{created}, $t->{$_} ) } @{$subj->{tags}}
     } @$posts );
 }
 
+sub _id_for_uuid($dbh,@uuids) {
+    my $bind = join(',', (map { '?' } @uuids));
+    Trog::SQLite::bulk_insert($dbh,'post',['uuid'],'IGNORE', @uuids);
+    return $dbh->selectall_hashref("SELECT id,uuid FROM post WHERE uuid IN ($bind)", 'uuid', {}, @uuids);
+}
+
 # It is important we use get() instead of read() because of incomplete data.
 sub build_routes($data_obj,$posts=[]) {
     my $dbh = _dbh();
     @$posts = $data_obj->get( limit => 0, acls => ['admin'] ) unless @$posts;
 
+    my @uuids = map { $_->{id} } @$posts;
+    my $pids = _id_for_uuid($dbh,@uuids);
+    foreach my $post (@$posts) {
+        $post->{post_id} = $pids->{$post->{id}}{id};
+    }
+
     # Ensure the callbacks we need are installed
     Trog::SQLite::bulk_insert($dbh,'callbacks', [qw{callback}], 'IGNORE', (uniq map { $_->{callback} } @$posts) );
 
@@ -90,8 +121,8 @@ sub build_routes($data_obj,$posts=[]) {
         $_
     } @$posts;
 
-    my @routes = map { ($_->{local_href}, $_->{method_id}, $_->{callback_id} ) } @$posts;
-    Trog::SQLite::bulk_insert($dbh,'routes', [qw{route method_id callback_id}], 'IGNORE', @routes);
+    my @routes = map { ($_->{post_id}, $_->{local_href}, $_->{method_id}, $_->{callback_id} ) } @$posts;
+    Trog::SQLite::bulk_insert($dbh,'routes', [qw{post_id route method_id callback_id}], 'IGNORE', @routes);
 
     # Now, compile the post aliases
     my %routes_actual = routes();

+ 11 - 5
schema/flatfile.schema

@@ -1,29 +1,34 @@
+
+CREATE TABLE IF NOT EXISTS post (
+    id INTEGER PRIMARY KEY AUTOINCREMENT,
+    uuid TEXT NOT NULL UNIQUE
+);
+
 CREATE TABLE IF NOT EXISTS tag (
     id INTEGER PRIMARY KEY AUTOINCREMENT,
     name TEXT NOT NULL UNIQUE
 );
 
 CREATE TABLE IF NOT EXISTS posts_index (
-    post_id TEXT NOT NULL,
+    post_id INTEGER NOT NULL REFERENCES post(id) ON DELETE CASCADE,
     post_time INTEGER NOT NULL,
-    tag_id INTEGER NOT NULL REFERENCES tag(id) ON DELETE CASCADE
+    tag_id INTEGER NOT NULL REFERENCES tag(id) ON DELETE RESTRICT
 );
 
 CREATE INDEX IF NOT EXISTS tag_idx ON tag(name);
 
-CREATE VIEW IF NOT EXISTS posts AS SELECT p.post_id AS id, p.post_time AS created, t.name AS tag FROM posts_index AS p JOIN tag AS t ON t.id=p.tag_id;
+CREATE VIEW IF NOT EXISTS posts AS SELECT pu.uuid AS id, p.post_time AS created, t.name AS tag FROM posts_index AS p JOIN tag AS t ON t.id=p.tag_id JOIN post AS pu ON p.post_id=pu.id;
 
 /* The intention is to read this entirely into memory at app startup     */
 /* This should not incur significant costs, even with millions of posts. */
 CREATE TABLE IF NOT EXISTS routes (
     id INTEGER PRIMARY KEY AUTOINCREMENT,
+    post_id INTEGER NOT NULL REFERENCES post(id) ON DELETE CASCADE,
     route TEXT NOT NULL UNIQUE,
     method_id TEXT NOT NULL REFERENCES methods(id) ON DELETE RESTRICT,
     callback_id TEXT NOT NULL REFERENCES callbacks(id) ON DELETE RESTRICT
 );
 
-/* Enum tables like this always require cleanup when there are no more references. */
-/* TODO  ^^^ */
 CREATE TABLE IF NOT EXISTS methods (
     id INTEGER PRIMARY KEY AUTOINCREMENT,
     method TEXT NOT NULL UNIQUE
@@ -34,6 +39,7 @@ CREATE TABLE IF NOT EXISTS callbacks (
     callback TEXT NOT NULL UNIQUE
 );
 
+/* The actual routing table */
 CREATE VIEW IF NOT EXISTS all_routes AS SELECT r.id AS id, r.route AS route, m.method AS method, c.callback AS callback FROM routes AS r JOIN methods AS m ON m.id=r.method_id JOIN callbacks AS c ON c.id=r.callback_id;
 
 /* Fill the methods table with the HTTP verbs */