Ver Fonte

Optimize keyset_amounts schema and queries for better performance

This commit refactors the keyset_amounts table schema and associated queries to
improve performance and reduce database operations. The main change is
consolidating issued and redeemed amounts into separate columns instead of
using a type-based row approach.
Cesar Rodas há 3 meses atrás
pai
commit
a1523cf22d

+ 22 - 21
crates/cdk-sql-common/src/mint/migrations/postgres/20251102000000_create_keyset_amounts.sql

@@ -1,24 +1,25 @@
--- Create keyset_amounts table
+-- Create keyset_amounts table with total_issued and total_redeemed columns
 CREATE TABLE IF NOT EXISTS keyset_amounts (
-    keyset_id TEXT NOT NULL,
-    type TEXT NOT NULL,
-    amount BIGINT NOT NULL DEFAULT 0,
-    PRIMARY KEY (keyset_id, type)
+    keyset_id TEXT PRIMARY KEY NOT NULL,
+    total_issued BIGINT NOT NULL DEFAULT 0,
+    total_redeemed BIGINT NOT NULL DEFAULT 0
 );
 
--- Create index for faster lookups
-CREATE INDEX IF NOT EXISTS idx_keyset_amounts_type ON keyset_amounts(type);
-
--- Prefill with issued amounts (sum from blind_signature where c IS NOT NULL)
-INSERT INTO keyset_amounts (keyset_id, type, amount)
-SELECT keyset_id, 'issued', COALESCE(SUM(amount), 0)
-FROM blind_signature
-WHERE c IS NOT NULL
-GROUP BY keyset_id;
-
--- Prefill with redeemed amounts (sum from proof where state = 'SPENT')
-INSERT INTO keyset_amounts (keyset_id, type, amount)
-SELECT keyset_id, 'redeemed', COALESCE(SUM(amount), 0)
-FROM proof
-WHERE state = 'SPENT'
-GROUP BY keyset_id;
+-- Prefill with issued and redeemed amounts using FULL OUTER JOIN
+INSERT INTO keyset_amounts (keyset_id, total_issued, total_redeemed)
+SELECT
+    COALESCE(bs.keyset_id, p.keyset_id) as keyset_id,
+    COALESCE(bs.total_issued, 0) as total_issued,
+    COALESCE(p.total_redeemed, 0) as total_redeemed
+FROM (
+    SELECT keyset_id, SUM(amount) as total_issued
+    FROM blind_signature
+    WHERE c IS NOT NULL
+    GROUP BY keyset_id
+) bs
+FULL OUTER JOIN (
+    SELECT keyset_id, SUM(amount) as total_redeemed
+    FROM proof
+    WHERE state = 'SPENT'
+    GROUP BY keyset_id
+) p ON bs.keyset_id = p.keyset_id;

+ 20 - 14
crates/cdk-sql-common/src/mint/migrations/sqlite/20251102000000_create_keyset_amounts.sql

@@ -1,24 +1,30 @@
--- Create keyset_amounts table
+-- Create keyset_amounts table with total_issued and total_redeemed columns
 CREATE TABLE IF NOT EXISTS keyset_amounts (
-    keyset_id TEXT NOT NULL,
-    type TEXT NOT NULL,
-    amount INTEGER NOT NULL DEFAULT 0,
-    PRIMARY KEY (keyset_id, type)
+    keyset_id TEXT PRIMARY KEY NOT NULL,
+    total_issued INTEGER NOT NULL DEFAULT 0,
+    total_redeemed INTEGER NOT NULL DEFAULT 0
 );
 
--- Create index for faster lookups
-CREATE INDEX IF NOT EXISTS idx_keyset_amounts_type ON keyset_amounts(type);
-
--- Prefill with issued amounts (sum from blind_signature where c IS NOT NULL)
-INSERT INTO keyset_amounts (keyset_id, type, amount)
-SELECT keyset_id, 'issued', COALESCE(SUM(amount), 0)
+-- Prefill with issued amounts
+INSERT OR IGNORE INTO keyset_amounts (keyset_id, total_issued, total_redeemed)
+SELECT keyset_id, SUM(amount) as total_issued, 0 as total_redeemed
 FROM blind_signature
 WHERE c IS NOT NULL
 GROUP BY keyset_id;
 
--- Prefill with redeemed amounts (sum from proof where state = 'SPENT')
-INSERT INTO keyset_amounts (keyset_id, type, amount)
-SELECT keyset_id, 'redeemed', COALESCE(SUM(amount), 0)
+-- Update with redeemed amounts
+UPDATE keyset_amounts
+SET total_redeemed = (
+    SELECT COALESCE(SUM(amount), 0)
+    FROM proof
+    WHERE proof.keyset_id = keyset_amounts.keyset_id
+    AND proof.state = 'SPENT'
+);
+
+-- Insert keysets that only have redeemed amounts (no issued)
+INSERT OR IGNORE INTO keyset_amounts (keyset_id, total_issued, total_redeemed)
+SELECT keyset_id, 0 as total_issued, SUM(amount) as total_redeemed
 FROM proof
 WHERE state = 'SPENT'
+AND keyset_id NOT IN (SELECT keyset_id FROM keyset_amounts)
 GROUP BY keyset_id;

+ 67 - 22
crates/cdk-sql-common/src/mint/mod.rs

@@ -221,20 +221,39 @@ where
 
         if new_state == State::Spent {
             // Update keyset_amounts table for redeemed amounts
-            query(
+            // First, try UPDATE (most common case)
+            let updated = query(
                 r#"
-                INSERT INTO keyset_amounts (keyset_id, type, amount)
-                SELECT keyset_id, 'redeemed', COALESCE(SUM(amount), 0)
-                FROM proof
-                WHERE y IN (:ys)
-                GROUP BY keyset_id
-                ON CONFLICT (keyset_id, type)
-                DO UPDATE SET amount = keyset_amounts.amount + EXCLUDED.amount
+                UPDATE keyset_amounts
+                SET total_redeemed = total_redeemed + amounts.total
+                FROM (
+                    SELECT keyset_id, COALESCE(SUM(amount), 0) as total
+                    FROM proof
+                    WHERE y IN (:ys)
+                    GROUP BY keyset_id
+                ) amounts
+                WHERE keyset_amounts.keyset_id = amounts.keyset_id
                 "#,
             )?
             .bind_vec("ys", ys.iter().map(|y| y.to_bytes().to_vec()).collect())
             .execute(&self.inner)
             .await?;
+
+            // If no rows were updated, INSERT new rows (rare case - first time seeing this keyset)
+            if updated == 0 {
+                query(
+                    r#"
+                    INSERT INTO keyset_amounts (keyset_id, total_issued, total_redeemed)
+                    SELECT keyset_id, 0, COALESCE(SUM(amount), 0)
+                    FROM proof
+                    WHERE y IN (:ys)
+                    GROUP BY keyset_id
+                    "#,
+                )?
+                .bind_vec("ys", ys.iter().map(|y| y.to_bytes().to_vec()).collect())
+                .execute(&self.inner)
+                .await?;
+            }
         }
 
         Ok(ys.iter().map(|y| current_states.remove(y)).collect())
@@ -1644,10 +1663,9 @@ where
             r#"
             SELECT
                 keyset_id,
-                amount
+                total_redeemed as amount
             FROM
                 keyset_amounts
-            WHERE type = 'redeemed'
         "#,
         )?
         .fetch_all(&*conn)
@@ -1737,18 +1755,32 @@ where
                     .execute(&self.inner)
                     .await?;
 
-                    query(
+                    // Update total_issued (most common case)
+                    let updated = query(
                         r#"
-                        INSERT INTO keyset_amounts (keyset_id, type, amount)
-                        VALUES (:keyset_id, 'issued', :amount)
-                        ON CONFLICT (keyset_id, type)
-                        DO UPDATE SET amount = keyset_amounts.amount + :amount
+                        UPDATE keyset_amounts
+                        SET total_issued = total_issued + :amount
+                        WHERE keyset_id = :keyset_id
                         "#,
                     )?
                     .bind("amount", u64::from(signature.amount) as i64)
                     .bind("keyset_id", signature.keyset_id.to_string())
                     .execute(&self.inner)
                     .await?;
+
+                    // If no rows updated, INSERT (rare case - first issuance for this keyset)
+                    if updated == 0 {
+                        query(
+                            r#"
+                            INSERT INTO keyset_amounts (keyset_id, total_issued, total_redeemed)
+                            VALUES (:keyset_id, :amount, 0)
+                            "#,
+                        )?
+                        .bind("amount", u64::from(signature.amount) as i64)
+                        .bind("keyset_id", signature.keyset_id.to_string())
+                        .execute(&self.inner)
+                        .await?;
+                    }
                 }
                 Some((c, _dleq_e, _dleq_s)) => {
                     // Blind message exists: check if c is NULL
@@ -1777,18 +1809,32 @@ where
                             .execute(&self.inner)
                             .await?;
 
-                            query(
+                            // Update total_issued (most common case)
+                            let updated = query(
                                 r#"
-                                INSERT INTO keyset_amounts (keyset_id, type, amount)
-                                VALUES (:keyset_id, 'issued', :amount)
-                                ON CONFLICT (keyset_id, type)
-                                DO UPDATE SET amount = keyset_amounts.amount + :amount
+                                UPDATE keyset_amounts
+                                SET total_issued = total_issued + :amount
+                                WHERE keyset_id = :keyset_id
                                 "#,
                             )?
                             .bind("amount", u64::from(signature.amount) as i64)
                             .bind("keyset_id", signature.keyset_id.to_string())
                             .execute(&self.inner)
                             .await?;
+
+                            // If no rows updated, INSERT (rare case - first issuance for this keyset)
+                            if updated == 0 {
+                                query(
+                                    r#"
+                                    INSERT INTO keyset_amounts (keyset_id, total_issued, total_redeemed)
+                                    VALUES (:keyset_id, :amount, 0)
+                                    "#,
+                                )?
+                                .bind("amount", u64::from(signature.amount) as i64)
+                                .bind("keyset_id", signature.keyset_id.to_string())
+                                .execute(&self.inner)
+                                .await?;
+                            }
                         }
                         _ => {
                             // Blind message already has c: Error
@@ -1979,10 +2025,9 @@ where
             r#"
             SELECT
                 keyset_id,
-                amount
+                total_issued as amount
             FROM
                 keyset_amounts
-            WHERE type = 'issued'
         "#,
         )?
         .fetch_all(&*conn)