1 PRAGMA application_id = 0x5a504442;
2 PRAGMA user_version = 1;
4 -- should be faster with rowid due to the blob content
5 -- these are really just blobs of data
6 -- TODO copyright and license information should probably
9 hash text primary key, -- sha256 of content
10 size integer, -- bigint? certainly need > 2GB
11 compression text, -- always xz?
16 create view filerefs as
18 count(PF.hash) + count(S.hash) + count(EL.file) + count(N.file) as refcount
20 left join packagefiles PF on PF.hash = F.hash
21 left join scripts S on S.hash = F.hash
22 left join elflibraries EL on EL.file = F.hash
23 left join notes N on N.file = F.hash
27 -- information about packages
28 -- a package is identified by a package,version,release triple
29 create table packages (
30 -- primary key columns
31 package text not null,
32 version text not null, -- the upstream version string
33 release integer not null, -- the local release number
40 licenses text, -- hash of actual license? need table for more than one?
42 build_time integer default (strftime('%s', 'now')),
44 hash text, -- see integ.c for package hash details
45 primary key (package,version,release),
46 check (typeof(package) = 'text'),
47 check (typeof(version) = 'text'),
48 check (typeof(release) = 'integer'),
50 -- enforce name and version conventions
51 check(instr(package,' ') = 0),
52 check(instr(package,'/') = 0),
53 check(instr(package,':') = 0),
54 check(instr(version,' ') = 0),
55 check(instr(version,'-') = 0),
56 check(instr(version,'/') = 0),
57 check(instr(version,':') = 0),
58 check(length(package) < 64),
59 check(length(package) > 0),
60 check(length(version) < 32),
61 check(length(version) > 0)
66 create index package_status_index on packages (status);
67 create index package_package_index on packages (package);
69 create view packages_pkgid as
70 select printf('%s-%s-%s', package, version, release) as pkgid, *
73 create trigger packages_delete_trigger instead of
74 delete on packages_pkgid
76 delete from packages where package = OLD.package
77 and version = OLD.version and release = OLD.release;
80 create trigger packages_update_trigger instead of
81 update on packages_pkgid
84 set package = NEW.package,
85 version = NEW.version,
86 release = NEW.release,
87 description = NEW.description,
88 architecture = NEW.architecture,
91 licenses = NEW.licenses,
92 packager = NEW.packager,
93 build_time = NEW.build_time,
94 install_time = NEW.install_time,
96 where package = OLD.package
97 and version = OLD.version
98 and release = OLD.release
103 -- handle package status history with a logging trigger.
104 create trigger logpkgstatus after update of status on packages
105 begin insert into zpmlog (action,target,info)
106 values (printf('status change %s %s', OLD.status, NEW.status),
107 printf('%s-%s-%s', NEW.package, NEW.version, NEW.release),
110 create table packagetags (
116 set_time integer default (strftime('%s', 'now')),
117 primary key (package,version,release,tag),
118 foreign key (package,version,release) references packages (package,version,release) on delete cascade on update cascade
121 -- files contained in a package
122 create table packagefiles (
128 path text, -- filesystem path
129 mode text not null default '0644', -- perms, use text for octal rep?
130 username text not null default 'root', -- name of owner
131 groupname text not null default 'root', -- group of owner
132 uid integer, -- numeric uid, generally ignored
133 gid integer, -- numeric gid, generally ignored
134 configuration integer not null default 0, -- boolean if config file
135 confhash text, -- last hash on disk
136 filetype varchar not null default 'r',
140 -- h hard link -- not supported
141 -- c character special -- not supported
142 -- b block special -- not supported
143 -- c and b device special files add dev number column
144 -- p fifos (i.e. pipe) -- not supported
145 -- s unix domain socket -- not supported
146 target text, -- link target for links
147 device integer, -- device file dev_t
148 hash text, -- null if not a regular file
149 mtime integer, -- seconds since epoch, finer resolution not needed
150 primary key (package,version,release,path),
151 foreign key (package,version,release)
152 references packages (package,version,release)
153 on delete cascade on update cascade,
154 check (not (filetype = 'l' and target is null)),
155 check (not (filetype = 'h' and target is null)),
156 check (target is null or length(target) between 1 and 4095),
157 check (hash is null or length(hash) between 1 and 1024),
158 check (path not in ('.', '..')),
159 check (not (filetype = 'r' and hash is null)),
160 check (not (filetype = 'c' and device is null)),
161 check (not (filetype = 'b' and device is null)),
162 check (filetype in ('r','d','l','h','c','b','p')),
163 check(length(username) between 1 and 256),
164 check(length(groupname) between 1 and 256),
165 check (configuration = 0 or configuration = 1)
170 create index packagefile_package_index on packagefiles (package);
171 create index packagefile_path_index on packagefiles (path);
172 create index packagefile_hash_index on packagefiles (hash);
173 create index pkgfile_configuration on packagefiles (configuration) where configuration = 1;
175 create view packagefiles_pkgid as
176 select printf('%s-%s-%s', package, version, release) as pkgid, *,
177 printf('%s:%s:%s:%s', filetype, mode, username, groupname) as mds
181 create trigger packagefiles_update_trigger instead of
182 update on packagefiles_pkgid
185 set package = NEW.package,
186 version = NEW.version,
187 release = NEW.release,
190 username = NEW.username,
191 groupname = NEW.groupname,
194 configuration = NEW.configuration,
195 filetype = NEW.filetype,
200 where package = OLD.package
201 and version = OLD.version
202 and release = OLD.release
208 create trigger packagefiles_delete_trigger instead of
209 delete on packagefiles_pkgid
211 delete from packagefiles
212 where package = OLD.package
213 and version = OLD.version
214 and release = OLD.release
217 update packages set hash = null
218 where package = OLD.package
219 and version = OLD.version
220 and release = OLD.release
225 create view installed_ref_count as
226 select I.path, count(*) as refcount
227 from installedfiles I
231 create view sync_status_ref_count as
232 select path, status, count(*) as refcount
233 from packagefiles_status
234 where status in ('installed', 'installing', 'removing')
235 group by path, status
238 create view packagefiles_status as
239 select P.status, PF.*
240 from packagefiles_pkgid PF
241 left join packages_pkgid P on P.pkgid = PF.pkgid
244 create view installedfiles as
245 select * from packagefiles_status
246 where status = 'installed'
249 create table pathtags (
255 path text, -- filesystem path
257 primary key (package,version,release,path,tag),
258 foreign key (package,version,release,path)
259 references packagefiles on delete cascade on update cascade
264 create view elfdeps as
265 select PF.pkgid, PF.status, PF.path, N.needed as needs,
266 PL.path as library, PL.pkgid provider, PL.status as library_status
267 from packagefiles_status PF
268 join elfneeded N on N.file = PF.hash
269 left join elflibraries L on N.needed = L.soname
270 left join packagefiles_status PL on PL.hash = L.file
273 -- TODO just elf information?
274 -- and just hash, not package?
275 create table elflibraries (
276 file text primary key,
281 create index elf_library_name_index on elflibraries(soname);
283 create table elfneeded (
284 file text, -- hash of file
285 needed text, -- soname of dependency
286 primary key (file, needed)
291 create view package_libraries as
292 select distinct PF.pkgid, EL.soname
293 from packagefiles_pkgid PF join elflibraries EL on PF.hash = EL.file
296 create view package_libraries_needed as
298 select distinct EN.needed as soname, PF.pkgid
300 join packagefiles_pkgid PF on PF.hash = EN.file
303 select distinct EL.soname, PF.pkgid
305 join packagefiles_pkgid PF on PF.hash = EL.file
307 select distinct PL.pkgid,PL.soname, PP.soname is not null as selfsatisfied
309 left join pkgprovides PP on PL.pkgid = PP.pkgid and PL.soname = PP.soname
312 -- package scripts: table of package, stage, file
313 create table scripts (
319 primary key (package,version,release,stage),
320 foreign key (package,version,release) references packages (package,version,release) on delete cascade on update cascade
323 create view scripts_pkgid as
324 select printf('%s-%s-%s', package, version, release) as pkgid, *
328 -- package dependencies: table of package, dependency, dep type (package, soname)
329 create table packagedeps (
333 requires text, -- package, can be partial
334 primary key (package,version,release,package),
335 foreign key (package,version,release) references packages (package,version,release) on delete cascade on update cascade
339 create table provides (
342 label text -- a capability label
345 create table requires (
348 label text -- a capability label
351 create table packagegroups (
357 -- not sure how machine readable this needs to be,
358 -- do not at all for now, figure it out later
359 -- could be worth logging all commands in a history table,
360 -- the zpm driver could do that and capture the exit status
362 -- might want the history table to note a "group" to tie together
363 -- sub-invocations, probably an environment variable set if not
364 -- already set by zpm, probably a uuid or a timestamp
365 create table zpmlog (
366 ts text default (strftime('%Y-%m-%d %H:%M:%f', 'now')),
367 -- timestamp of action
369 target text, -- packagename, repo name, etc
370 info text -- human readable
374 id integer primary key, -- rowid alias
375 ts text default (strftime('%Y-%m-%dT%H:%M:%f', 'now')),
377 pkgid text, -- package
378 path text, -- file path involved
379 file text, -- hash of file
380 ack integer default 0
383 create table history (
384 ts integer, -- again, probably needs timestamp sub second
390 create table repository (
391 name text primary key, -- our name for a repo
393 priority integer not null default 1,
394 refreshed integer -- last refresh time
396 -- force the url to be repourl/info.repo
397 -- package urls repourl/pkgid.zpm
399 -- urls for downloading packages. possibly unneeded
400 create table repository_packages (
402 pkg text, -- glob pattern? in which case others not needed
408 -- track which repository a package was cloned from, i.e. where we got it
409 create table packagesource (
413 repository text references repository
417 create view needed_libraries as
419 libs(file,needs,provider) as (
420 select N.file, N.needed as needs, L.file as provider
421 from elfneeded N left join elflibraries L on N.needed = L.soname
423 select L.file, N.needed as needs, EL.file as provider
425 join elfneeded N on N.file = L.provider
426 left join elflibraries EL on N.needed = EL.soname
431 * tables for repository info, essentially materalized views
433 create table repository_libs (
438 create table repository_libsneeded (