Migrate to postgresql

This commit is contained in:
Daniel Friesel 2019-03-25 17:04:39 +01:00
parent d114a6248e
commit 632f731940
2 changed files with 26 additions and 19 deletions

View file

@ -165,7 +165,7 @@ sub startup {
insert into users ( insert into users (
name, status, public_level, email, token, password, name, status, public_level, email, token, password,
registered_at, last_login registered_at, last_login
) values (?, 0, 0, ?, ?, ?, ?, ?); ) values (?, 0, 0, ?, ?, ?, to_timestamp(?), to_timestamp(?));
} }
); );
} }
@ -200,7 +200,7 @@ sub startup {
qq{ qq{
insert into pending_mails ( insert into pending_mails (
email, num_tries, last_try email, num_tries, last_try
) values (?, ?, ?); ) values (?, ?, to_timestamp(?));
} }
); );
} }
@ -222,7 +222,7 @@ sub startup {
return $self->app->dbh->prepare( return $self->app->dbh->prepare(
qq{ qq{
update users set deletion_requested = ? where id = ?; update users set deletion_requested = to_timestamp(?) where id = ?;
} }
); );
} }
@ -239,9 +239,9 @@ sub startup {
sched_time, real_time, sched_time, real_time,
route, messages route, messages
) values ( ) values (
?, ?, ?, to_timestamp(?),
?, ?, ?, ?, ?, ?, ?, ?,
?, ?, ?, ?, to_timestamp(?), to_timestamp(?),
?, ?,
?, ? ?, ?
) )
} }
@ -252,10 +252,15 @@ sub startup {
dbh => sub { dbh => sub {
my ($self) = @_; my ($self) = @_;
my $dbname = $ENV{TRAVELYNX_DB_FILE} // 'travelynx.sqlite'; my $dbname = $ENV{TRAVELYNX_DB_NAME} // 'travelynx_dev';
my $host = $ENV{TRAVELYNX_DB_HOST} // 'localhost';
my $port = $ENV{TRAVELYNX_DB_PORT} // '5432';
my $user = $ENV{TRAVELYNX_DB_USER};
my $pw = $ENV{TRAVELYNX_DB_PASSWORD};
return DBI->connect( "dbi:SQLite:dbname=${dbname}", undef, undef, return DBI->connect(
{ AutoCommit => 1 } ); "dbi:Pg:dbname=${dbname};host=${host};port=${port}",
$user, $pw, { AutoCommit => 1 } );
} }
); );
$self->attr( $self->attr(
@ -264,9 +269,9 @@ sub startup {
return $self->app->dbh->prepare( return $self->app->dbh->prepare(
qq{ qq{
select action_id, action_time, stations.ds100, stations.name, select action_id, extract(epoch from action_time), stations.ds100, stations.name,
train_type, train_line, train_no, train_id, train_type, train_line, train_no, train_id,
sched_time, real_time, extract(epoch from sched_time), extract(epoch from real_time),
route, messages route, messages
from user_actions from user_actions
left outer join stations on station_id = stations.id left outer join stations on station_id = stations.id
@ -282,9 +287,9 @@ sub startup {
return $self->app->dbh->prepare( return $self->app->dbh->prepare(
qq{ qq{
select action_id, action_time, stations.ds100, stations.name, select action_id, extract(epoch from action_time), stations.ds100, stations.name,
train_type, train_line, train_no, train_id, train_type, train_line, train_no, train_id,
sched_time, real_time, extract(epoch from sched_time), extract(epoch from real_time),
route, messages route, messages
from user_actions from user_actions
left outer join stations on station_id = stations.id left outer join stations on station_id = stations.id
@ -301,14 +306,14 @@ sub startup {
return $self->app->dbh->prepare( return $self->app->dbh->prepare(
qq{ qq{
select action_id, action_time, stations.ds100, stations.name, select action_id, extract(epoch from action_time), stations.ds100, stations.name,
train_type, train_line, train_no, train_id, train_type, train_line, train_no, train_id,
sched_time, real_time, extract(epoch from sched_time), extract(epoch from real_time),
route, messages route, messages
from user_actions from user_actions
left outer join stations on station_id = stations.id left outer join stations on station_id = stations.id
where user_id = ? where user_id = ?
and (action_time = ? or action_time = ?) and (action_time = to_timestamp(?) or action_time = to_timestamp(?))
order by action_time desc order by action_time desc
limit 2 limit 2
} }
@ -348,7 +353,7 @@ qq{select * from pending_mails where email = ? and num_tries > 1;}
qq{ qq{
select select
id, name, status, public_level, email, id, name, status, public_level, email,
registered_at, last_login, deletion_requested extract(epoch from registered_at), extract(epoch from last_login), extract(epoch from deletion_requested)
from users where id = ? from users where id = ?
} }
); );
@ -397,10 +402,12 @@ qq{select * from pending_mails where email = ? and num_tries > 1;}
return $self->app->dbh->prepare( return $self->app->dbh->prepare(
qq{ qq{
insert or replace into tokens insert into tokens
(user_id, type, token) (user_id, type, token)
values values
(?, ?, ?) (?, ?, ?)
on conflict (user_id, type)
do update set token = EXCLUDED.token
} }
); );
} }
@ -456,7 +463,7 @@ qq{select * from pending_mails where email = ? and num_tries > 1;}
insert into user_actions ( insert into user_actions (
user_id, action_id, action_time user_id, action_id, action_time
) values ( ) values (
?, $self->app->action_type->{undo}, ? ?, $self->app->action_type->{undo}, to_timestamp(?)
) )
} }
); );

View file

@ -2,7 +2,7 @@ package Travelynx::Controller::Account;
use Mojo::Base 'Mojolicious::Controller'; use Mojo::Base 'Mojolicious::Controller';
use Crypt::Eksblowfish::Bcrypt qw(bcrypt en_base64); use Crypt::Eksblowfish::Bcrypt qw(bcrypt en_base64);
use Encode qw(decode); use Encode qw(decode encode);
use Email::Sender::Simple qw(try_to_sendmail); use Email::Sender::Simple qw(try_to_sendmail);
use Email::Simple; use Email::Simple;
use UUID::Tiny qw(:std); use UUID::Tiny qw(:std);