Files
photoassistant/tables.sql

178 lines
11 KiB
SQL

alter database PA set timezone to 'Australia/Victoria';
create sequence PA_USER_ID_SEQ;
create sequence PA_USER_STATE_ID_SEQ;
create sequence FACE_ID_SEQ;
create sequence PATH_ID_SEQ;
create sequence PATH_TYPE_ID_SEQ;
create sequence FILE_ID_SEQ;
create sequence FILE_TYPE_ID_SEQ;
create sequence JOBEXTRA_ID_SEQ;
create sequence JOBLOG_ID_SEQ;
create sequence JOB_ID_SEQ;
create sequence PERSON_ID_SEQ;
create sequence REFIMG_ID_SEQ;
create sequence SETTINGS_ID_SEQ;
create sequence PA_JOB_MANAGER_ID_SEQ;
create sequence PA_JOB_MANAGER_FE_MESSAGE_ID_SEQ;
create sequence FACE_OVERRIDE_TYPE_ID_SEQ;
create sequence FACE_OVERRIDE_ID_SEQ;
-- these are hard-coded at present, not sure I can reflexively find models from API?
create table AI_MODEL ( ID integer, NAME varchar(24), DESCRIPTION varchar(80), constraint PK_AI_MODEL primary key(ID) );
insert into AI_MODEL values ( 1, 'hog', 'normal' );
insert into AI_MODEL values ( 2, 'cnn', 'more accurate / much slower' );
create table SETTINGS(
ID integer, BASE_PATH varchar, IMPORT_PATH varchar, STORAGE_PATH varchar, RECYCLE_BIN_PATH varchar,
AUTO_ROTATE Boolean,
DEFAULT_REFIMG_MODEL integer, DEFAULT_SCAN_MODEL integer, DEFAULT_THRESHOLD float,
FACE_SIZE_LIMIT integer,
SCHEDULED_IMPORT_SCAN integer, SCHEDULED_STORAGE_SCAN integer,
SCHEDULED_BIN_CLEANUP integer, BIN_CLEANUP_FILE_AGE integer,
JOB_ARCHIVE_AGE integer,
constraint PK_SETTINGS_ID primary key(ID),
constraint FK_DEFAULT_REFIMG_MODEL foreign key (DEFAULT_REFIMG_MODEL) references AI_MODEL(ID),
constraint FK_DEFAULT_SCAN_MODEL foreign key (DEFAULT_SCAN_MODEL) references AI_MODEL(ID) );
create table PA_USER(
ID integer,
DN varchar unique,
DEFAULT_IMPORT_NOO varchar,
DEFAULT_STORAGE_NOO varchar,
DEFAULT_SEARCH_NOO varchar,
DEFAULT_GROUPING varchar(16),
DEFAULT_HOW_MANY integer,
DEFAULT_SIZE integer,
DEFAULT_IMPORT_FOLDERS Boolean,
DEFAULT_STORAGE_FOLDERS Boolean,
constraint PK_PA_USER_ID primary key(ID) );
-- this is totally not 3rd normal form, but when I made it that, it was so complex, it was stupid
-- so for the little data here, I'm deliberately doing a redundant data structure
create table PA_USER_STATE ( ID integer, PA_USER_DN varchar(128), PATH_TYPE varchar(16),
NOO varchar(16), GROUPING varchar(16), HOW_MANY integer, ST_OFFSET integer, SIZE integer, FOLDERS Boolean,
ROOT varchar, CWD varchar,
ORIG_PTYPE varchar, ORIG_SEARCH_TERM varchar, ORIG_URL varchar,
VIEW_EID integer, CURRENT integer, FIRST_EID integer, LAST_EID integer, NUM_ENTRIES integer, LAST_USED timestamptz,
constraint FK_PA_USER_DN foreign key (PA_USER_DN) references PA_USER(DN),
constraint PK_PA_USER_STATES_ID primary key(ID ) );
create table FILE_TYPE ( ID integer, NAME varchar(32) unique, constraint PK_FILE_TYPE_ID primary key(ID) );
create table PATH_TYPE ( ID integer, NAME varchar(16) unique, constraint PK_PATH_TYPE_ID primary key(ID) );
create table PATH ( ID integer, TYPE_ID integer, PATH_PREFIX varchar(1024), NUM_FILES integer,
constraint PK_PATH_ID primary key(ID),
constraint FK_PATH_TYPE_TYPE_ID foreign key (TYPE_ID) references PATH_TYPE(ID) );
create table ENTRY( ID integer, NAME varchar(128), TYPE_ID integer, EXISTS_ON_FS boolean,
constraint PK_ENTRY_ID primary key(ID),
constraint FK_FILE_TYPE_TYPE_ID foreign key (TYPE_ID) references FILE_TYPE(ID) );
create table FILE ( EID integer, SIZE_MB integer, HASH varchar(34), THUMBNAIL varchar, FACES_CREATED_ON float, LAST_HASH_DATE float, LAST_AI_SCAN float, YEAR integer, MONTH integer, DAY integer, WOY integer,
constraint PK_FILE_ID primary key(EID),
constraint FK_FILE_ENTRY_ID foreign key (EID) references ENTRY(ID) );
create table DEL_FILE ( FILE_EID integer, ORIG_PATH_PREFIX varchar(1024), constraint PK_DEL_FILE_FILE_EID primary key (FILE_EID),
constraint FK_ENTRY_ID foreign key (FILE_EID) references FILE(EID) );
create table DIR ( EID integer, REL_PATH varchar(256), NUM_FILES integer, LAST_IMPORT_DATE float,
constraint PK_DIR_EID primary key(EID),
constraint FK_DIR_ENTRY_ID foreign key (EID) references ENTRY(ID) );
create table PATH_DIR_LINK ( path_id integer, dir_eid integer,
constraint PK_PDL_path_id_dir_eid primary key (path_id, dir_eid),
constraint FK_PDL_PATH_ID foreign key (PATH_ID) references PATH(ID),
constraint FK_PDL_DIR_EID foreign key (DIR_EID) references DIR(EID) );
create table ENTRY_DIR_LINK ( entry_id integer, dir_eid integer,
constraint PK_EDL_entry_id_dir_eid primary key (entry_id, dir_eid),
constraint FK_EDL_ENTRY_ID foreign key (ENTRY_ID) references ENTRY(ID),
constraint FK_EDL_DIR_EID foreign key (DIR_EID) references DIR(EID) );
create table PERSON ( ID integer default nextval('PERSON_ID_SEQ'), TAG varchar(48), FIRSTNAME varchar(48), SURNAME varchar(48),
constraint PK_PERSON_ID primary key(ID) );
alter sequence PERSON_ID_SEQ owned by PERSON.ID;
create table REFIMG ( ID integer, FNAME varchar(128), FACE bytea, ORIG_W integer, ORIG_H integer, FACE_LOCN varchar(32), CREATED_ON float, THUMBNAIL varchar, MODEL_USED integer,
constraint PK_REFIMG_ID primary key(ID),
constraint FK_REFIMG_MODEL_USED foreign key (MODEL_USED) references AI_MODEL(ID) );
alter sequence REFIMG_ID_SEQ owned by REFIMG.ID;
create table FACE( ID integer, FACE bytea, LOCN varchar(32), W integer, H integer, constraint PK_FACE_ID primary key(ID) );
create table FACE_FILE_LINK( FACE_ID integer, FILE_EID integer, MODEL_USED integer,
constraint PK_FFL_FACE_ID_FILE_ID primary key(FACE_ID, FILE_EID),
constraint FK_FFL_FACE_ID foreign key (FACE_ID) references FACE(ID) on delete cascade,
constraint FK_FFL_FILE_EID foreign key (FILE_EID) references FILE(EID),
constraint FK_FFL_MODEL_USED foreign key (MODEL_USED) references AI_MODEL(ID) );
create table FACE_REFIMG_LINK( FACE_ID integer, REFIMG_ID integer, FACE_DISTANCE float,
constraint PK_FRL_FACE_ID_REFIMG_ID primary key(FACE_ID, REFIMG_ID),
constraint FK_FRL_FACE_ID foreign key (FACE_ID) references FACE(ID) on delete cascade,
constraint FK_FRL_REFIMG_ID foreign key (REFIMG_ID) references REFIMG(ID) );
create table FACE_OVERRIDE_TYPE ( ID integer, NAME varchar unique, constraint PK_FACE_OVERRIDE_TYPE_ID primary key(ID) );
insert into FACE_OVERRIDE_TYPE values ( (select nextval('FACE_OVERRIDE_TYPE_ID_SEQ')), 'Manual match to existing person' );
insert into FACE_OVERRIDE_TYPE values ( (select nextval('FACE_OVERRIDE_TYPE_ID_SEQ')), 'Not a face' );
insert into FACE_OVERRIDE_TYPE values ( (select nextval('FACE_OVERRIDE_TYPE_ID_SEQ')), 'Too young' );
insert into FACE_OVERRIDE_TYPE values ( (select nextval('FACE_OVERRIDE_TYPE_ID_SEQ')), 'Ignore face' );
-- keep non-redundant FACE because, when we rebuild data we may have a null FACE_ID, but still want to connect to this override
-- from a previous AI pass... (would happen if we delete a file and then reimport/scan it), OR, more likely we change (say) a threshold, etc.
-- any reordering of faces, generates new face_ids... (but if the face data was the same, then this override should stand)
create table FACE_NO_MATCH_OVERRIDE ( ID integer, FACE_ID integer, TYPE_ID integer, FACE bytea,
constraint FK_FNMO_FACE_ID foreign key (FACE_ID) references FACE(ID),
constraint FK_FNMO_TYPE foreign key (TYPE_ID) references FACE_OVERRIDE_TYPE(ID),
constraint PK_FNMO_ID primary key(ID) );
-- manual match goes to person not refimg, so on search, etc. we deal with this anomaly (via sql not ORM)
create table FACE_MANUAL_OVERRIDE ( ID integer, FACE_ID integer, PERSON_ID integer, FACE bytea, constraint PK_FACE_MANUAL_OVERRIDE_ID primary key(ID) );
create table PERSON_REFIMG_LINK ( PERSON_ID integer, REFIMG_ID integer,
constraint PK_PRL primary key(PERSON_ID, REFIMG_ID),
constraint FK_PRL_PERSON_ID foreign key (PERSON_ID) references PERSON(ID),
constraint FK_PRL_REFIMG_ID foreign key (REFIMG_ID) references REFIMG(ID),
constraint U_PRL_REFIMG_ID unique(REFIMG_ID) );
create table JOB (
ID integer, START_TIME timestamptz, LAST_UPDATE timestamptz, NAME varchar(64), STATE varchar(128),
NUM_FILES integer, CURRENT_FILE_NUM integer, CURRENT_FILE varchar(256), WAIT_FOR integer, PA_JOB_STATE varchar(48),
constraint PK_JOB_ID primary key(ID) );
-- used to pass / keep extra values, e.g. num_files for jobs that have sets of files, or out* for adding output from jobs that you want to pass to next job in the chain
create table JOBEXTRA ( ID integer, JOB_ID integer, NAME varchar(32), VALUE varchar,
constraint PK_JOBEXTRA_ID primary key(ID), constraint FK_JOBEXTRA_JOB_ID foreign key(JOB_ID) references JOB(ID) );
create table JOBLOG ( ID integer, JOB_ID integer, LOG_DATE timestamptz, LOG varchar,
constraint PK_JL_ID primary key(ID), constraint FK_JL_JOB_ID foreign key(JOB_ID) references JOB(ID) );
create table PA_JOB_MANAGER_FE_MESSAGE ( ID integer, JOB_ID integer, ALERT varchar(16), MESSAGE varchar(1024),
constraint PA_JOB_MANAGER_FE_ACKS_ID primary key(ID),
constraint FK_PA_JOB_MANAGER_FE_MESSAGE_JOB_ID foreign key(JOB_ID) references JOB(ID) );
-- default data for types of paths
insert into PATH_TYPE values ( (select nextval('PATH_TYPE_ID_SEQ')), 'Import' );
insert into PATH_TYPE values ( (select nextval('PATH_TYPE_ID_SEQ')), 'Storage' );
insert into PATH_TYPE values ( (select nextval('PATH_TYPE_ID_SEQ')), 'Bin' );
-- default data for types of files
insert into FILE_TYPE values ( (select nextval('FILE_TYPE_ID_SEQ')), 'Image' );
insert into FILE_TYPE values ( (select nextval('FILE_TYPE_ID_SEQ')), 'Video' );
insert into FILE_TYPE values ( (select nextval('FILE_TYPE_ID_SEQ')), 'Directory' );
insert into FILE_TYPE values ( (select nextval('FILE_TYPE_ID_SEQ')), 'Unknown' );
-- fake data only for making testing easier
--insert into PERSON values ( (select nextval('PERSON_ID_SEQ')), 'dad', 'Damien', 'De Paoli' );
--insert into PERSON values ( (select nextval('PERSON_ID_SEQ')), 'mum', 'Mandy', 'De Paoli' );
--insert into PERSON values ( (select nextval('PERSON_ID_SEQ')), 'cam', 'Cameron', 'De Paoli' );
--insert into PERSON values ( (select nextval('PERSON_ID_SEQ')), 'mich', 'Michelle', 'De Paoli' );
-- DEV(ddp):
--insert into SETTINGS ( id, base_path, import_path, storage_path, recycle_bin_path, auto_rotate, default_refimg_model, default_scan_model, default_threshold, face_size_limit, scheduled_import_scan, scheduled_storage_scan, scheduled_bin_cleanup, bin_cleanup_file_age, job_archive_age ) values ( (select nextval('SETTINGS_ID_SEQ')), '/home/ddp/src/photoassistant/', 'images_to_process/', 'photos/', '.pa_bin/', true, 1, 1, '0.55', 43, 1, 1, 7, 30, 3 );
-- DEV(cam):
--insert into SETTINGS ( id, base_path, import_path, storage_path, recycle_bin_path, auto_rotate, default_refimg_model, default_scan_model, default_threshold, face_size_limit, scheduled_import_scan, scheduled_storage_scan, scheduled_bin_cleanup, bin_cleanup_file_age, job_archive_age ) values ( (select nextval('SETTINGS_ID_SEQ')), 'c:/Users/cam/Desktop/code/python/photoassistant/', 'c:\images_to_process', 'photos/', '.pa_bin/', true, 1, 1, '0.55', 43, 1, 1, 7, 30, 3 );
-- PROD:
insert into SETTINGS ( id, base_path, import_path, storage_path, recycle_bin_path, auto_rotate, default_refimg_model, default_scan_model, default_threshold, face_size_limit, scheduled_import_scan, scheduled_storage_scan, scheduled_bin_cleanup, bin_cleanup_file_age, job_archive_age ) values ( (select nextval('SETTINGS_ID_SEQ')), '/export/docker/storage/', 'Camera_uploads/', 'photos/', '.pa_bin/', true, 1, 1, '0.55', 43, 1, 1, 7, 30, 4 );