1 -- SQL script for upgrading the local database to the format expected for LBS
4 -- This script should be loaded after connecting to the database to be
7 -- Database schema changes: the size and mtime columns were added to the
8 -- segments table, and the segments_used table was added. Rather than upgrade
9 -- the segments table in-place, we create a new table and then rename it over
10 -- the old segments table. The intent column was also added to the snapshots
12 create table segments_new (
13 segmentid integer primary key,
14 segment text unique not null,
22 create table segments_used (
23 snapshotid integer not null,
24 segmentid integer not null,
27 create unique index segments_used_index
28 on segments_used(snapshotid, segmentid);
30 alter table snapshots add column intent real;
32 -- Initialize the intent column; set all old snapshots to have intent 1
33 -- (intended to be a daily snapshot).
34 update snapshots set intent = 1;
36 -- Compute the size of each of the segments, if possible, based on our
37 -- knowledge of the objects stored in them.
38 insert into segments_new
39 select segmentid, segment, path, checksum, mtime, size, null as expire_time
41 (select segmentid, segment, path, checksum from segments)
43 (select segmentid, sum(size) as size, max(timestamp) as mtime
44 from block_index group by segmentid)
48 alter table segments_new rename to segments;
50 -- Populate the segments_used table based upon data contained in
51 -- snapshot_contents--this is roughly the same calculation that is actually
52 -- done, only now this calculation is done when a snapshot is created.
53 insert into segments_used
54 select snapshotid, segmentid, cast(used as real) / size as utilization
56 (select snapshotid, segmentid, sum(size) as used
57 from snapshot_contents join block_index using (blockid)
58 group by snapshotid, segmentid)
60 (select segmentid, size from segments)
63 -- The snapshot_contents table is obsolete.
64 drop table snapshot_contents;
66 -- Upgrade database views.
67 drop view cleaning_order;
68 drop view segment_info;
70 create view segment_info as
71 select segmentid, mtime, size, expire_time,
72 cast(size * utilization as integer) as used, utilization
74 (select segmentid, max(utilization) as utilization
75 from segments_used group by segmentid)