summaryrefslogtreecommitdiff
path: root/lib/Catmandu/Store/DBI/Handler/Pg.pm
blob: be8052620cb3549b904c46dc4c425b0e76a8d271 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
package Catmandu::Store::DBI::Handler::Pg;

use Catmandu::Sane;
use DBD::Pg ();
use Moo;
use namespace::clean;

our $VERSION = "0.0702";

with 'Catmandu::Store::DBI::Handler';

sub _column_sql {
    my ($self, $map, $bag) = @_;
    my $col = $map->{column};
    my $dbh = $bag->store->dbh;
    my $sql = $dbh->quote_identifier($col) . " ";
    if ($map->{type} eq 'string') {
        $sql .= 'TEXT';
    }
    elsif ($map->{type} eq 'integer') {
        $sql .= 'INTEGER';
    }
    elsif ($map->{type} eq 'binary') {
        $sql .= 'BYTEA';
    }
    elsif ($map->{type} eq 'json') {
        if ($dbh->{pg_server_version} < 90400) {
            Catmandu::Error->throw(
                "JSONB type only supported in PostgreSQL 9.4 and above");
        }
        $sql .= 'JSONB';
    }
    elsif ($map->{type} eq 'datetime') {
        $sql .= 'TIMESTAMP(0)';
    }
    elsif ($map->{type} eq 'datetime_milli') {
        $sql .= 'TIMESTAMP(3)';
    }
    else {
        Catmandu::Error->throw("Unknown type '$map->{type}'");
    }
    if ($map->{array}) {
        $sql .= '[]';
    }
    if ($map->{unique}) {
        $sql .= " UNIQUE";
    }
    if ($map->{required}) {
        $sql .= " NOT NULL";
    }
    $sql;
}

sub _create_index_sql {
    my ($self, $bag, $map) = @_;
    my $name  = $bag->name;
    my $col   = $map->{column};
    my $dbh   = $bag->store->dbh;
    my $q_col = $dbh->quote_identifier($col);
    my $sql   = <<SQL;
DO \$\$
BEGIN

IF NOT EXISTS (
    SELECT 1
    FROM   pg_class c
    JOIN   pg_namespace n ON n.oid = c.relnamespace
    WHERE  c.relname = '${name}_${col}_idx'
    AND    n.nspname = 'public'
    ) THEN

    CREATE INDEX ${name}_${col}_idx ON public.${name} (${q_col});
END IF;

END\$\$;
SQL
}

sub create_table {
    my ($self, $bag) = @_;
    my $mapping = $bag->mapping;
    my $name    = $bag->name;
    my $dbh     = $bag->store->dbh;
    my $q_name  = $dbh->quote_identifier($name);

    my $sql
        = "CREATE TABLE IF NOT EXISTS $q_name("
        . join(',', map {$self->_column_sql($_, $bag)} values %$mapping)
        . ");";

    for my $map (values %$mapping) {
        next if $map->{unique} || !$map->{index};
        $sql .= $self->_create_index_sql($bag, $map);
    }

    local $SIG{__WARN__} = sub {
        my $msg = $_[0];
        if ($msg !~ /^NOTICE:  relation "$name" already exists/) {
            warn $msg;
        }
    };
    $dbh->do($sql) or Catmandu::Error->throw($dbh->errstr);
}

# see
# http://stackoverflow.com/questions/15840922/where-not-exists-in-postgresql-gives-syntax-error
# and
# https://rt.cpan.org/Public/Bug/Display.html?id=13180
sub add_row {
    my ($self, $bag, $row) = @_;
    my $mapping  = $bag->mapping;
    my $dbh      = $bag->store->dbh;
    my $id_col   = $mapping->{_id}{column};
    my $q_id_col = $dbh->quote_identifier($id_col);
    my %binary_cols;
    my %json_cols;
    for my $map (values %$mapping) {

        if ($map->{type} eq 'binary') {
            $binary_cols{$map->{column}} = 1;
        }
        elsif ($map->{type} eq 'json') {
            $json_cols{$map->{column}} = 1;
        }
    }
    my $id     = $row->{$id_col};
    my @cols   = keys %$row;
    my @q_cols = map {$dbh->quote_identifier($_)} @cols;
    my @vals   = values %$row;
    my $name   = $bag->name;
    my $q_name = $dbh->quote_identifier($name);
    my $insert_sql
        = "INSERT INTO $q_name("
        . join(',', @q_cols)
        . ") SELECT "
        . join(',', ('?') x @cols)
        . " WHERE NOT EXISTS (SELECT 1 FROM $q_name WHERE $q_id_col=?)";
    my $update_sql
        = "UPDATE $q_name SET "
        . join(',', map {"$_=?"} @q_cols)
        . " WHERE $q_id_col=?";

    my $sth = $dbh->prepare_cached($update_sql)
        or Catmandu::Error->throw($dbh->errstr);
    my $i = 0;
    for (; $i < @cols; $i++) {
        my $col = $cols[$i];
        my $val = $vals[$i];
        if ($binary_cols{$col}) {
            $sth->bind_param($i + 1, $val, {pg_type => DBD::Pg->PG_BYTEA});
        }
        elsif ($json_cols{$col}) {
            $sth->bind_param($i + 1, $val, {pg_type => DBD::Pg->PG_JSONB});
        }
        else {
            $sth->bind_param($i + 1, $val);
        }
    }
    $sth->bind_param($i + 1, $id);
    $sth->execute or Catmandu::Error->throw($sth->errstr);

    unless ($sth->rows) {
        $sth->finish;
        $sth = $dbh->prepare_cached($insert_sql)
            or Catmandu::Error->throw($dbh->errstr);
        my $i = 0;
        for (; $i < @cols; $i++) {
            my $col = $cols[$i];
            my $val = $vals[$i];
            if ($binary_cols{$col}) {
                $sth->bind_param($i + 1, $val,
                    {pg_type => DBD::Pg->PG_BYTEA});
            }
            elsif ($json_cols{$col}) {
                $sth->bind_param($i + 1, $val,
                    {pg_type => DBD::Pg->PG_JSONB});
            }
            else {
                $sth->bind_param($i + 1, $val);
            }
        }
        $sth->bind_param($i + 1, $id);
        $sth->execute or Catmandu::Error->throw($sth->errstr);
    }
    $sth->finish;
}

1;