3 PRAGMA application_id = 0x5a504442;
4 PRAGMA user_version = 1;
6 -- should be faster with rowid due to the blob content
7 -- these are really just blobs of data
8 -- TODO copyright and license information should probably
11 hash text primary key, -- sha256 of content
12 size integer, -- bigint? certainly need > 2GB
13 compression text, -- always xz?
18 -- information about packages
19 -- a package is identified by a package,version,release triple
20 create table packages (
21 -- primary key columns
22 package text not null,
23 version text not null, -- the upstream version string
24 release integer not null, -- the local release number
25 -- pkgid text, -- the three above joined with '-'
32 licenses text, -- hash of actual license? need table for more than one?
34 build_time integer default (strftime('%s', 'now')),
36 checksum text, -- checksum of package contents. null for incompleted packages
37 primary key (package,version,release),
38 check (typeof(package) = 'text'),
39 check (typeof(version) = 'text'),
40 check (typeof(release) = 'integer'),
42 -- TODO enforce name and version conventions
43 -- check(instr(version,'-') = 0)
44 -- check(instr(package,'/') = 0)
45 -- check(instr(package,'/') = 0)
46 -- check(instr(version,' ') = 0)
47 -- check(instr(package,' ') = 0)
48 -- check(instr(package,' ') = 0)
49 -- check(length(package) < 64)
50 -- check(length(version) < 32)
55 create index package_status_index on packages (status);
57 create view packages_pkgid as
58 select printf('%s-%s-%s', package, version, release) as pkgid, *
61 create trigger packages_update_trigger instead of
62 update on packages_pkgid
65 set package = NEW.package,
66 version = NEW.version,
67 release = NEW.release,
68 description = NEW.description,
69 architecture = NEW.architecture,
72 licenses = NEW.licenses,
73 packager = NEW.packager,
74 build_time = NEW.build_time,
75 install_time = NEW.install_time,
76 checksum = NEW.checksum
77 where package = OLD.package
78 and version = OLD.version
79 and release = OLD.release
84 -- handle package status history with a logging trigger.
85 create trigger logpkgstatus after update of status on packages
86 begin insert into zpmlog (action,target,info)
87 values (printf('status change %s %s', OLD.status, NEW.status),
88 printf('%s-%s-%s', NEW.package, NEW.version, NEW.release),
91 create table packagetags (
97 set_time integer default (strftime('%s', 'now')),
98 primary key (package,version,release,tag),
99 foreign key (package,version,release) references packages (package,version,release) on delete cascade on update cascade
102 -- packagefile hash is columns as text, joined with null bytes, then
103 -- sha256 sum of that
104 -- package checksum is package columns as text, joined with null bytes,
105 -- other than the checksum and install_time column
106 -- then that hashed. finally, that hash, plus the ascii sorted
107 -- hashes of the package files all joined with newlines, hashed.
108 -- really don't like this.
110 -- files contained in a package
111 create table packagefiles (
117 path text, -- filesystem path
118 mode text not null, -- perms, use text for octal rep?
119 username text not null, -- name of owner
120 groupname text not null, -- group of owner
121 uid integer, -- numeric uid, generally ignored
122 gid integer, -- numeric gid, generally ignored
123 configuration integer not null default 0, -- boolean if config file
124 filetype varchar not null default 'r',
128 -- h hard link -- not supported
129 -- c character special and b device special files add dev number column
131 -- p fifos (i.e. pipe)
132 target text, -- link target for links
133 -- device file dev numbers, should probably be a separate table
136 hash text, -- null if no actual content, i.e. anything but a regular file
137 mtime integer, -- seconds since epoch, finer resolution probably not needed
138 primary key (package,version,release,path),
139 foreign key (package,version,release) references packages (package,version,release) on delete cascade on update cascade,
140 check (not (filetype = 'l' and target is null)),
141 check (not (filetype = 'r' and hash is null)),
142 check (not (filetype = 'c' and (devmajor is null or devminor is null))),
143 check (not (filetype = 'b' and (devmajor is null or devminor is null))),
144 check (configuration = 0 or configuration = 1)
149 create view packagefiles_pkgid as
150 select printf('%s-%s-%s', package, version, release) as pkgid, *,
151 printf('%s:%o:%s:%s', filetype, mode, username, groupname) as mds
155 create trigger packagefiles_update_trigger instead of
156 update on packagefiles_pkgid
159 set package = NEW.package,
160 version = NEW.version,
161 release = NEW.release,
164 username = NEW.username,
165 groupname = NEW.groupname,
168 configuration = NEW.configuration,
169 filetype = NEW.filetype,
171 devmajor = NEW.devmajor,
172 devminor = NEW.devminor,
175 where package = OLD.package
176 and version = OLD.version
177 and release = OLD.release
183 create view installed_ref_count as
184 select I.path, count(*) as refcount
185 from installedfiles I
189 create view sync_status_ref_count as
190 select path, status, count(*) as refcount
191 from packagefiles_status
192 where status in ('installed', 'installing', 'removing')
193 group by path, status
196 create view packagefiles_status as
197 select P.status, PF.*
198 from packagefiles_pkgid PF
199 left join packages_pkgid P on P.pkgid = PF.pkgid
202 create view installedfiles as
203 select * from packagefiles_status
204 where status = 'installed'
207 create view install_status as
209 select 'new' as op, PN.*
210 from packagefiles_status PN
211 left join installed_ref_count RC on RC.path = PN.path
212 where RC.refcount is null
213 and PN.status = 'installing'
217 select 'update' as op, PN.*
218 from packagefiles_status PN
219 inner join installedfiles PI on PI.path = PN.path and PI.package = PN.package
220 left join installed_ref_count RC on RC.path = PN.path
221 where RC.refcount = 1
222 and PN.status = 'installing'
223 and PI.hash is not PN.hash
227 select 'conflict' as op, PI.*
228 from packagefiles_status PN
229 inner join installedfiles PI on PI.path = PN.path and PI.package != PN.package
230 where PN.status = 'installing'
233 select 'remove' as op, PI.*
234 from installedfiles PI
235 left join packagefiles_status PN
236 on PI.path = PN.path and PI.package = PN.package
237 and PI.pkgid != PN.pkgid
238 where PN.path is null
239 and PI.package in (select package from packages where status = 'installing')
242 -- remove files in removing, but not installing
243 select distinct 'remove' as op, PR.*
244 from packagefiles_status PR
245 left join packagefiles_status PN
247 and PR.pkgid != PN.pkgid and PN.status in ('installing', 'installed')
248 where PN.path is null
249 and PR.status = 'removing'
252 create table pathtags (
258 path text, -- filesystem path
260 primary key (package,version,release,path,tag),
261 foreign key (package,version,release,path)
262 references packagefiles on delete cascade on update cascade
267 create table elfinfo (
268 file text primary key, -- hash of blob
274 create table elfdeps (
278 primary key (file, soname, dependency)
283 -- TODO just elf information?
284 -- and just hash, not package?
285 create table elflibraries (
286 file text primary key,
292 create table elfneeded (
294 needed text, -- soname of dependency
295 primary key (file, needed)
300 -- package scripts: table of package, stage, file
301 create table scripts (
307 primary key (package,version,release,stage),
308 foreign key (package,version,release) references packages (package,version,release) on delete cascade on update cascade
311 create view scripts_pkgid as
312 select printf('%s-%s-%s', package, version, release) as pkgid, *
316 -- package dependencies: table of package, dependency, dep type (package, soname)
317 create table packagedeps (
321 requires text, -- package name (only)
324 primary key (package,version,release,package),
325 foreign key (package,version,release) references packages (package,version,release) on delete cascade on update cascade
329 create table provides (
332 label text -- a capability label
335 create table requires (
338 label text -- a capability label
341 create table packagegroups (
347 -- not sure how machine readable this needs to be,
348 -- do not at all for now, figure it out later
349 -- could be worth logging all commands in a history table,
350 -- the zpm driver could do that and capture the exit status
352 -- might want the history table to note a "group" to tie together
353 -- sub-invocations, probably an environment variable set if not
354 -- already set by zpm, probably a uuid or a timestamp
355 create table zpmlog (
356 ts text default (strftime('%Y-%m-%d %H:%M:%f', 'now')),
357 -- timestamp of action
359 target text, -- packagename, repo name, etc
360 info text -- human readable
363 create table history (
364 ts integer, -- again, probably needs timestamp sub second
370 create table repository (
371 name text primary key, -- our name for a repo
373 priority integer not null default 1,
374 refreshed integer -- last refresh time
377 -- urls for downloading packages. possibly unneeded
378 create table repository_packages (
380 pkg text, -- glob pattern? in which case others not needed
386 -- track which repository a package was cloned from, i.e. where we got it
387 create table packagesource (
391 repository text references repository