@ -70,31 +70,12 @@ public class CacheExporter @Inject constructor(
}
public suspend fun export ( id : Long , store : Store ) {
// TODO(gpe): think about what to do if there is a collision
database . execute { connection ->
connection . prepareStatement (
"""
WITH t AS (
SELECT a . archive _id , c . data , g . container _id
FROM master _indexes m
JOIN master _index _archives a ON a . master _index _id = m . id
JOIN groups g ON g . archive _id = 255 AND g . group _id = a . archive _id :: INTEGER
AND g . version = a . version AND NOT g . version _truncated
JOIN containers c ON c . id = g . container _id AND c . crc32 = a . crc32
JOIN indexes i ON i . container _id = g . container _id AND i . version = a . version
WHERE m . id = ?
)
SELECT 255 :: uint1 , t . archive _id :: INTEGER , t . data , NULL
FROM t
UNION ALL
SELECT t . archive _id , ig . group _id , c . data , g . version
FROM t
JOIN index _groups ig ON ig . container _id = t . container _id
JOIN groups g ON g . archive _id = t . archive _id :: INTEGER AND g . group _id = ig . group _id AND (
( g . version = ig . version AND NOT g . version _truncated ) OR
( g . version = ig . version & 65535 AND g . version _truncated )
)
JOIN containers c ON c . id = g . container _id AND c . crc32 = ig . crc32
SELECT archive _id , group _id , data , version
FROM master _index _valid _groups
WHERE master _index _id = ?
""" .trimIndent()
) . use { stmt ->
stmt . fetchSize = BATCH _SIZE
@ -133,26 +114,11 @@ public class CacheExporter @Inject constructor(
return database . execute { connection ->
connection . prepareStatement (
"""
WITH t AS (
SELECT a . archive _id , c . data , g . container _id
FROM master _indexes m
JOIN master _index _archives a ON a . master _index _id = m . id
JOIN groups g ON g . archive _id = 255 AND g . group _id = a . archive _id :: INTEGER
AND g . version = a . version AND NOT g . version _truncated
JOIN containers c ON c . id = g . container _id AND c . crc32 = a . crc32
JOIN indexes i ON i . container _id = g . container _id AND i . version = a . version
WHERE m . id = ?
)
SELECT t . archive _id , ig . group _id , ig . name _hash , n . name , ( k . key ) . k0 , ( k . key ) . k1 , ( k . key ) . k2 , ( k . key ) . k3
FROM t
JOIN index _groups ig ON ig . container _id = t . container _id
JOIN groups g ON g . archive _id = t . archive _id :: INTEGER AND g . group _id = ig . group _id AND (
( g . version = ig . version AND NOT g . version _truncated ) OR
( g . version = ig . version & 65535 AND g . version _truncated )
)
JOIN containers c ON c . id = g . container _id AND c . crc32 = ig . crc32
JOIN keys k ON k . id = c . key _id
LEFT JOIN names n ON n . hash = ig . name _hash AND n . name ~ ' ^ l ( ?: [ 0 - 9 ] | [ 1 - 9 ] [ 0 - 9 ] ) _ ( ?: [ 0 - 9 ] | [ 1 - 9 ] [ 0 - 9 ] | 1 [ 0 - 9 ] { 2 } | 2 [ 0 - 4 ] [ 0 - 9 ] | 25 [ 0 - 5 ] ) $ '
SELECT v . archive _id , v . group _id , v . name _hash , n . name , ( k . key ) . k0 , ( k . key ) . k1 , ( k . key ) . k2 , ( k . key ) . k3
FROM master _index _valid _groups v
JOIN keys k ON k . id = v . key _id
LEFT JOIN names n ON n . hash = v . name _hash AND n . name ~ ' ^ l ( ?: [ 0 - 9 ] | [ 1 - 9 ] [ 0 - 9 ] ) _ ( ?: [ 0 - 9 ] | [ 1 - 9 ] [ 0 - 9 ] | 1 [ 0 - 9 ] { 2 } | 2 [ 0 - 4 ] [ 0 - 9 ] | 25 [ 0 - 5 ] ) $ '
WHERE v . master _index _id = ?
""" .trimIndent()
) . use { stmt ->
stmt . setLong ( 1 , id )