Построение Raw-SQL cредствами Storm-ORM

Возникло у меня желание попробовать построить чистый, сырой запрос (Raw-SQL) с помощью storm.expr для одного самописного специфического маппера, сочетающего в себе паттерны Single Table Inheritance и Entity Attribute Value.

Причем, параметризирование запроса должно выполняться именованными (а не позиционными) аргументами, без участия Storm ORM.

И вот что у меня получилось (конкретная реализация, структура и названия, естественно, изменены):

  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
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
import sqlparse
from storm.expr import (
    Add, Alias, build_tables, Column, COLUMN, Comparable, Count, EXPR, has_tables, In, LeftJoin,
    NamedFunc, Select, SQL, SQLRaw, Sum, Table as TableOrig, TABLE, Undef
)
from storm.databases.mysql import compile as compile
from storm.variables import Variable

compile = compile.create_child()


@compile.when(int, long)
def compile_int(compile, expr, state):
    return str(expr)


@compile.when(Variable)
def compile_variable(compile, variable, state):
    value = variable.get(to_db=True)
    if isinstance(value, (int, long)):
        return str(value)
    state.parameters.append(variable)
    return "?"


@compile.when(Select)
def compile_select(compile, select, state):
    tokens = ["SELECT "]
    state.push("auto_tables", [])
    state.push("context", COLUMN)
    if select.distinct:
        tokens.append("DISTINCT ")
        if isinstance(select.distinct, (tuple, list)):
            tokens.append(
                "ON (%s) " % compile(select.distinct, state, raw=True))
    tokens.append(compile(select.columns, state))
    tables_pos = len(tokens)
    parameters_pos = len(state.parameters)
    state.context = EXPR
    if select.where is not Undef:
        tokens.append(" WHERE ")
        tokens.append(compile(select.where, state, raw=True))
    if select.group_by is not Undef:
        tokens.append(" GROUP BY ")
        tokens.append(compile(select.group_by, state, raw=True))
    if select.having is not Undef:
        tokens.append(" HAVING ")
        tokens.append(compile(select.having, state, raw=True))
    if select.order_by is not Undef:
        tokens.append(" ORDER BY ")
        tokens.append(compile(select.order_by, state, raw=True))
    if select.limit is not Undef:  # patched
        tokens.append(" LIMIT ")
        tokens.append(compile(select.limit, state, raw=True))
    if select.offset is not Undef:  # patched
        tokens.append(" OFFSET ")
        tokens.append(compile(select.offset, state, raw=True))
    if has_tables(state, select):
        state.context = TABLE
        state.push("parameters", [])
        tokens.insert(tables_pos, " FROM ")
        tokens.insert(tables_pos+1, build_tables(compile, select.tables,
                                                 select.default_tables, state))
        parameters = state.parameters
        state.pop()
        state.parameters[parameters_pos:parameters_pos] = parameters
    state.pop()
    state.pop()
    return "".join(tokens)

S = SQL


def as_(self, name=Undef):
    return Alias(self, name)

Comparable.as_ = as_


class If(NamedFunc):
    __slots__ = ()
    name = "IF"


class Space(object):

    def __init__(self, factory):
        self._factory = factory

    def __getattr__(self, name):
        return self._factory(name)

C = Space(Column)


class Param(SQL):

    __slots__ = ()

    def __init__(self, expr):
        expr = '%({})s'.format(expr)
        SQL.__init__(self, expr)


P = Space(Param)


class Table(TableOrig):

    __slots__ = ()

    def __getattr__(cls, name):
        return Column(name, cls)

    def as_(cls, name=Undef):
        return TableAlias(cls, name)


T = Space(Table)


class TableAlias(Alias):

    def __getattr__(cls, name):
        return Column(name, cls)

# ============================================
# Ok,preparations is done, now let build query
# ============================================


class EventMapper(object):

    _compile = compile

    class BaseQuery(object):

        def __init__(self):
            meta_ta = T.stats_posts_meta.as_('i')
            self.event_where = []
            self.event_having = Add()
            self.event_query = self._create_event_query(self.event_where, self.event_having)
            self.info_query = self._create_info_query(TableAlias(self.event_query, 'e'), meta_ta)
            self.final_query = self._create_final_query(TableAlias(self.info_query, 'e'))

        def _create_event_query(self, where, having):
            event_ta = Table('entity_events_daily').as_('e')
            return Select(
                columns=[
                    Alias(None, 'TIMESTAMP'),
                    Alias(None, 'user_id'),
                    event_ta.entity_id.as_('entity_id'),
                ],
                tables=event_ta,
                where=(
                    (event_ta.site_id == P.site_id) &
                    (event_ta.category_id == P.category_id) &
                    (event_ta.timestamp >= P.min_timestamp) &
                    (event_ta.timestamp < P.max_timestamp) &
                    In(event_ta.event_id, where)
                ),
                group_by=[event_ta.entity_id],
                having=(
                    (C.created_entity_count >= P.min_entity_creation_count) &
                    (having > 0)
                )
            )

        def _create_info_query(self, event_query_ta, meta_ta):
            return Select(
                columns=[
                    Alias(None, 'entity_id'),
                    Alias(None, 'TIMESTAMP'),
                    Count().as_('active_entity_count'),
                    meta_ta.owner_id.as_('owner_id'),
                ],
                tables=LeftJoin(
                    event_query_ta,
                    meta_ta,
                    on=(meta_ta.entity_id == event_query_ta.entity_id)),
                group_by=[meta_ta.owner_id]
            )

        def _create_final_query(self, info_ta):
            return Select(
                columns=[SQLRaw('*')],
                tables=info_ta,
                offset=P.offset,
                limit=P.limit
            )

        def add_criteria(self, *names):
            for name in names:
                self.add_criterion(name)

        def add_criterion(self, name):
            count_name = "{}_count".format(name)
            self.event_query.columns.append(
                Sum(If(C.event_id.is_in(Param(name)), C.event_count, 0)).as_(count_name),
            )
            self.event_where.append(Param(name))
            self.event_having.exprs += (Column(count_name),)
            self.info_query.columns.append(
                Sum(Column(count_name)).as_(count_name)
            )

        def get(self):
            return self.final_query

    def find_by_criteria(self, **criteria):
        query = self.BaseQuery()
        query.add_criteria(*criteria.keys())
        return self._execute(query, criteria.values())

    def _execute(self, query, params=()):
        print sqlparse.format(self._compile(query.get()), reindent=True, keyword_case='upper')


event_mapper = EventMapper()
object_list = event_mapper.find_by_criteria(
    comments=1,
    internal_shares=2,
    external_shares=3,
    internal_likes=4,
    external_likes=5,
    entity_creations=6,
    views=7,
    clicks=8
)

На выходе получается запрос вида:

SELECT *
FROM
  (SELECT NULL AS entity_id,
          NULL AS `TIMESTAMP`,
          COUNT(*) AS active_entity_count,
          i.owner_id AS owner_id,
          SUM(entity_creations_count) AS entity_creations_count,
          SUM(views_count) AS views_count,
          SUM(internal_shares_count) AS internal_shares_count,
          SUM(comments_count) AS comments_count,
          SUM(external_shares_count) AS external_shares_count,
          SUM(external_likes_count) AS external_likes_count,
          SUM(internal_likes_count) AS internal_likes_count,
          SUM(clicks_count) AS clicks_count
   FROM
     (SELECT NULL AS `TIMESTAMP`,
             NULL AS user_id,
             e.entity_id AS entity_id,
             SUM(IF((event_id IN (%(entity_creations)s)), event_count, 0)) AS entity_creations_count,
             SUM(IF((event_id IN (%(views)s)), event_count, 0)) AS views_count,
             SUM(IF((event_id IN (%(internal_shares)s)), event_count, 0)) AS internal_shares_count,
             SUM(IF((event_id IN (%(comments)s)), event_count, 0)) AS comments_count,
             SUM(IF((event_id IN (%(external_shares)s)), event_count, 0)) AS external_shares_count,
             SUM(IF((event_id IN (%(external_likes)s)), event_count, 0)) AS external_likes_count,
             SUM(IF((event_id IN (%(internal_likes)s)), event_count, 0)) AS internal_likes_count,
             SUM(IF((event_id IN (%(clicks)s)), event_count, 0)) AS clicks_count
      FROM entity_events_daily AS e
      WHERE e.site_id = %(site_id)s
        AND e.category_id = %(category_id)s
        AND e.`timestamp` >= %(min_timestamp)s
        AND e.`timestamp` < %(max_timestamp)s
        AND e.event_id IN (%(entity_creations)s,
                           %(views)s,
                           %(internal_shares)s,
                           %(comments)s,
                           %(external_shares)s,
                           %(external_likes)s,
                           %(internal_likes)s,
                           %(clicks)s)
      GROUP BY e.entity_id
      HAVING created_entity_count >= %(min_entity_creation_count)s
      AND entity_creations_count+views_count+internal_shares_count+comments_count+external_shares_count+external_likes_count+internal_likes_count+clicks_count > 0) AS e
   LEFT JOIN stats_posts_meta AS i ON i.entity_id = e.entity_id
   GROUP BY i.owner_id) AS e LIMIT %(limit)s
OFFSET %(offset)s

Comments

comments powered by Disqus