Fix pgsql creation column bug

Root cause: Use default 'now'::timestamp will not generate timestamp for each transaction,
PG will convert now to a timestamp as soon as the constant is parsed. To fix it, update it
to defult CURRENT_TIMESTAMP, thie setting is the same as default now(), which returns the
start time of current transaction because ther are fuction calls, hey will give the desired
behavior of defaulting to the time of row insertion.

Reference: https://www.postgresql.org/docs/9.6/static/functions-datetime.html#FUNCTIONS-DATETIME-CURRENT
PG version: 9.6.9
This commit is contained in:
wangyan 2018-07-30 03:05:50 -07:00
parent 43774df6f3
commit 22411cf6b2
2 changed files with 70 additions and 66 deletions

View File

@ -39,12 +39,23 @@ create table harbor_user (
reset_uuid varchar(40) DEFAULT NULL,
salt varchar(40) DEFAULT NULL,
sysadmin_flag boolean DEFAULT false NOT NULL,
creation_time timestamp(0),
update_time timestamp(0),
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
UNIQUE (username),
UNIQUE (email)
);
CREATE FUNCTION update_update_time_at_column() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
NEW.update_time = NOW();
RETURN NEW;
END;
$$;
CREATE TRIGGER harbor_user_update_time_at_modtime BEFORE UPDATE ON harbor_user FOR EACH ROW EXECUTE PROCEDURE update_update_time_at_column();
insert into harbor_user (username, email, password, realname, comment, deleted, sysadmin_flag, creation_time, update_time) values
('admin', 'admin@example.com', '', 'system admin', 'admin user',false, true, NOW(), NOW()),
('anonymous', 'anonymous@example.com', '', 'anonymous user', 'anonymous user', true, false, NOW(), NOW());
@ -57,13 +68,15 @@ create table project (
and 11 is reserved for marking the deleted project.
*/
name varchar (255) NOT NULL,
creation_time timestamp,
update_time timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
deleted boolean DEFAULT false NOT NULL,
FOREIGN KEY (owner_id) REFERENCES harbor_user(user_id),
UNIQUE (name)
);
CREATE TRIGGER project_update_time_at_modtime BEFORE UPDATE ON project FOR EACH ROW EXECUTE PROCEDURE update_update_time_at_column();
insert into project (owner_id, name, creation_time, update_time) values
(1, 'library', NOW(), NOW());
@ -77,21 +90,12 @@ create table project_member (
*/
entity_type char(1) NOT NULL,
role int NOT NULL,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id),
CONSTRAINT unique_project_entity_type UNIQUE (project_id, entity_id, entity_type)
);
CREATE FUNCTION update_update_time_at_column() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
NEW.update_time = NOW();
RETURN NEW;
END;
$$;
CREATE TRIGGER project_member_update_time_at_modtime BEFORE UPDATE ON project_member FOR EACH ROW EXECUTE PROCEDURE update_update_time_at_column();
insert into project_member (project_id, entity_id, role, entity_type) values
@ -102,8 +106,8 @@ create table project_metadata (
project_id int NOT NULL,
name varchar(255) NOT NULL,
value varchar(255),
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
deleted boolean DEFAULT false NOT NULL,
PRIMARY KEY (id),
CONSTRAINT unique_project_id_and_name UNIQUE (project_id,name),
@ -120,8 +124,8 @@ create table user_group (
group_name varchar(255) NOT NULL,
group_type smallint default 0,
ldap_group_dn varchar(512) NOT NULL,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -135,7 +139,7 @@ create table access_log (
repo_tag varchar (128),
GUID varchar(64),
operation varchar(20) NOT NULL,
op_time timestamp,
op_time timestamp default CURRENT_TIMESTAMP,
primary key (log_id)
);
@ -148,8 +152,8 @@ create table repository (
description text,
pull_count int DEFAULT 0 NOT NULL,
star_count int DEFAULT 0 NOT NULL,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
primary key (repository_id),
UNIQUE (name)
);
@ -168,8 +172,8 @@ create table replication_policy (
filters varchar(1024),
replicate_deletion boolean DEFAULT false NOT NULL,
start_time timestamp NULL,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -188,8 +192,8 @@ create table replication_target (
*/
target_type SMALLINT NOT NULL DEFAULT 0,
insecure boolean NOT NULL DEFAULT false,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -206,8 +210,8 @@ create table replication_job (
New job service only records uuid, for compatibility in this table both IDs are stored.
*/
job_uuid varchar(64),
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -223,8 +227,8 @@ create table replication_immediate_trigger (
namespace varchar(256) NOT NULL,
on_push boolean NOT NULL DEFAULT false,
on_deletion boolean NOT NULL DEFAULT false,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -240,8 +244,8 @@ create table replication_immediate_trigger (
New job service only records uuid, for compatibility in this table both IDs are stored.
*/
job_uuid varchar(64),
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -262,8 +266,8 @@ create table img_scan_overview (
components_overview varchar(2048),
/* primary key for querying details, in clair it should be the name of the "top layer" */
details_key varchar(128),
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY(id),
UNIQUE(image_digest)
);
@ -302,8 +306,8 @@ create table harbor_label (
*/
scope char(1) NOT NULL,
project_id int,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
deleted boolean DEFAULT false NOT NULL,
PRIMARY KEY(id),
CONSTRAINT unique_label UNIQUE (name,scope, project_id)
@ -329,8 +333,8 @@ the resource_name is the name of image when the resource_type is i
'i' for image
*/
resource_type char(1) NOT NULL,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY(id),
CONSTRAINT unique_label_resource UNIQUE (label_id,resource_id, resource_name, resource_type)
);
@ -344,8 +348,8 @@ create table admin_job (
cron_str varchar(256),
status varchar(64) NOT NULL,
job_uuid varchar(64),
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
deleted boolean DEFAULT false NOT NULL,
PRIMARY KEY(id)
);

View File

@ -31,8 +31,8 @@ create table harbor_user (
reset_uuid varchar(40) DEFAULT NULL,
salt varchar(40) DEFAULT NULL,
sysadmin_flag smallint DEFAULT 0 NOT NULL,
creation_time timestamp(0),
update_time timestamp(0),
creation_time timestamp,
update_time timestamp,
UNIQUE (username),
UNIQUE (email)
);
@ -64,8 +64,8 @@ create table project_member (
*/
entity_type char(1) NOT NULL,
role int NOT NULL,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id),
CONSTRAINT unique_project_entity_type UNIQUE (project_id, entity_id, entity_type)
);
@ -86,8 +86,8 @@ create table project_metadata (
project_id int NOT NULL,
name varchar(255) NOT NULL,
value varchar(255),
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
deleted smallint DEFAULT 0 NOT NULL,
PRIMARY KEY (id),
CONSTRAINT unique_project_id_and_name UNIQUE (project_id,name)
@ -103,8 +103,8 @@ create table user_group (
group_name varchar(255) NOT NULL,
group_type smallint default 0,
ldap_group_dn varchar(512) NOT NULL,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -131,8 +131,8 @@ create table repository (
description text,
pull_count int DEFAULT 0 NOT NULL,
star_count int DEFAULT 0 NOT NULL,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
primary key (repository_id),
UNIQUE (name)
);
@ -151,8 +151,8 @@ create table replication_policy (
filters varchar(1024),
replicate_deletion SMALLINT DEFAULT 0 NOT NULL,
start_time timestamp NULL,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -171,8 +171,8 @@ create table replication_target (
*/
target_type SMALLINT NOT NULL DEFAULT 0,
insecure SMALLINT NOT NULL DEFAULT 0,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -189,8 +189,8 @@ create table replication_job (
New job service only records uuid, for compatibility in this table both IDs are stored.
*/
job_uuid varchar(64),
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -206,8 +206,8 @@ create table replication_immediate_trigger (
namespace varchar(256) NOT NULL,
on_push SMALLINT NOT NULL DEFAULT 0,
on_deletion SMALLINT NOT NULL DEFAULT 0,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -223,8 +223,8 @@ create table replication_immediate_trigger (
New job service only records uuid, for compatibility in this table both IDs are stored.
*/
job_uuid varchar(64),
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY (id)
);
@ -245,8 +245,8 @@ create table img_scan_overview (
components_overview varchar(2048),
/* primary key for querying details, in clair it should be the name of the "top layer" */
details_key varchar(128),
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY(id),
UNIQUE(image_digest)
);
@ -285,8 +285,8 @@ create table harbor_label (
*/
scope char(1) NOT NULL,
project_id int,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY(id),
CONSTRAINT unique_name_and_scope UNIQUE (name,scope,project_id)
);
@ -311,8 +311,8 @@ the resource_name is the name of image when the resource_type is i
'i' for image
*/
resource_type char(1) NOT NULL,
creation_time timestamp default 'now'::timestamp,
update_time timestamp default 'now'::timestamp,
creation_time timestamp default CURRENT_TIMESTAMP,
update_time timestamp default CURRENT_TIMESTAMP,
PRIMARY KEY(id),
CONSTRAINT unique_label_resource UNIQUE (label_id,resource_id, resource_name, resource_type)
);