Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP
Browse files

bug 858802 Replace schema.sql with SQLAlchemy model

* Recreated setupdb_app.py
* Added ~140 UDFs to schema creation in separate files
* Create a SQLAlchemy Postgres connection manager for setupdb_app.py
* one integration test only to test setupdb_app
* Moved model definitions into models.py
* Example alembic migrations
* Removed deprecated partitioning test and testSchema.py
* generated fresh set of data using fakedata.py tool

Many thanks to Peter Bengtsson, Rob Helmer and Lars Lohn.
  • Loading branch information...
commit 52269b21e354fc422704f4aca50ace3f0a70d3b6 1 parent 6d6dc73
@selenamarie selenamarie authored
Showing with 254,632 additions and 1,067 deletions.
  1. +50 −0 alembic.ini
  2. +42 −0 alembic/README
  3. +72 −0 alembic/env.py
  4. +22 −0 alembic/script.py.mako
  5. +33 −0 alembic/versions/5316d4cfc03a_adding_raw_crashes_a.py
  6. +26 −0 alembic/versions/e5eb3c07f2a_adding_uuid_to_exten.py
  7. +5 −0 config/common_database.ini-dist
  8. +10 −5 docs/populatepostgres.rst
  9. +8 −2 requirements/dev.txt
  10. +8 −5 scripts/staging/dumpschema.sh
  11. +1,337 −0 socorro/external/postgresql/models.py
  12. +366 −0 socorro/external/postgresql/raw_sql/procs/001_update_reports_clean.sql
  13. +11 −0 socorro/external/postgresql/raw_sql/procs/002_version_sort_digit.sql
  14. +10 −0 socorro/external/postgresql/raw_sql/procs/003_major_version_sort.sql
  15. +18 −0 socorro/external/postgresql/raw_sql/procs/004_crash_hadu.sql
  16. +50 −0 socorro/external/postgresql/raw_sql/procs/add_column_if_not_exists.sql
  17. +59 −0 socorro/external/postgresql/raw_sql/procs/add_new_product.sql
  18. +64 −0 socorro/external/postgresql/raw_sql/procs/add_new_release.sql
  19. +56 −0 socorro/external/postgresql/raw_sql/procs/add_old_release.sql
  20. +11 −0 socorro/external/postgresql/raw_sql/procs/aurora_or_nightly.sql
  21. +17 −0 socorro/external/postgresql/raw_sql/procs/backfill_adu.sql
  22. +36 −0 socorro/external/postgresql/raw_sql/procs/backfill_all_dups.sql
  23. +12 −0 socorro/external/postgresql/raw_sql/procs/backfill_build_adu.sql
  24. +11 −0 socorro/external/postgresql/raw_sql/procs/backfill_correlations.sql
  25. +12 −0 socorro/external/postgresql/raw_sql/procs/backfill_crashes_by_user.sql
  26. +12 −0 socorro/external/postgresql/raw_sql/procs/backfill_crashes_by_user_build.sql
  27. +17 −0 socorro/external/postgresql/raw_sql/procs/backfill_daily_crashes.sql
  28. +16 −0 socorro/external/postgresql/raw_sql/procs/backfill_explosiveness.sql
  29. +15 −0 socorro/external/postgresql/raw_sql/procs/backfill_hang_report.sql
  30. +12 −0 socorro/external/postgresql/raw_sql/procs/backfill_home_page_graph.sql
  31. +12 −0 socorro/external/postgresql/raw_sql/procs/backfill_home_page_graph_build.sql
  32. +97 −0 socorro/external/postgresql/raw_sql/procs/backfill_matviews.sql
  33. +12 −0 socorro/external/postgresql/raw_sql/procs/backfill_nightly_builds.sql
  34. +84 −0 socorro/external/postgresql/raw_sql/procs/backfill_one_day.sql
  35. +11 −0 socorro/external/postgresql/raw_sql/procs/backfill_rank_compare.sql
  36. +48 −0 socorro/external/postgresql/raw_sql/procs/backfill_reports_clean.sql
  37. +84 −0 socorro/external/postgresql/raw_sql/procs/backfill_reports_duplicates.sql
  38. +25 −0 socorro/external/postgresql/raw_sql/procs/backfill_signature_counts.sql
  39. +13 −0 socorro/external/postgresql/raw_sql/procs/backfill_tcbs.sql
  40. +13 −0 socorro/external/postgresql/raw_sql/procs/backfill_tcbs_build.sql
  41. +8 −0 socorro/external/postgresql/raw_sql/procs/build_date.sql
  42. +12 −0 socorro/external/postgresql/raw_sql/procs/build_numeric.sql
  43. +38 −0 socorro/external/postgresql/raw_sql/procs/check_partitions.sql
  44. +17 −0 socorro/external/postgresql/raw_sql/procs/content_count_state.sql
  45. +31 −0 socorro/external/postgresql/raw_sql/procs/create_os_version_string.sql
  46. +44 −0 socorro/external/postgresql/raw_sql/procs/create_table_if_not_exists.sql
  47. +69 −0 socorro/external/postgresql/raw_sql/procs/create_weekly_partition.sql
  48. +11 −0 socorro/external/postgresql/raw_sql/procs/crontabber_nodelete.sql
  49. +11 −0 socorro/external/postgresql/raw_sql/procs/crontabber_timestamp.sql
  50. +14 −0 socorro/external/postgresql/raw_sql/procs/daily_crash_code.sql
  51. +25 −0 socorro/external/postgresql/raw_sql/procs/drop_old_partitions.sql
  52. +38 −0 socorro/external/postgresql/raw_sql/procs/edit_featured_versions.sql
  53. +114 −0 socorro/external/postgresql/raw_sql/procs/edit_product_info.sql
  54. +7 −0 socorro/external/postgresql/raw_sql/procs/get_cores.sql
  55. +10 −0 socorro/external/postgresql/raw_sql/procs/get_product_version_ids.sql
  56. +7 −0 socorro/external/postgresql/raw_sql/procs/initcap.sql
  57. +7 −0 socorro/external/postgresql/raw_sql/procs/is_rapid_beta.sql
  58. +39 −0 socorro/external/postgresql/raw_sql/procs/last_record.sql
  59. +14 −0 socorro/external/postgresql/raw_sql/procs/log_priorityjobs.sql
  60. +9 −0 socorro/external/postgresql/raw_sql/procs/major_version.sql
  61. +20 −0 socorro/external/postgresql/raw_sql/procs/nonzero_string.sql
  62. +16 −0 socorro/external/postgresql/raw_sql/procs/old_version_sort.sql
  63. +8 −0 socorro/external/postgresql/raw_sql/procs/pacific2ts.sql
  64. +5 −0 socorro/external/postgresql/raw_sql/procs/pg_stat_statements.sql
  65. +5 −0 socorro/external/postgresql/raw_sql/procs/pg_stat_statements_reset.sql
  66. +17 −0 socorro/external/postgresql/raw_sql/procs/plugin_count_state.sql
  67. +38 −0 socorro/external/postgresql/raw_sql/procs/product_version_sort_number.sql
  68. +21 −0 socorro/external/postgresql/raw_sql/procs/reports_clean_done.sql
  69. +60 −0 socorro/external/postgresql/raw_sql/procs/reports_clean_weekly_partition.sql
  70. +22 −0 socorro/external/postgresql/raw_sql/procs/same_time_fuzzy.sql
  71. +8 −0 socorro/external/postgresql/raw_sql/procs/socorro_db_data_refresh.sql
  72. +18 −0 socorro/external/postgresql/raw_sql/procs/sunset_date.sql
  73. +9 −0 socorro/external/postgresql/raw_sql/procs/to_major_version.sql
  74. +35 −0 socorro/external/postgresql/raw_sql/procs/transform_rules_insert_order.sql
  75. +22 −0 socorro/external/postgresql/raw_sql/procs/transform_rules_update_order.sql
  76. +25 −0 socorro/external/postgresql/raw_sql/procs/try_lock_table.sql
  77. +8 −0 socorro/external/postgresql/raw_sql/procs/tstz_between.sql
  78. +134 −0 socorro/external/postgresql/raw_sql/procs/update_adu.sql
  79. +112 −0 socorro/external/postgresql/raw_sql/procs/update_build_adu.sql
  80. +90 −0 socorro/external/postgresql/raw_sql/procs/update_correlations.sql
  81. +97 −0 socorro/external/postgresql/raw_sql/procs/update_crashes_by_user.sql
  82. +136 −0 socorro/external/postgresql/raw_sql/procs/update_crashes_by_user_build.sql
  83. +96 −0 socorro/external/postgresql/raw_sql/procs/update_daily_crashes.sql
  84. +252 −0 socorro/external/postgresql/raw_sql/procs/update_explosiveness.sql
  85. +8 −0 socorro/external/postgresql/raw_sql/procs/update_final_betas.sql
  86. +63 −0 socorro/external/postgresql/raw_sql/procs/update_hang_report.sql
  87. +94 −0 socorro/external/postgresql/raw_sql/procs/update_home_page_graph.sql
  88. +128 −0 socorro/external/postgresql/raw_sql/procs/update_home_page_graph_build.sql
  89. +29 −0 socorro/external/postgresql/raw_sql/procs/update_lookup_new_reports.sql
  90. +58 −0 socorro/external/postgresql/raw_sql/procs/update_nightly_builds.sql
  91. +68 −0 socorro/external/postgresql/raw_sql/procs/update_os_versions.sql
  92. +62 −0 socorro/external/postgresql/raw_sql/procs/update_os_versions_new_reports.sql
  93. +241 −0 socorro/external/postgresql/raw_sql/procs/update_product_versions.sql
  94. +68 −0 socorro/external/postgresql/raw_sql/procs/update_rank_compare.sql
  95. +7 −0 socorro/external/postgresql/raw_sql/procs/update_reports_clean_cron.sql
  96. +90 −0 socorro/external/postgresql/raw_sql/procs/update_reports_duplicates.sql
  97. +100 −0 socorro/external/postgresql/raw_sql/procs/update_signatures.sql
  98. +22 −0 socorro/external/postgresql/raw_sql/procs/update_socorro_db_version.sql
  99. +81 −0 socorro/external/postgresql/raw_sql/procs/update_tcbs.sql
  100. +101 −0 socorro/external/postgresql/raw_sql/procs/update_tcbs_build.sql
  101. +7 −0 socorro/external/postgresql/raw_sql/procs/url2domain.sql
  102. +8 −0 socorro/external/postgresql/raw_sql/procs/utc_day_is.sql
  103. +8 −0 socorro/external/postgresql/raw_sql/procs/utc_day_near.sql
  104. +18 −0 socorro/external/postgresql/raw_sql/procs/validate_lookup.sql
  105. +15 −0 socorro/external/postgresql/raw_sql/procs/version_matches_channel.sql
  106. +66 −0 socorro/external/postgresql/raw_sql/procs/version_sort.sql
  107. +12 −0 socorro/external/postgresql/raw_sql/procs/version_sort_trigger.sql
  108. +10 −0 socorro/external/postgresql/raw_sql/procs/version_sort_update_trigger_after.sql
  109. +23 −0 socorro/external/postgresql/raw_sql/procs/version_sort_update_trigger_before.sql
  110. +29 −0 socorro/external/postgresql/raw_sql/procs/version_string.sql
  111. +58 −0 socorro/external/postgresql/raw_sql/procs/watch_report_processing.sql
  112. +8 −0 socorro/external/postgresql/raw_sql/procs/week_begins_partition.sql
  113. +8 −0 socorro/external/postgresql/raw_sql/procs/week_begins_partition_string.sql
  114. +8 −0 socorro/external/postgresql/raw_sql/procs/week_begins_utc.sql
  115. +8 −0 socorro/external/postgresql/raw_sql/procs/week_ends_partition.sql
  116. +8 −0 socorro/external/postgresql/raw_sql/procs/week_ends_partition_string.sql
  117. +39 −0 socorro/external/postgresql/raw_sql/procs/weekly_report_partitions.sql
  118. +4 −0 socorro/external/postgresql/raw_sql/types/flash_process_dump_type.sql
  119. +3 −0  socorro/external/postgresql/raw_sql/types/major_version.sql
  120. +7 −0 socorro/external/postgresql/raw_sql/types/product_info_change.sql
  121. +6 −0 socorro/external/postgresql/raw_sql/types/release_enum.sql
  122. +2 −0  socorro/external/postgresql/raw_sql/views/001_product_info_view.sql
  123. +12 −0 socorro/external/postgresql/raw_sql/views/crashes_by_user_build_view.sql
  124. +3 −0  socorro/external/postgresql/raw_sql/views/crashes_by_user_rollup_view.sql
  125. +3 −0  socorro/external/postgresql/raw_sql/views/crashes_by_user_view.sql
  126. +3 −0  socorro/external/postgresql/raw_sql/views/current_server_status_view.sql
  127. +3 −0  socorro/external/postgresql/raw_sql/views/default_versions_builds_view.sql
  128. +3 −0  socorro/external/postgresql/raw_sql/views/default_versions_view.sql
  129. +3 −0  socorro/external/postgresql/raw_sql/views/hang_report_view.sql
  130. +3 −0  socorro/external/postgresql/raw_sql/views/home_page_graph_build_view.sql
  131. +3 −0  socorro/external/postgresql/raw_sql/views/home_page_graph_view.sql
  132. +3 −0  socorro/external/postgresql/raw_sql/views/performance_check_1_view.sql
  133. +3 −0  socorro/external/postgresql/raw_sql/views/product_crash_ratio_view.sql
  134. +3 −0  socorro/external/postgresql/raw_sql/views/product_os_crash_ratio_view.sql
  135. +3 −0  socorro/external/postgresql/raw_sql/views/product_selector_view.sql
  136. +180 −43 socorro/external/postgresql/setupdb_app.py
  137. +0 −479 socorro/unittest/database/testSchema.py
  138. +0 −211 socorro/unittest/database/testSchemaPartitionedTable.py
  139. +4 −1 socorro/unittest/external/postgresql/test_job.py
  140. +14 −10 socorro/unittest/external/postgresql/test_products.py
  141. +68 −175 socorro/unittest/external/postgresql/test_setupdb_app.py
  142. +15 −3 socorro/unittest/external/postgresql/test_signature_urls.py
  143. 0  sql/sqlalchemy/__init__.py
  144. +1,212 −0 sql/sqlalchemy/breakpad_declarative.py
  145. +6,459 −0 sql/sqlalchemy/setupdb_app.py
  146. +4 −0 sql/upgrade/README
  147. +2 −2 tools/dataload/crontabber_state.csv
  148. +5 −4 tools/dataload/import.sh
  149. +4 −4 tools/dataload/os_name_matches.csv
  150. +4 −4 tools/dataload/os_names.csv
  151. +11 −11 tools/dataload/os_versions.csv
  152. +4 −4 tools/dataload/process_types.csv
  153. +2 −2 tools/dataload/product_productid_map.csv
  154. +11 −5 tools/dataload/product_release_channels.csv
  155. +3 −2 tools/dataload/products.csv
  156. +6,241 −33 tools/dataload/raw_adu.csv
  157. +6 −6 tools/dataload/release_channel_matches.csv
  158. +6 −5 tools/dataload/release_channels.csv
  159. +9 −14 tools/dataload/release_repositories.csv
  160. +391 −13 tools/dataload/releases_raw.csv
  161. +233,743 −9 tools/dataload/reports.csv
  162. +6 −6 tools/dataload/uptime_levels.csv
  163. +9 −9 tools/dataload/windows_versions.csv
View
50 alembic.ini
@@ -0,0 +1,50 @@
+# A generic, single database configuration.
+
+[alembic]
+# path to migration scripts
+script_location = alembic
+
+# template used to generate migration files
+file_template = %%(rev)s_%%(slug)s
+
+# set to 'true' to run the environment during
+# the 'revision' command, regardless of autogenerate
+# revision_environment = false
+
+sqlalchemy.url = postgresql://selena:death@localhost/breakpad
+
+
+# Logging configuration
+[loggers]
+keys = root,sqlalchemy,alembic
+
+[handlers]
+keys = console
+
+[formatters]
+keys = generic
+
+[logger_root]
+level = WARN
+handlers = console
+qualname =
+
+[logger_sqlalchemy]
+level = WARN
+handlers =
+qualname = sqlalchemy.engine
+
+[logger_alembic]
+level = INFO
+handlers =
+qualname = alembic
+
+[handler_console]
+class = StreamHandler
+args = (sys.stderr,)
+level = NOTSET
+formatter = generic
+
+[formatter_generic]
+format = %(levelname)-5.5s [%(name)s] %(message)s
+datefmt = %H:%M:%S
View
42 alembic/README
@@ -0,0 +1,42 @@
+
+= Using Alembic for schema migrations =
+
+There are a few new requirements in requirements/dev.txt! Be sure to get those installed.
+
+Then, make a change to:
+
+ socorro/external/postgresql/models.py
+
+And then:
+
+ PYTHONPATH=. alembic revision --autogenerate -m "Making an important change to the schema"
+
+A migration script will be put into:
+
+ alembic/versions
+
+Now you can modify it to meet your needs.
+
+Then, to apply the migration:
+
+ PYTHONPATH=. alembic upgrade head
+
+Downgrade to previous revision:
+
+ PYTHONPATH=. alembic downgrade -1
+
+
+== Dealing with unsupported or custom TYPEs ==
+
+We use a few types not currently supported by SQLAlchemy, so you may need to modify the migration slightly.
+
+=== JSON example
+
+Modify to import JSON type from socorro's model:
+
+ from socorro.external.postgresql.models import JSON
+ sa.Column(u'raw_crash', JSON(), nullable=False),
+
+== Adding an index
+
+ sa.Column(u'uuid', postgresql.UUID(), nullable=False, index=True, unique=True),
View
72 alembic/env.py
@@ -0,0 +1,72 @@
+from __future__ import with_statement
+from alembic import context
+from sqlalchemy import engine_from_config, pool
+from logging.config import fileConfig
+from socorro.external.postgresql.models import *
+
+# this is the Alembic Config object, which provides
+# access to the values within the .ini file in use.
+config = context.config
+
+# Interpret the config file for Python logging.
+# This line sets up loggers basically.
+fileConfig(config.config_file_name)
+
+# add your model's MetaData object here
+# for 'autogenerate' support
+# from myapp import mymodel
+# target_metadata = mymodel.Base.metadata
+target_metadata = DeclarativeBase.metadata
+
+# other values from the config, defined by the needs of env.py,
+# can be acquired:
+# my_important_option = config.get_main_option("my_important_option")
+# ... etc.
+
+def run_migrations_offline():
+ """Run migrations in 'offline' mode.
+
+ This configures the context with just a URL
+ and not an Engine, though an Engine is acceptable
+ here as well. By skipping the Engine creation
+ we don't even need a DBAPI to be available.
+
+ Calls to context.execute() here emit the given string to the
+ script output.
+
+ """
+ url = config.get_main_option("sqlalchemy.url")
+ context.configure(url=url)
+
+ with context.begin_transaction():
+ context.run_migrations()
+
+def run_migrations_online():
+ """Run migrations in 'online' mode.
+
+ In this scenario we need to create an Engine
+ and associate a connection with the context.
+
+ """
+ engine = engine_from_config(
+ config.get_section(config.config_ini_section),
+ prefix='sqlalchemy.',
+ poolclass=pool.NullPool)
+
+ connection = engine.connect()
+ context.configure(
+ connection=connection,
+ target_metadata=target_metadata
+ )
+
+ try:
+ with context.begin_transaction():
+ context.run_migrations()
+ finally:
+ connection.close()
+
+if context.is_offline_mode():
+ run_migrations_offline()
+else:
+ run_migrations_online()
+
View
22 alembic/script.py.mako
@@ -0,0 +1,22 @@
+"""${message}
+
+Revision ID: ${up_revision}
+Revises: ${down_revision}
+Create Date: ${create_date}
+
+"""
+
+# revision identifiers, used by Alembic.
+revision = ${repr(up_revision)}
+down_revision = ${repr(down_revision)}
+
+from alembic import op
+import sqlalchemy as sa
+${imports if imports else ""}
+
+def upgrade():
+ ${upgrades if upgrades else "pass"}
+
+
+def downgrade():
+ ${downgrades if downgrades else "pass"}
View
33 alembic/versions/5316d4cfc03a_adding_raw_crashes_a.py
@@ -0,0 +1,33 @@
+"""Adding raw_crashes and raw_adu.received_at
+
+Revision ID: 5316d4cfc03a
+Revises: None
+Create Date: 2013-03-26 11:30:19.464380
+
+"""
+
+# revision identifiers, used by Alembic.
+revision = '5316d4cfc03a'
+down_revision = None
+
+from alembic import op
+import sqlalchemy as sa
+from sqlalchemy.dialects import postgresql
+from socorro.external.postgresql.models import JSON
+
+def upgrade():
+ ### commands auto generated by Alembic - please adjust! ###
+ op.create_table(u'raw_crashes',
+ sa.Column(u'uuid', postgresql.UUID(), nullable=False, index=True, unique=True),
+ sa.Column(u'raw_crash', JSON(), nullable=False),
+ sa.Column(u'date_processed', postgresql.TIMESTAMP(timezone=True), nullable=True)
+ )
+ op.add_column(u'raw_adu', sa.Column(u'received_at', postgresql.TIMESTAMP(timezone=True), server_default='NOW()', nullable=True))
+ ### end Alembic commands ###
+
+
+def downgrade():
+ ### commands auto generated by Alembic - please adjust! ###
+ op.drop_column(u'raw_adu', u'received_at')
+ op.drop_table(u'raw_crashes')
+ ### end Alembic commands ###
View
26 alembic/versions/e5eb3c07f2a_adding_uuid_to_exten.py
@@ -0,0 +1,26 @@
+"""Adding uuid to extensions
+
+Revision ID: e5eb3c07f2a
+Revises: 5316d4cfc03a
+Create Date: 2013-03-26 14:24:56.425147
+
+"""
+
+# revision identifiers, used by Alembic.
+revision = 'e5eb3c07f2a'
+down_revision = '5316d4cfc03a'
+
+from alembic import op
+import sqlalchemy as sa
+from sqlalchemy.dialects import postgresql
+
+def upgrade():
+ ### commands auto generated by Alembic - please adjust! ###
+ op.add_column(u'extensions', sa.Column(u'uuid', postgresql.UUID(), nullable=True))
+ ### end Alembic commands ###
+
+
+def downgrade():
+ ### commands auto generated by Alembic - please adjust! ###
+ op.drop_column(u'extensions', u'uuid')
+ ### end Alembic commands ###
View
5 config/common_database.ini-dist
@@ -47,3 +47,8 @@
# doc: a class that will execute transactions
# converter: configman.converters.class_converter
#transaction_executor_class='socorro.database.transaction_executor.TransactionExecutorWithLimitedBackoff'
+
+#name: read_write_users
+#doc: database users with read_write access to socorrodb
+#converter: eval
+read_write_users="breakpad_rw, postgres, monitor"
View
15 docs/populatepostgres.rst
@@ -44,19 +44,24 @@ graphs and show reports such as "Top Crash By Signature".
IMPORTANT NOTE - many reports use the reports_clean_done() stored
procedure to check that reports exist for the last UTC hour of the
-day being processed, as a way to catch problems. If your crash
+day being processed, as a way to catch problems. If your crash
volume does not guarantee one crash per hour, you may want to modify
-this function in socorro/sql/schema.sql and reload the schema
+this function in socorro/external/postgresql/raw_sql/procs/reports_clean_done.sql
+and reload the schema
::
./socorro/external/postgresql/setupdb_app.py --database_name=breakpad --dropdb
ALSO - the backfill procedure ignores any data over 30 days old.
Make sure you've adjusted the dates in the CSV files appropriately,
-or change these funtions in the schema.sql and reload the schema as above.
+or change these functions in socorro/external/postgresql/raw_sql/procs/backfill_*.sql
+and reload the schema as above.
-Normally this is run for the previous day by cron_daily_matviews.sh
-but you can simply run the backfill_matviews() function to bootstrap the system.
+Normally this is run for the previous day by cron_daily_matviews.sh
+but you can run the following function to bootstrap the system
+::
+
+ psql breakpad -c "SELECT backfill_matviews()"
This is normally run by the import.sh, so take a look in there if
you need to make adjustments.
View
10 requirements/dev.txt
@@ -1,6 +1,12 @@
-r prod.txt
+Mako==0.7.3
+MarkupSafe==0.15
+Paste==1.7.5.1
+SQLAlchemy==0.7.9
+alembic==0.4.2
coverage==3.5.2b1
-nose==1.1.2
mock==0.8.0
+nose==1.1.2
poster==0.8.1
-Paste==1.7.5.1
+requests==1.1.0
+sqlalchemy-citext==1.0-2
View
13 scripts/staging/dumpschema.sh
@@ -1,9 +1,11 @@
#!/bin/bash
DB=$1
-PORT=$3
+USER=$2
+PORT=$4
+: ${USER:="postgres"}
: ${DB:="breakpad"}
-if [ -z $2 ]
+if [ -z $3 ]
then
HOST=''
else
@@ -11,15 +13,16 @@ else
fi
: ${PORT:="5432"}
-pg_dump $HOST -p $PORT -s \
- -n public \
+TODAY=`date +%Y%m%d`
+
+pg_dump $HOST -p $PORT -s -U $USER \
-T high_load_temp \
-T locks* \
-T activity_snapshot \
-T product_info_changelog \
-T '*_201*' \
-T 'priority_jobs_*' \
- $DB > schema-20121008.sql
+ $DB > schema-$DB-$TODAY.sql
echo 'schema dumped'
View
1,337 socorro/external/postgresql/models.py
@@ -0,0 +1,1337 @@
+#! /usr/bin/env python
+# This Source Code Form is subject to the terms of the Mozilla Public
+# License, v. 2.0. If a copy of the MPL was not distributed with this
+# file, You can obtain one at http://mozilla.org/MPL/2.0/.
+
+"""
+SQLAlchemy models for Socorro
+"""
+from __future__ import unicode_literals
+
+from sqlalchemy import *
+from sqlalchemy import create_engine
+from sqlalchemy import event
+from sqlalchemy.ext import compiler
+from sqlalchemy.ext.declarative import declarative_base
+from sqlalchemy.orm import relationship, sessionmaker
+from sqlalchemy.schema import DDLElement
+from sqlalchemy.sql import table
+import sqlalchemy.types as types
+
+try:
+ from sqlalchemy.dialects.postgresql import *
+ from sqlalchemy.dialects.postgresql.base import ischema_names
+except ImportError:
+ from sqlalchemy.databases.postgres import *
+
+#######################################
+# Create CITEXT type for SQL Alchemy
+#######################################
+
+class CITEXT(types.UserDefinedType):
+ name = 'citext'
+
+ def get_col_spec(self):
+ return 'CITEXT'
+
+ def bind_processor(self, dialect):
+ def process(value):
+ return value
+ return process
+
+ def result_processor(self, dialect, coltype):
+ def process(value):
+ return value
+ return process
+
+ def __repr__(self):
+ return "citext"
+
+class JSON(types.UserDefinedType):
+ name = 'json'
+
+ def get_col_spec(self):
+ return 'JSON'
+
+ def bind_processor(self, dialect):
+ def process(value):
+ return value
+ return process
+
+ def result_processor(self, dialect, coltype):
+ def process(value):
+ return value
+ return process
+
+ def __repr__(self):
+ return "json"
+
+
+class MAJOR_VERSION(types.UserDefinedType):
+ name = 'MAJOR_VERSION'
+
+ def get_col_spec(self):
+ return 'MAJOR_VERSION'
+
+ def bind_processor(self, dialect):
+ def process(value):
+ return value
+ return process
+
+ def result_processor(self, dialect, coltype):
+ def process(value):
+ return value
+ return process
+
+ def __repr__(self):
+ return 'major_version'
+
+
+class flash_process_dump_type(types.UserDefinedType):
+ name = 'flash_process_dump_type'
+
+ def get_col_spec(self):
+ return 'flash_process_dump_type'
+
+ def bind_processor(self, dialect):
+ def process(value):
+ return value
+ return process
+
+ def result_processor(self, dialect, coltype):
+ def process(value):
+ return value
+ return process
+
+ def __repr__(self):
+ return 'flash_process_dump_type'
+
+
+class product_info_change(types.UserDefinedType):
+ name = 'product_info_change'
+
+ def get_col_spec(self):
+ return 'product_info_change'
+
+ def bind_processor(self, dialect):
+ def process(value):
+ return value
+ return process
+
+ def result_processor(self, dialect, coltype):
+ def process(value):
+ return value
+ return process
+
+ def __repr__(self):
+ return 'product_info_change'
+
+
+class release_enum(types.UserDefinedType):
+ name = 'release_enum'
+
+ def get_col_spec(self):
+ return 'release_enum'
+
+ def bind_processor(self, dialect):
+ def process(value):
+ return value
+ return process
+
+ def result_processor(self, dialect, coltype):
+ def process(value):
+ return value
+ return process
+
+ def __repr__(self):
+ return 'release_enum'
+
+
+###########################################
+# Baseclass for all Socorro tables
+###########################################
+
+DeclarativeBase = declarative_base()
+metadata = DeclarativeBase.metadata
+
+ischema_names['citext'] = CITEXT
+ischema_names['json'] = JSON
+ischema_names['major_version'] = MAJOR_VERSION
+ischema_names['release_enum'] = release_enum
+ischema_names['product_info_change'] = product_info_change
+ischema_names['flash_process_dump_type'] = flash_process_dump_type
+
+
+###############################
+# Schema definition: Tables
+###############################
+
+class EmailCampaignsContact(DeclarativeBase):
+ __tablename__ = 'email_campaigns_contacts'
+
+ #column definitions
+ email_campaigns_id = Column(u'email_campaigns_id', INTEGER(), ForeignKey('email_campaigns.id'))
+ email_contacts_id = Column(u'email_contacts_id', INTEGER(), ForeignKey('email_contacts.id'))
+ status = Column(u'status', TEXT(), nullable=False, server_default='stopped')
+
+ # Indexes
+ email_campaigns_contacts_mapping_unique = Index('email_campaigns_contacts_mapping_unique', email_campaigns_id, email_contacts_id, unique=True)
+ __mapper_args__ = {"primary_key":(email_campaigns_id, email_contacts_id)}
+
+
+class Tcbs(DeclarativeBase):
+ __tablename__ = 'tcbs'
+
+ #column definitions
+ signature_id = Column(u'signature_id', INTEGER(), ForeignKey('signatures.signature_id'), primary_key=True, nullable=False, index=True)
+ report_date = Column(u'report_date', DATE(), primary_key=True, nullable=False, index=True)
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False)
+ process_type = Column(u'process_type', CITEXT(), primary_key=True, nullable=False)
+ release_channel = Column(u'release_channel', CITEXT(), ForeignKey('release_channels.release_channel'), primary_key=True, nullable=False)
+ report_count = Column(u'report_count', INTEGER(), nullable=False, server_default=text('0'))
+ win_count = Column(u'win_count', INTEGER(), nullable=False, server_default=text('0'))
+ mac_count = Column(u'mac_count', INTEGER(), nullable=False, server_default=text('0'))
+ lin_count = Column(u'lin_count', INTEGER(), nullable=False, server_default=text('0'))
+ hang_count = Column(u'hang_count', INTEGER(), nullable=False, server_default=text('0'))
+ startup_count = Column(u'startup_count', INTEGER())
+
+ idx_tcbs_product_version = Index('idx_tcbs_product_version', product_version_id, report_date)
+ tcbs_report_date = Index('tcbs_report_date', report_date)
+ tcbs_signature = Index('tcbs_signature', signature_id)
+
+
+class CorrelationAddon(DeclarativeBase):
+ __tablename__ = 'correlation_addons'
+
+ #column definitions
+ correlation_id = Column(u'correlation_id', INTEGER(), ForeignKey('correlations.correlation_id'), nullable=False)
+ addon_key = Column(u'addon_key', TEXT(), nullable=False)
+ addon_version = Column(u'addon_version', TEXT(), nullable=False)
+ crash_count = Column(u'crash_count', INTEGER(), nullable=False, server_default=text('0'))
+
+ __mapper_args__ = {"primary_key":(correlation_id, addon_key, addon_version)}
+ correlation_addons_key = Index('correlation_addons_key', correlation_id, addon_key, addon_version, unique=True)
+
+class CorrelationCore(DeclarativeBase):
+ __tablename__ = 'correlation_cores'
+
+ #column definitions
+ correlation_id = Column(u'correlation_id', INTEGER(), ForeignKey('correlations.correlation_id'), nullable=False)
+ architecture = Column(u'architecture', CITEXT(), nullable=False)
+ cores = Column(u'cores', INTEGER(), nullable=False)
+ crash_count = Column(u'crash_count', INTEGER(), nullable=False, server_default=text('0'))
+
+ __mapper_args__ = {"primary_key":(correlation_id, architecture, cores)}
+ correlation_cores_key = Index(u'correlation_cores_key', correlation_id, architecture, cores, unique=True)
+
+
+class CorrelationModule(DeclarativeBase):
+ __tablename__ = 'correlation_modules'
+
+ #column definitions
+ correlation_id = Column(u'correlation_id', INTEGER(), ForeignKey('correlations.correlation_id'), nullable=False)
+ module_signature = Column(u'module_signature', TEXT(), nullable=False)
+ module_version = Column(u'module_version', TEXT(), nullable=False)
+ crash_count = Column(u'crash_count', INTEGER(), nullable=False, server_default=text('0'))
+
+ __mapper_args__ = {"primary_key":(correlation_id, module_signature, module_version)}
+ correlation_modules_key = Index(u'correlation_modules_key', correlation_id, module_signature, module_version, unique=True)
+
+class Extension(DeclarativeBase):
+ __tablename__ = 'extensions'
+
+ #column definitions
+ report_id = Column(u'report_id', INTEGER(), nullable=False)
+ date_processed = Column(u'date_processed', TIMESTAMP(timezone=True))
+ extension_key = Column(u'extension_key', INTEGER(), nullable=False)
+ extension_id = Column(u'extension_id', TEXT(), nullable=False)
+ extension_version = Column(u'extension_version', TEXT())
+ uuid = Column(u'uuid', UUID())
+
+ __mapper_args__ = {"primary_key":(report_id, date_processed, extension_key, extension_id, extension_version)}
+
+class PluginsReport(DeclarativeBase):
+ __tablename__ = 'plugins_reports'
+
+ #column definitions
+ report_id = Column(u'report_id', INTEGER(), nullable=False)
+ plugin_id = Column(u'plugin_id', INTEGER(), nullable=False)
+ date_processed = Column(u'date_processed', TIMESTAMP(timezone=True))
+ version = Column(u'version', TEXT(), nullable=False)
+
+ __mapper_args__ = {"primary_key":(report_id, plugin_id, date_processed, version)}
+
+class PriorityjobsLog(DeclarativeBase):
+ __tablename__ = 'priorityjobs_log'
+
+ #column definitions
+ uuid = Column(u'uuid', VARCHAR(length=255))
+ __mapper_args__ = {"primary_key":(uuid)}
+
+class RawAdu(DeclarativeBase):
+ __tablename__ = 'raw_adu'
+
+ #column definitions
+ adu_count = Column(u'adu_count', INTEGER())
+ date = Column(u'date', DATE())
+ product_name = Column(u'product_name', TEXT())
+ product_os_platform = Column(u'product_os_platform', TEXT())
+ product_os_version = Column(u'product_os_version', TEXT())
+ product_version = Column(u'product_version', TEXT())
+ build = Column(u'build', TEXT())
+ build_channel = Column(u'build_channel', TEXT())
+ product_guid = Column(u'product_guid', TEXT())
+ received_at = Column(u'received_at', TIMESTAMP(timezone=True), server_default=text('NOW()'))
+
+ raw_adu_1_idx = Index(u'raw_adu_1_idx', date, product_name, product_version, product_os_platform, product_os_version)
+
+ __mapper_args__ = {"primary_key":(adu_count, date, product_name, product_version, product_os_platform, product_os_version, build, build_channel, product_guid)}
+
+class ReplicationTest(DeclarativeBase):
+ __tablename__ = 'replication_test'
+
+ #column definitions
+ id = Column(u'id', SMALLINT())
+ test = Column(u'test', BOOLEAN())
+
+ __mapper_args__ = {"primary_key":(id, test)}
+
+class ReportsBad(DeclarativeBase):
+ __tablename__ = 'reports_bad'
+ uuid = Column(u'uuid', TEXT(), nullable=False)
+ date_processed = Column(u'date_processed', TIMESTAMP(timezone=True), nullable=False)
+
+ __mapper_args__ = {"primary_key":(uuid)}
+
+class WindowsVersion(DeclarativeBase):
+ __tablename__ = 'windows_versions'
+ windows_version_name = Column(u'windows_version_name', CITEXT(), nullable=False)
+ major_version = Column(u'major_version', INTEGER(), nullable=False)
+ minor_version = Column(u'minor_version', INTEGER(), nullable=False)
+
+ # Indexes
+ windows_version_key = Index('windows_version_key', major_version, minor_version, unique=True)
+
+ __mapper_args__ = {"primary_key":(major_version, minor_version)}
+
+class Report(DeclarativeBase):
+ __tablename__ = 'reports'
+
+ __table_args__ = {}
+
+ # Column definitions
+ id = Column(u'id', Integer(), primary_key=True)
+ client_crash_date = Column(u'client_crash_date', TIMESTAMP(timezone=True))
+ date_processed = Column(u'date_processed', TIMESTAMP(timezone=True))
+ uuid = Column(u'uuid', VARCHAR(length=50), nullable=False)
+ product = Column(u'product', VARCHAR(length=30))
+ version = Column(u'version', VARCHAR(length=16))
+ build = Column(u'build', VARCHAR(length=30))
+ signature = Column(u'signature', VARCHAR(length=255))
+ url = Column(u'url', VARCHAR(length=255))
+ install_age = Column(u'install_age', INTEGER())
+ last_crash = Column(u'last_crash', INTEGER())
+ uptime = Column(u'uptime', INTEGER())
+ cpu_name = Column(u'cpu_name', VARCHAR(length=100))
+ cpu_info = Column(u'cpu_info', VARCHAR(length=100))
+ reason = Column(u'reason', VARCHAR(length=255))
+ address = Column(u'address', VARCHAR(length=20))
+ os_name = Column(u'os_name', VARCHAR(length=100))
+ os_version = Column(u'os_version', VARCHAR(length=100))
+ email = Column(u'email', VARCHAR(length=100))
+ user_id = Column(u'user_id', VARCHAR(length=50))
+ started_datetime = Column(u'started_datetime', TIMESTAMP(timezone=True))
+ completed_datetime = Column(u'completed_datetime', TIMESTAMP(timezone=True))
+ success = Column(u'success', BOOLEAN())
+ truncated = Column(u'truncated', BOOLEAN())
+ processor_notes = Column(u'processor_notes', TEXT())
+ user_comments = Column(u'user_comments', VARCHAR(length=1024))
+ app_notes = Column(u'app_notes', VARCHAR(length=1024))
+ distributor = Column(u'distributor', VARCHAR(length=20))
+ distributor_version = Column(u'distributor_version', VARCHAR(length=20))
+ topmost_filenames = Column(u'topmost_filenames', TEXT())
+ addons_checked = Column(u'addons_checked', BOOLEAN())
+ flash_version = Column(u'flash_version', TEXT())
+ hangid = Column(u'hangid', TEXT())
+ process_type = Column(u'process_type', TEXT())
+ release_channel = Column(u'release_channel', TEXT())
+ productid = Column(u'productid', TEXT())
+ exploitability = Column(u'exploitability', TEXT())
+
+class Address(DeclarativeBase):
+ __tablename__ = 'addresses'
+
+ __table_args__ = {}
+
+ #column definitions
+ address_id = Column(u'address_id', INTEGER(), primary_key=True, nullable=False)
+ address = Column(u'address', CITEXT(), nullable=False)
+ first_seen = Column(u'first_seen', TIMESTAMP(timezone=True))
+
+ #relationship definitions
+ addresses_address_key = Index('addresses_address_key', address, unique=True)
+ addresses_pkey = Index('addresses_pkey', address_id, unique=True)
+
+
+class Bug(DeclarativeBase):
+ __tablename__ = 'bugs'
+
+ __table_args__ = {}
+
+ #column definitions
+ id = Column(u'id', INTEGER(), primary_key=True, nullable=False)
+ status = Column(u'status', TEXT())
+ resolution = Column(u'resolution', TEXT())
+ short_desc = Column(u'short_desc', TEXT())
+
+ #relationship definitions
+
+
+class BugAssociation(DeclarativeBase):
+ __tablename__ = 'bug_associations'
+
+ __table_args__ = {}
+
+ #column definitions
+ bug_id = Column(u'bug_id', INTEGER(), ForeignKey('bugs.id'), primary_key=True, nullable=False, index=True)
+ signature = Column(u'signature', TEXT(), primary_key=True, nullable=False)
+
+ # Indexes
+ idx_bug_associations_bug_id = Index('idx_bug_associations_bug_id', bug_id)
+ bug_associations_pkey = Index('bug_associations_pkey', signature, bug_id, unique=True)
+
+ #relationship definitions
+ bugs = relationship('Bug', primaryjoin='BugAssociation.bug_id==Bug.id')
+
+
+class BuildAdu(DeclarativeBase):
+ __tablename__ = 'build_adu'
+
+ __table_args__ = {}
+
+ #column definitions
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False)
+ build_date = Column(u'build_date', DATE(), primary_key=True, nullable=False)
+ adu_date = Column(u'adu_date', DATE(), primary_key=True, nullable=False)
+ os_name = Column(u'os_name', CITEXT(), primary_key=True, nullable=False)
+ adu_count = Column(u'adu_count', INTEGER(), nullable=False)
+
+ #build_adu_key = Index('build_adu_key', product_version_id, build_date, adu_date, os_name, unique=True)
+ #relationship definitions
+
+
+class Correlations(DeclarativeBase):
+ __tablename__ = 'correlations'
+
+ __table_args__ = {}
+
+ #column definitions
+ correlation_id = Column(u'correlation_id', INTEGER(), primary_key=True, nullable=False)
+ crash_count = Column(u'crash_count', INTEGER(), nullable=False, server_default=text('0'))
+ os_name = Column(u'os_name', CITEXT(), nullable=False)
+ product_version_id = Column(u'product_version_id', INTEGER(), nullable=False, autoincrement=False)
+ reason_id = Column(u'reason_id', INTEGER(), nullable=False)
+ signature_id = Column(u'signature_id', INTEGER(), nullable=False)
+
+ #relationship definitions
+ correlations_key = Index('correlations_key', product_version_id, os_name, reason_id, signature_id, unique=True)
+
+
+class CrashType(DeclarativeBase):
+ __tablename__ = 'crash_types'
+
+ __table_args__ = {}
+
+ #column definitions
+ crash_type = Column(u'crash_type', CITEXT(), nullable=False)
+ crash_type_id = Column(u'crash_type_id', INTEGER(), primary_key=True, nullable=False)
+ crash_type_short = Column(u'crash_type_short', CITEXT(), nullable=False)
+ has_hang_id = Column(u'has_hang_id', BOOLEAN())
+ include_agg = Column(u'include_agg', BOOLEAN(), nullable=False, server_default=text('True'))
+ old_code = Column(u'old_code', CHAR(length=1), nullable=False)
+ process_type = Column(u'process_type', CITEXT(), ForeignKey('process_types.process_type'), nullable=False)
+
+ # Indexes
+ crash_type_key = Index('crash_type_key', crash_type, unique=True)
+ crash_type_short_key = Index('crash_type_short_key', crash_type_short, unique=True)
+
+ #relationship definitions
+ process_types = relationship('ProcessType', primaryjoin='CrashType.process_type==ProcessType.process_type')
+
+
+class CrashesByUser(DeclarativeBase):
+ __tablename__ = 'crashes_by_user'
+
+ __table_args__ = {}
+
+ #column definitions
+ adu = Column(u'adu', INTEGER(), nullable=False)
+ crash_type_id = Column(u'crash_type_id', INTEGER(), ForeignKey('crash_types.crash_type_id'), primary_key=True, nullable=False)
+ os_short_name = Column(u'os_short_name', CITEXT(), primary_key=True, nullable=False)
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False)
+ report_count = Column(u'report_count', INTEGER(), nullable=False)
+ report_date = Column(u'report_date', DATE(), primary_key=True, nullable=False)
+
+ #relationship definitions
+ crash_types = relationship('CrashType', primaryjoin='CrashesByUser.crash_type_id==CrashType.crash_type_id')
+
+
+class CrashesByUserBuild(DeclarativeBase):
+ __tablename__ = 'crashes_by_user_build'
+
+ __table_args__ = {}
+
+ #column definitions
+ adu = Column(u'adu', INTEGER(), nullable=False)
+ build_date = Column(u'build_date', DATE(), primary_key=True, nullable=False)
+ crash_type_id = Column(u'crash_type_id', INTEGER(), ForeignKey('crash_types.crash_type_id'), primary_key=True, nullable=False)
+ os_short_name = Column(u'os_short_name', CITEXT(), primary_key=True, nullable=False)
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False)
+ report_count = Column(u'report_count', INTEGER(), nullable=False)
+ report_date = Column(u'report_date', DATE(), primary_key=True, nullable=False)
+
+ #relationship definitions
+ crash_types = relationship('CrashType', primaryjoin='CrashesByUserBuild.crash_type_id==CrashType.crash_type_id')
+
+
+class CrontabberState(DeclarativeBase):
+ __tablename__ = 'crontabber_state'
+
+ __table_args__ = {}
+
+ #column definitions
+ last_updated = Column(u'last_updated', TIMESTAMP(timezone=True), primary_key=True, nullable=False)
+ state = Column(u'state', TEXT(), nullable=False)
+
+ # TODO Indexes
+ # crontabber_state_one_row = Index('crontabber_state_one_row', ON crontabber_state ((state IS NOT NULL)), unique=True)
+
+ #relationship definitions
+
+
+class DailyHang(DeclarativeBase):
+ __tablename__ = 'daily_hangs'
+
+ __table_args__ = {}
+
+ #column definitions
+ browser_signature_id = Column(u'browser_signature_id', INTEGER(), nullable=False)
+ duplicates = Column(u'duplicates', ARRAY(TEXT()))
+ flash_version_id = Column(u'flash_version_id', INTEGER())
+ hang_id = Column(u'hang_id', TEXT(), nullable=False)
+ plugin_signature_id = Column(u'plugin_signature_id', INTEGER(), nullable=False)
+ plugin_uuid = Column(u'plugin_uuid', TEXT(), primary_key=True, nullable=False)
+ product_version_id = Column(u'product_version_id', INTEGER(), nullable=False, autoincrement=False)
+ report_date = Column(u'report_date', DATE())
+ url = Column(u'url', CITEXT())
+ uuid = Column(u'uuid', TEXT(), nullable=False)
+
+ # Indexes
+ daily_hangs_browser_signature_id = Index('daily_hangs_browser_signature_id', browser_signature_id)
+ daily_hangs_flash_version_id = Index('daily_hangs_flash_version_id', flash_version_id)
+ daily_hangs_hang_id = Index('daily_hangs_hang_id', hang_id)
+ daily_hangs_plugin_signature_id = Index('daily_hangs_plugin_signature_id', plugin_signature_id)
+ daily_hangs_product_version_id = Index('daily_hangs_product_version_id', product_version_id)
+ daily_hangs_report_date = Index('daily_hangs_report_date', report_date)
+ daily_hangs_uuid = Index('daily_hangs_uuid', uuid)
+
+
+class Domain(DeclarativeBase):
+ __tablename__ = 'domains'
+
+ __table_args__ = {}
+
+ #column definitions
+ domain = Column(u'domain', CITEXT(), nullable=False)
+ domain_id = Column(u'domain_id', INTEGER(), primary_key=True, nullable=False)
+ first_seen = Column(u'first_seen', TIMESTAMP(timezone=True))
+
+ # Indexes
+ domains_domain_key = Index('domains_domain_key', domain, unique=True)
+ #relationship definitions
+
+
+class EmailCampaign(DeclarativeBase):
+ __tablename__ = 'email_campaigns'
+
+ __table_args__ = {}
+
+ #column definitions
+ author = Column(u'author', TEXT(), nullable=False)
+ body = Column(u'body', TEXT(), nullable=False)
+ date_created = Column(u'date_created', TIMESTAMP(timezone=True), nullable=False, server_default=text('NOW()'))
+ email_count = Column(u'email_count', INTEGER(), server_default=text('0'))
+ end_date = Column(u'end_date', TIMESTAMP(timezone=True), nullable=False)
+ id = Column(u'id', INTEGER(), primary_key=True, nullable=False)
+ product = Column(u'product', TEXT(), nullable=False)
+ signature = Column(u'signature', TEXT(), nullable=False)
+ start_date = Column(u'start_date', TIMESTAMP(timezone=True), nullable=False)
+ status = Column(u'status', TEXT(), nullable=False, server_default='stopped')
+ subject = Column(u'subject', TEXT(), nullable=False)
+ versions = Column(u'versions', TEXT(), nullable=False)
+
+ email_campaigns_product_signature_key = Index('email_campaigns_product_signature_key', product, signature);
+
+ #relationship definitions
+ email_contacts = relationship('EmailContact', primaryjoin='EmailCampaign.id==email_campaigns_contacts.c.email_campaigns_id', secondary='EmailCampaignsContact', secondaryjoin='EmailCampaignsContact.email_contacts_id==EmailContact.id')
+
+
+class EmailContact(DeclarativeBase):
+ __tablename__ = 'email_contacts'
+
+ __table_args__ = {}
+
+ #column definitions
+ crash_date = Column(u'crash_date', TIMESTAMP(timezone=True))
+ email = Column(u'email', TEXT(), nullable=False)
+ id = Column(u'id', INTEGER(), primary_key=True, nullable=False)
+ ooid = Column(u'ooid', TEXT())
+ subscribe_status = Column(u'subscribe_status', BOOLEAN(), server_default=text('True'))
+ subscribe_token = Column(u'subscribe_token', TEXT(), nullable=False)
+
+ # Indexes
+ email_contacts_email_unique = Index('email_contacts_email_unique', email, unique=True)
+ email_contacts_token_unique = Index('email_contacts_token_unique', subscribe_token, unique=True)
+
+ #relationship definitions
+ email_campaigns = relationship('EmailCampaign', primaryjoin='EmailContact.id==EmailCampaignsContact.email_contacts_id', secondary='EmailCampaignsContact', secondaryjoin='EmailCampaignsContact.email_campaigns_id==EmailCampaign.id')
+
+class Email(DeclarativeBase):
+ __tablename__ = 'emails'
+
+ __table_args__ = {}
+
+ #column definitions
+ email = Column(u'email', CITEXT(), nullable=False, primary_key=True)
+ last_sending = Column(u'last_sending', TIMESTAMP(timezone=True))
+
+class Explosivenes(DeclarativeBase):
+ __tablename__ = 'explosiveness'
+
+ __table_args__ = {}
+
+ #column definitions
+ day0 = Column(u'day0', NUMERIC())
+ day1 = Column(u'day1', NUMERIC())
+ day2 = Column(u'day2', NUMERIC())
+ day3 = Column(u'day3', NUMERIC())
+ day4 = Column(u'day4', NUMERIC())
+ day5 = Column(u'day5', NUMERIC())
+ day6 = Column(u'day6', NUMERIC())
+ day7 = Column(u'day7', NUMERIC())
+ day8 = Column(u'day8', NUMERIC())
+ day9 = Column(u'day9', NUMERIC())
+ last_date = Column(u'last_date', DATE(), primary_key=True, nullable=False)
+ oneday = Column(u'oneday', NUMERIC())
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False, index=True)
+ signature_id = Column(u'signature_id', INTEGER(), primary_key=True, nullable=False, index=True)
+ threeday = Column(u'threeday', NUMERIC())
+
+ explosiveness_product_version_id = Index('explosiveness_product_version_id', product_version_id)
+ explosiveness_signature_id = Index('explosiveness_signature_id', signature_id)
+
+ #relationship definitions
+
+
+class FlashVersion(DeclarativeBase):
+ __tablename__ = 'flash_versions'
+
+ __table_args__ = {}
+
+ #column definitions
+ first_seen = Column(u'first_seen', TIMESTAMP(timezone=True))
+ flash_version = Column(u'flash_version', CITEXT(), nullable=False)
+ flash_version_id = Column(u'flash_version_id', INTEGER(), primary_key=True, nullable=False)
+
+ # Indexes
+ flash_versions_flash_version_key = Index('flash_versions_flash_version_key', flash_version, unique=True)
+
+ #relationship definitions
+
+
+class HomePageGraph(DeclarativeBase):
+ __tablename__ = 'home_page_graph'
+
+ __table_args__ = {}
+
+ #column definitions
+ adu = Column(u'adu', INTEGER(), nullable=False, server_default=text('0'))
+ crash_hadu = Column(u'crash_hadu', NUMERIC(), nullable=False, server_default=text('0.0'))
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False)
+ report_count = Column(u'report_count', INTEGER(), nullable=False, server_default=text('0'))
+ report_date = Column(u'report_date', DATE(), primary_key=True, nullable=False)
+
+ #relationship definitions
+
+
+class HomePageGraphBuild(DeclarativeBase):
+ __tablename__ = 'home_page_graph_build'
+
+ __table_args__ = {}
+
+ #column definitions
+ adu = Column(u'adu', INTEGER(), nullable=False, server_default=text('0'))
+ build_date = Column(u'build_date', DATE(), primary_key=True, nullable=False)
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False)
+ report_count = Column(u'report_count', INTEGER(), nullable=False, server_default=text('0'))
+ report_date = Column(u'report_date', DATE(), primary_key=True, nullable=False)
+
+ # Indexes
+ home_page_graph_build_key = Index('home_page_graph_build_key', product_version_id, build_date, report_date, unique=True)
+
+ #relationship definitions
+
+
+class Job(DeclarativeBase):
+ __tablename__ = 'jobs'
+
+ __table_args__ = {}
+
+ #column definitions
+ id = Column(u'id', INTEGER(), primary_key=True, nullable=False)
+ message = Column(u'message', TEXT())
+ owner = Column(u'owner', INTEGER(), ForeignKey('processors.id'))
+ pathname = Column(u'pathname', VARCHAR(length=1024), nullable=False)
+ priority = Column(u'priority', INTEGER(), server_default=text('0'))
+ queueddatetime = Column(u'queueddatetime', TIMESTAMP(timezone=True))
+ starteddatetime = Column(u'starteddatetime', TIMESTAMP(timezone=True))
+ completeddatetime = Column(u'completeddatetime', TIMESTAMP(timezone=True))
+ success = Column(u'success', BOOLEAN())
+ uuid = Column(u'uuid', VARCHAR(length=50), nullable=False)
+
+ jobs_completeddatetime_queueddatetime_key = Index('jobs_completeddatetime_queueddatetime_key', completeddatetime, queueddatetime)
+ #relationship definitions
+ processors = relationship('Processor', primaryjoin='Job.owner==Processor.id')
+
+ # Indexes
+ jobs_completeddatetime_queueddatetime_key = Index('jobs_completeddatetime_queueddatetime_key', completeddatetime, queueddatetime)
+ jobs_owner_starteddatetime_key = Index('jobs_owner_starteddatetime_key', owner, starteddatetime)
+ jobs_uuid_key = Index('jobs_uuid_key', uuid, unique=True)
+
+
+class NightlyBuild(DeclarativeBase):
+ __tablename__ = 'nightly_builds'
+
+ __table_args__ = {}
+
+ #column definitions
+ build_date = Column(u'build_date', DATE(), primary_key=True, nullable=False)
+ days_out = Column(u'days_out', INTEGER(), primary_key=True, nullable=False)
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False)
+ report_count = Column(u'report_count', INTEGER(), nullable=False, server_default=text('0'))
+ report_date = Column(u'report_date', DATE(), nullable=False)
+
+ # Indexes
+ nightly_builds_product_version_id_report_date = Index('nightly_builds_product_version_id_report_date', product_version_id, report_date)
+ nightly_builds_key = Index('nightly_builds_key', product_version_id, build_date, days_out, unique=True)
+
+
+class OsName(DeclarativeBase):
+ __tablename__ = 'os_names'
+
+ __table_args__ = {}
+
+ #column definitions
+ os_name = Column(u'os_name', CITEXT(), primary_key=True, nullable=False)
+ os_short_name = Column(u'os_short_name', CITEXT(), nullable=False)
+
+ #relationship definitions
+
+
+class OsNameMatche(DeclarativeBase):
+ __tablename__ = 'os_name_matches'
+
+ __table_args__ = {}
+
+ #column definitions
+ match_string = Column(u'match_string', TEXT(), primary_key=True, nullable=False)
+ os_name = Column(u'os_name', CITEXT(), ForeignKey('os_names.os_name'), primary_key=True, nullable=False)
+
+ #relationship definitions
+ os_names = relationship('OsName', primaryjoin='OsNameMatche.os_name==OsName.os_name')
+ os_name_matches_key = Index('os_name_matches_key', os_name, match_string, unique=True)
+
+
+class OsVersion(DeclarativeBase):
+ __tablename__ = 'os_versions'
+
+ __table_args__ = {}
+
+ #column definitions
+ major_version = Column(u'major_version', INTEGER(), nullable=False)
+ minor_version = Column(u'minor_version', INTEGER(), nullable=False)
+ os_name = Column(u'os_name', CITEXT(), ForeignKey('os_names.os_name'), nullable=False)
+ os_version_id = Column(u'os_version_id', INTEGER(), primary_key=True, nullable=False)
+ os_version_string = Column(u'os_version_string', CITEXT())
+
+ # Indexes
+ os_versions_pkey = Index('os_versions_pkey', os_version_id, unique=True)
+
+ #relationship definitions
+ os_names = relationship('OsName', primaryjoin='OsVersion.os_name==OsName.os_name')
+
+
+class Plugin(DeclarativeBase):
+ __tablename__ = 'plugins'
+
+ __table_args__ = {}
+
+ #column definitions
+ filename = Column(u'filename', TEXT(), nullable=False)
+ id = Column(u'id', INTEGER(), primary_key=True, nullable=False)
+ name = Column(u'name', TEXT(), nullable=False)
+
+ # Indexes
+ filename_name_key = Index('filename_name_key', filename, name, unique=True)
+
+ #relationship definitions
+
+
+class Priorityjob(DeclarativeBase):
+ __tablename__ = 'priorityjobs'
+
+ __table_args__ = {}
+
+ #column definitions
+ uuid = Column(u'uuid', VARCHAR(length=255), primary_key=True, nullable=False)
+
+ #relationship definitions
+
+
+class PriorityjobsLoggingSwitch(DeclarativeBase):
+ __tablename__ = 'priorityjobs_logging_switch'
+
+ __table_args__ = {}
+
+ #column definitions
+ log_jobs = Column(u'log_jobs', BOOLEAN(), primary_key=True, nullable=False)
+
+ #relationship definitions
+
+
+class ProcessType(DeclarativeBase):
+ __tablename__ = 'process_types'
+
+ __table_args__ = {}
+
+ #column definitions
+ process_type = Column(u'process_type', CITEXT(), primary_key=True, nullable=False)
+
+ #relationship definitions
+
+
+class Processor(DeclarativeBase):
+ __tablename__ = 'processors'
+
+ __table_args__ = {}
+
+ #column definitions
+ id = Column(u'id', INTEGER(), primary_key=True, nullable=False)
+ lastseendatetime = Column(u'lastseendatetime', TIMESTAMP())
+ name = Column(u'name', VARCHAR(length=255), nullable=False)
+ startdatetime = Column(u'startdatetime', TIMESTAMP(), nullable=False)
+
+ #relationship definitions
+
+
+class Product(DeclarativeBase):
+ __tablename__ = 'products'
+
+ __table_args__ = {}
+
+ #column definitions
+ product_name = Column(u'product_name', CITEXT(), primary_key=True, nullable=False)
+ rapid_beta_version = Column(u'rapid_beta_version', MAJOR_VERSION())
+ rapid_release_version = Column(u'rapid_release_version', MAJOR_VERSION())
+ release_name = Column(u'release_name', CITEXT(), nullable=False)
+ sort = Column(u'sort', SMALLINT(), nullable=False, server_default=text('0'))
+
+ #relationship definitions
+ release_channels = relationship('ReleaseChannel', primaryjoin='Product.product_name==ProductReleaseChannel.product_name', secondary='ProductReleaseChannel', secondaryjoin='ProductReleaseChannel.release_channel==ReleaseChannel.release_channel')
+ product_versions = relationship('Product', primaryjoin='Product.product_name==ProductVersion.product_name', secondary='ProductVersion', secondaryjoin='ProductVersion.rapid_beta_id==ProductVersion.product_version_id')
+ signatures = relationship('Signature', primaryjoin='Product.product_name==SignatureProductsRollup.product_name', secondary='SignatureProductsRollup', secondaryjoin='SignatureProductsRollup.signature_id==Signature.signature_id')
+
+
+class ProductAdu(DeclarativeBase):
+ __tablename__ = 'product_adu'
+
+ __table_args__ = {}
+
+ #column definitions
+ adu_count = Column(u'adu_count', BIGINT(), nullable=False, server_default=text('0'))
+ adu_date = Column(u'adu_date', DATE(), primary_key=True, nullable=False)
+ os_name = Column(u'os_name', CITEXT(), primary_key=True, nullable=False)
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False)
+
+ # Indexes
+ product_adu_key = Index('product_adu_key', product_version_id, adu_date, os_name, unique=True)
+
+ #relationship definitions
+
+
+class ProductProductidMap(DeclarativeBase):
+ __tablename__ = 'product_productid_map'
+
+ __table_args__ = {}
+
+ #column definitions
+ product_name = Column(u'product_name', CITEXT(), ForeignKey('products.product_name'), nullable=False)
+ productid = Column(u'productid', TEXT(), primary_key=True, nullable=False)
+ rewrite = Column(u'rewrite', BOOLEAN(), nullable=False, server_default=text('False'))
+ version_began = Column(u'version_began', MAJOR_VERSION())
+ version_ended = Column(u'version_ended', MAJOR_VERSION())
+
+ # Indexes
+ productid_map_key2 = Index('productid_map_key2', product_name, version_began, unique=True)
+
+ #relationship definitions
+ products = relationship('Product', primaryjoin='ProductProductidMap.product_name==Product.product_name')
+
+
+class ProductReleaseChannel(DeclarativeBase):
+ __tablename__ = 'product_release_channels'
+
+ #column definitions
+ product_name = Column(u'product_name', CITEXT(), ForeignKey('products.product_name'), primary_key=True, nullable=False)
+ release_channel = Column(u'release_channel', CITEXT(), ForeignKey('release_channels.release_channel'), primary_key=True, nullable=False)
+ throttle = Column(u'throttle', NUMERIC(), nullable=False, server_default=text('1.0'))
+
+ #relationship definitions
+ release_channels = relationship('ReleaseChannel', primaryjoin='ProductReleaseChannel.release_channel==ReleaseChannel.release_channel')
+ products = relationship('Product', primaryjoin='ProductReleaseChannel.product_name==Product.product_name')
+
+
+class ProductVersion(DeclarativeBase):
+ __tablename__ = 'product_versions'
+
+ #column definitions
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False)
+ product_name = Column(u'product_name', CITEXT(), ForeignKey('products.product_name'), nullable=False, index=True)
+ major_version = Column(u'major_version', MAJOR_VERSION(), index=True)
+ release_version = Column(u'release_version', CITEXT(), nullable=False)
+ version_string = Column(u'version_string', CITEXT(), nullable=False)
+ beta_number = Column(u'beta_number', INTEGER())
+ version_sort = Column(u'version_sort', TEXT(), nullable=False, server_default="0", index=True)
+ build_date = Column(u'build_date', DATE(), nullable=False)
+ sunset_date = Column(u'sunset_date', DATE(), nullable=False)
+ featured_version = Column(u'featured_version', BOOLEAN(), nullable=False, server_default=text('False'))
+ build_type = Column(u'build_type', CITEXT(), nullable=False, server_default='release')
+ has_builds = Column(u'has_builds', BOOLEAN())
+ is_rapid_beta = Column(u'is_rapid_beta', BOOLEAN(), server_default=text('False'))
+ rapid_beta_id = Column(u'rapid_beta_id', INTEGER(), ForeignKey('product_versions.product_version_id'))
+
+ # Indexes
+ product_versions_major_version = Index('product_versions_major_version', major_version)
+ product_versions_product_name = Index('product_versions_product_name', product_name)
+ product_versions_version_sort = Index('product_versions_version_sort', version_sort)
+ product_version_version_key = Index('product_version_version_key', product_name, version_string, unique=True)
+
+ # TODO
+ # product_version_unique_beta = Index('product_version_unique_beta', ON product_versions product_name, release_version, beta_number) WHERE (beta_number IS NOT NULL, unique=True)
+
+ #relationship definitions
+ products = relationship('Product', primaryjoin='ProductVersion.product_version_id==ProductVersion.rapid_beta_id', secondary='ProductVersion', secondaryjoin='ProductVersion.product_name==Product.product_name')
+ product_versions = relationship('ProductVersion', primaryjoin='ProductVersion.rapid_beta_id==ProductVersion.product_version_id')
+
+
+class ProductVersionBuild(DeclarativeBase):
+ __tablename__ = 'product_version_builds'
+
+ __table_args__ = {}
+
+ #column definitions
+ build_id = Column(u'build_id', NUMERIC(), primary_key=True, nullable=False)
+ platform = Column(u'platform', TEXT(), primary_key=True, nullable=False)
+ product_version_id = Column(u'product_version_id', INTEGER(), ForeignKey('product_versions.product_version_id'), primary_key=True, nullable=False)
+ repository = Column(u'repository', CITEXT())
+
+ #relationship definitions
+ product_versions = relationship('ProductVersion', primaryjoin='ProductVersionBuild.product_version_id==ProductVersion.product_version_id')
+
+
+class RankCompare(DeclarativeBase):
+ __tablename__ = 'rank_compare'
+
+ __table_args__ = {}
+
+ #column definitions
+ percent_of_total = Column(u'percent_of_total', NUMERIC())
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False)
+ rank_days = Column(u'rank_days', INTEGER(), primary_key=True, nullable=False)
+ rank_report_count = Column(u'rank_report_count', INTEGER())
+ report_count = Column(u'report_count', INTEGER())
+ signature_id = Column(u'signature_id', INTEGER(), primary_key=True, nullable=False, index=True)
+ total_reports = Column(u'total_reports', BIGINT())
+
+ # Indexes
+ rank_compare_product_version_id_rank_report_count = Index('rank_compare_product_version_id_rank_report_count', product_version_id, rank_report_count)
+ rank_compare_signature_id = Index('rank_compare_signature_id', signature_id)
+
+
+class RawCrashes(DeclarativeBase):
+ __tablename__ = 'raw_crashes'
+
+ __table_args__ = {}
+
+ #column definitions
+ uuid = Column(u'uuid', UUID(), nullable=False, index=True, unique=True)
+ raw_crash = Column(u'raw_crash', JSON(), nullable=False)
+ date_processed = Column(u'date_processed', TIMESTAMP(timezone=True))
+
+ #relationship definitions
+ __mapper_args__ = {"primary_key":(uuid)}
+
+
+class Reason(DeclarativeBase):
+ __tablename__ = 'reasons'
+
+ __table_args__ = {}
+
+ #column definitions
+ first_seen = Column(u'first_seen', TIMESTAMP(timezone=True))
+ reason = Column(u'reason', CITEXT(), nullable=False)
+ reason_id = Column(u'reason_id', INTEGER(), primary_key=True, nullable=False)
+
+ # Indexes
+ reasons_reason_key = Index('reasons_reason_key', reason, unique=True)
+
+ #relationship definitions
+
+
+class ReleaseChannel(DeclarativeBase):
+ __tablename__ = 'release_channels'
+
+ __table_args__ = {}
+
+ #column definitions
+ release_channel = Column(u'release_channel', CITEXT(), primary_key=True, nullable=False)
+ sort = Column(u'sort', SMALLINT(), nullable=False, server_default=text('0'))
+
+ #relationship definitions
+ products = relationship('Product', primaryjoin='ReleaseChannel.release_channel==ProductReleaseChannel.release_channel', secondary='ProductReleaseChannel', secondaryjoin='ProductReleaseChannel.product_name==Product.product_name')
+ signatures = relationship('Signature', primaryjoin='ReleaseChannel.release_channel==Tcbs.release_channel', secondary='Tcbs', secondaryjoin='Tcbs.signature_id==Signature.signature_id')
+
+
+class ReleaseChannelMatch(DeclarativeBase):
+ __tablename__ = 'release_channel_matches'
+
+ __table_args__ = {}
+
+ #column definitions
+ match_string = Column(u'match_string', TEXT(), primary_key=True, nullable=False)
+ release_channel = Column(u'release_channel', CITEXT(), ForeignKey('release_channels.release_channel'), primary_key=True, nullable=False)
+
+
+ #relationship definitions
+ release_channels = relationship('ReleaseChannel', primaryjoin='ReleaseChannelMatch.release_channel==ReleaseChannel.release_channel')
+
+
+class ReleaseRepository(DeclarativeBase):
+ __tablename__ = 'release_repositories'
+
+ __table_args__ = {}
+
+ #column definitions
+ repository = Column(u'repository', CITEXT(), primary_key=True, nullable=False)
+
+ #relationship definitions
+
+
+class ReleasesRaw(DeclarativeBase):
+ __tablename__ = 'releases_raw'
+
+ __table_args__ = {}
+
+ #column definitions
+ beta_number = Column(u'beta_number', INTEGER())
+ build_id = Column(u'build_id', NUMERIC(), primary_key=True, nullable=False)
+ build_type = Column(u'build_type', CITEXT(), primary_key=True, nullable=False)
+ platform = Column(u'platform', TEXT(), primary_key=True, nullable=False)
+ product_name = Column(u'product_name', CITEXT(), primary_key=True, nullable=False)
+ repository = Column(u'repository', CITEXT(), primary_key=True, nullable=False, server_default='mozilla-release')
+ version = Column(u'version', TEXT(), primary_key=True, nullable=False)
+
+ #relationship definitions
+ # TODO function-based index
+ from sqlalchemy import func
+# releases_raw_date = Index('releases_raw_date', func.build_date(build_id));
+ # Index( releases_raw_date ON releases_raw USING btree (build_date(build_id))
+
+
+class ReportPartitionInfo(DeclarativeBase):
+ __tablename__ = 'report_partition_info'
+
+ __table_args__ = {}
+
+ #column definitions
+ build_order = Column(u'build_order', INTEGER(), nullable=False, server_default=text('1'))
+ fkeys = Column(u'fkeys', ARRAY(TEXT()), nullable=False, server_default=text("'{}'::text[]"))
+ indexes = Column(u'indexes', ARRAY(TEXT()), nullable=False, server_default=text("'{}'::text[]"))
+ keys = Column(u'keys', ARRAY(TEXT()), nullable=False, server_default=text("'{}'::text[]"))
+ table_name = Column(u'table_name', CITEXT(), primary_key=True, nullable=False)
+
+ #relationship definitions
+
+
+class ReportsClean(DeclarativeBase):
+ __tablename__ = 'reports_clean'
+
+ __table_args__ = {}
+
+ #column definitions
+ address_id = Column(u'address_id', INTEGER(), nullable=False)
+ architecture = Column(u'architecture', CITEXT())
+ build = Column(u'build', NUMERIC())
+ client_crash_date = Column(u'client_crash_date', TIMESTAMP(timezone=True))
+ cores = Column(u'cores', INTEGER())
+ date_processed = Column(u'date_processed', TIMESTAMP(timezone=True), nullable=False)
+ domain_id = Column(u'domain_id', INTEGER(), nullable=False)
+ duplicate_of = Column(u'duplicate_of', TEXT())
+ flash_process_dump = Column(u'flash_process_dump', flash_process_dump_type())
+ flash_version_id = Column(u'flash_version_id', INTEGER(), nullable=False)
+ hang_id = Column(u'hang_id', TEXT())
+ install_age = Column(u'install_age', INTERVAL())
+ os_name = Column(u'os_name', CITEXT(), nullable=False)
+ os_version_id = Column(u'os_version_id', INTEGER(), nullable=False)
+ process_type = Column(u'process_type', CITEXT(), nullable=False)
+ product_version_id = Column(u'product_version_id', INTEGER(), autoincrement=False)
+ reason_id = Column(u'reason_id', INTEGER(), nullable=False)
+ release_channel = Column(u'release_channel', CITEXT(), nullable=False)
+ signature_id = Column(u'signature_id', INTEGER(), nullable=False)
+ uptime = Column(u'uptime', INTERVAL())
+ uuid = Column(u'uuid', TEXT(), primary_key=True, nullable=False)
+
+ #relationship definitions
+
+
+class ReportsDuplicate(DeclarativeBase):
+ __tablename__ = 'reports_duplicates'
+
+ __table_args__ = {}
+
+ #column definitions
+ date_processed = Column(u'date_processed', TIMESTAMP(timezone=True), nullable=False)
+ duplicate_of = Column(u'duplicate_of', TEXT(), nullable=False, index=True)
+ uuid = Column(u'uuid', TEXT(), primary_key=True, nullable=False)
+
+ # Indexes
+ reports_duplicates_leader = Index('reports_duplicates_leader', duplicate_of)
+ reports_duplicates_timestamp = Index('reports_duplicates_timestamp', date_processed, uuid)
+
+
+class ReportsUserInfo(DeclarativeBase):
+ __tablename__ = 'reports_user_info'
+
+ __table_args__ = {}
+
+ #column definitions
+ app_notes = Column(u'app_notes', CITEXT())
+ date_processed = Column(u'date_processed', TIMESTAMP(timezone=True), nullable=False)
+ email = Column(u'email', CITEXT())
+ url = Column(u'url', TEXT())
+ user_comments = Column(u'user_comments', CITEXT())
+ uuid = Column(u'uuid', TEXT(), primary_key=True, nullable=False)
+
+ #relationship definitions
+
+
+class ServerStatu(DeclarativeBase):
+ __tablename__ = 'server_status'
+
+ __table_args__ = {}
+
+ #column definitions
+ avg_process_sec = Column(u'avg_process_sec', REAL())
+ avg_wait_sec = Column(u'avg_wait_sec', REAL())
+ date_created = Column(u'date_created', TIMESTAMP(timezone=True), nullable=False)
+ date_oldest_job_queued = Column(u'date_oldest_job_queued', TIMESTAMP(timezone=True))
+ date_recently_completed = Column(u'date_recently_completed', TIMESTAMP(timezone=True))
+ id = Column(u'id', INTEGER(), primary_key=True, nullable=False)
+ processors_count = Column(u'processors_count', INTEGER(), nullable=False)
+ waiting_job_count = Column(u'waiting_job_count', INTEGER(), nullable=False)
+
+ # Index
+ idx_server_status_date = Index('idx_server_status_date', date_created, id)
+
+
+class Session(DeclarativeBase):
+ __tablename__ = 'sessions'
+
+ __table_args__ = {}
+
+ #column definitions
+ data = Column(u'data', TEXT(), nullable=False)
+ last_activity = Column(u'last_activity', INTEGER(), nullable=False)
+ session_id = Column(u'session_id', VARCHAR(length=127), primary_key=True, nullable=False)
+
+ #relationship definitions
+
+
+class Signature(DeclarativeBase):
+ __tablename__ = 'signatures'
+
+ __table_args__ = {}
+
+ #column definitions
+ first_build = Column(u'first_build', NUMERIC())
+ first_report = Column(u'first_report', TIMESTAMP(timezone=True))
+ signature = Column(u'signature', TEXT())
+ signature_id = Column(u'signature_id', INTEGER(), primary_key=True, nullable=False)
+
+ # Indexes
+ signatures_signature_key = Index('signatures_signature_key', signature, unique=True)
+
+ #relationship definitions
+ products = relationship('Product', primaryjoin='Signature.signature_id==SignatureProductsRollup.signature_id', secondary='SignatureProductsRollup', secondaryjoin='SignatureProductsRollup.product_name==Product.product_name')
+ release_channels = relationship('ReleaseChannel', primaryjoin='Signature.signature_id==Tcbs.signature_id', secondary='Tcbs', secondaryjoin='Tcbs.release_channel==ReleaseChannel.release_channel')
+
+
+class SignatureProduct(DeclarativeBase):
+ __tablename__ = 'signature_products'
+
+ __table_args__ = {}
+
+ #column definitions
+ first_report = Column(u'first_report', TIMESTAMP(timezone=True))
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False, index=True)
+ signature_id = Column(u'signature_id', INTEGER(), ForeignKey('signatures.signature_id'), primary_key=True, nullable=False)
+
+ # Indexes
+ signature_products_product_version = Index('signature_products_product_version', product_version_id)
+
+ #relationship definitions
+ signatures = relationship('Signature', primaryjoin='SignatureProduct.signature_id==Signature.signature_id')
+
+class SignatureProductsRollup(DeclarativeBase):
+ __tablename__ = 'signature_products_rollup'
+
+ signature_id = Column(u'signature_id', INTEGER(), ForeignKey('signatures.signature_id'), primary_key=True, nullable=False)
+ product_name = Column(u'product_name', CITEXT(), ForeignKey('products.product_name'), primary_key=True, nullable=False)
+ ver_count = Column(u'ver_count', INTEGER(), nullable=False, server_default=text('0'))
+ version_list = Column(u'version_list', ARRAY(TEXT()), nullable=False, server_default=text("'{}'::text[]"))
+
+ #relationship definitions
+ products = relationship('Product', primaryjoin='SignatureProductsRollup.product_name==Product.product_name')
+ signatures = relationship('Signature', primaryjoin='SignatureProductsRollup.signature_id==Signature.signature_id')
+
+
+class SocorroDbVersion(DeclarativeBase):
+ __tablename__ = 'socorro_db_version'
+
+ __table_args__ = {}
+
+ #column definitions
+ current_version = Column(u'current_version', TEXT(), primary_key=True, nullable=False)
+ refreshed_at = Column(u'refreshed_at', TIMESTAMP(timezone=True))
+
+ #relationship definitions
+
+
+class SocorroDbVersionHistory(DeclarativeBase):
+ __tablename__ = 'socorro_db_version_history'
+
+ __table_args__ = {}
+
+ #column definitions
+ backfill_to = Column(u'backfill_to', DATE())
+ upgraded_on = Column(u'upgraded_on', TIMESTAMP(timezone=True), primary_key=True, nullable=False, server_default=text('NOW()'))
+ version = Column(u'version', TEXT(), primary_key=True, nullable=False)
+
+ #relationship definitions
+
+
+class SpecialProductPlatform(DeclarativeBase):
+ __tablename__ = 'special_product_platforms'
+
+ __table_args__ = {}
+
+ #column definitions
+ min_version = Column(u'min_version', MAJOR_VERSION())
+ platform = Column(u'platform', CITEXT(), primary_key=True, nullable=False)
+ product_name = Column(u'product_name', CITEXT(), nullable=False)
+ release_channel = Column(u'release_channel', CITEXT(), primary_key=True, nullable=False)
+ release_name = Column(u'release_name', CITEXT(), primary_key=True, nullable=False)
+ repository = Column(u'repository', CITEXT(), primary_key=True, nullable=False)
+
+ #relationship definitions
+
+
+class TcbsBuild(DeclarativeBase):
+ __tablename__ = 'tcbs_build'
+
+ __table_args__ = {}
+
+ #column definitions
+ build_date = Column(u'build_date', DATE(), primary_key=True, nullable=False)
+ hang_count = Column(u'hang_count', INTEGER(), nullable=False, server_default=text('0'))
+ lin_count = Column(u'lin_count', INTEGER(), nullable=False, server_default=text('0'))
+ mac_count = Column(u'mac_count', INTEGER(), nullable=False, server_default=text('0'))
+ process_type = Column(u'process_type', CITEXT(), primary_key=True, nullable=False)
+ product_version_id = Column(u'product_version_id', INTEGER(), primary_key=True, nullable=False, autoincrement=False)
+ release_channel = Column(u'release_channel', CITEXT(), nullable=False)
+ report_count = Column(u'report_count', INTEGER(), nullable=False, server_default=text('0'))
+ report_date = Column(u'report_date', DATE(), primary_key=True, nullable=False)
+ signature_id = Column(u'signature_id', INTEGER(), primary_key=True, nullable=False)
+ startup_count = Column(u'startup_count', INTEGER())
+ win_count = Column(u'win_count', INTEGER(), nullable=False, server_default=text('0'))
+
+ #relationship definitions
+
+
+class TransformRule(DeclarativeBase):
+ __tablename__ = 'transform_rules'
+
+ __table_args__ = {}
+
+ #column definitions
+ transform_rule_id = Column(u'transform_rule_id', INTEGER(), primary_key=True, nullable=False)
+ category = Column(u'category', CITEXT(), nullable=False)
+ rule_order = Column(u'rule_order', INTEGER(), nullable=False)
+ action = Column(u'action', TEXT(), nullable=False, server_default='')
+ action_args = Column(u'action_args', TEXT(), nullable=False, server_default='')
+ action_kwargs = Column(u'action_kwargs', TEXT(), nullable=False, server_default='')
+ predicate = Column(u'predicate', TEXT(), nullable=False, server_default='')
+ predicate_args = Column(u'predicate_args', TEXT(), nullable=False, server_default='')
+ predicate_kwargs = Column(u'predicate_kwargs', TEXT(), nullable=False, server_default='')
+
+ # Indexes
+ transform_rules_key = Index('transform_rules_key', category, rule_order, unique=True)
+
+ #relationship definitions
+
+
+class UptimeLevel(DeclarativeBase):
+ __tablename__ = 'uptime_levels'
+
+ __table_args__ = {}
+
+ #column definitions
+ max_uptime = Column(u'max_uptime', INTERVAL(), nullable=False)
+ min_uptime = Column(u'min_uptime', INTERVAL(), nullable=False)
+ uptime_level = Column(u'uptime_level', INTEGER(), primary_key=True, nullable=False, autoincrement=False)
+ uptime_string = Column(u'uptime_string', CITEXT(), nullable=False)
+
+ # Indexes
+ uptime_levels_uptime_string_key = Index('uptime_levels_uptime_string_key', uptime_string, unique=True)
+
+ #relationship definitions
+
+###########################################
+## Special, non-table schema objects
+###########################################
+
+
+###########################################
+## Schema definition: Aggregates
+###########################################
+
+@event.listens_for(UptimeLevel.__table__, "after_create")
+def array_accum(target, connection, **kw):
+ array_accum = """
+CREATE AGGREGATE array_accum(anyelement) (
+ SFUNC = array_append,
+ STYPE = anyarray,
+ INITCOND = '{}'
+)
+"""
+ connection.execute(array_accum)
View
366 socorro/external/postgresql/raw_sql/procs/001_update_reports_clean.sql
@@ -0,0 +1,366 @@
+CREATE FUNCTION update_reports_clean(fromtime timestamp with time zone, fortime interval DEFAULT '01:00:00'::interval, checkdata boolean DEFAULT true, analyze_it boolean DEFAULT true) RETURNS boolean
+ LANGUAGE plpgsql
+ SET client_min_messages TO 'ERROR'
+ AS $_$
+declare rc_part TEXT;
+ rui_part TEXT;
+ newfortime INTERVAL;
+begin
+-- this function creates a reports_clean fact table and all associated dimensions
+-- intended to be run hourly for a target time three hours ago or so
+-- eventually to be replaced by code for the processors to run
+
+-- VERSION: 7
+-- now includes support for rapid betas, camino transition
+
+-- accepts a timestamptz, so be careful that the calling script is sending
+-- something appropriate
+
+-- since we do allow dynamic timestamps, check if we split over a week
+-- boundary. if so, call self recursively for the first half of the period
+
+IF ( week_begins_utc(fromtime) <>
+ week_begins_utc( fromtime + fortime - interval '1 second' ) ) THEN
+ PERFORM update_reports_clean( fromtime,
+ ( week_begins_utc( fromtime + fortime ) - fromtime ), checkdata );
+ newfortime := ( fromtime + fortime ) - week_begins_utc( fromtime + fortime );
+ fromtime := week_begins_utc( fromtime + fortime );
+ fortime := newfortime;
+END IF;
+
+-- prevent calling for a period of more than one day
+
+IF fortime > INTERVAL '1 day' THEN
+ RAISE EXCEPTION 'you may not execute this function on more than one day of data';
+END IF;
+
+-- create a temporary table from the hour of reports you want to
+-- process. generally this will be from 3-4 hours ago to
+-- avoid missing reports
+
+-- RULE: replace NULL reason, address, flash_version, os_name with "Unknown"
+-- RULE: replace NULL signature, url with ''
+-- pre-cleaning: replace NULL product, version with ''
+-- RULE: extract number of cores from cpu_info
+-- RULE: convert all reference list TEXT values to CITEXT except Signature
+
+create temporary table new_reports
+on commit drop
+as select uuid,
+ date_processed,
+ client_crash_date,
+ uptime,
+ install_age,
+ build,
+ COALESCE(signature, '')::text as signature,
+ COALESCE(reason, 'Unknown')::citext as reason,
+ COALESCE(address, 'Unknown')::citext as address,
+ COALESCE(flash_version, 'Unknown')::citext as flash_version,
+ COALESCE(product, '')::citext as product,
+ COALESCE(version, '')::citext as version,
+ COALESCE(os_name, 'Unknown')::citext as os_name,
+ os_version::citext as os_version,
+ coalesce(process_type, 'Browser') as process_type,
+ COALESCE(url2domain(url),'') as domain,
+ email, user_comments, url, app_notes,
+ release_channel, hangid as hang_id,
+ cpu_name as architecture,
+ get_cores(cpu_info) as cores
+from reports
+where date_processed >= fromtime and date_processed < ( fromtime + fortime )
+ and completed_datetime is not null;
+
+-- check for no data
+
+PERFORM 1 FROM new_reports
+LIMIT 1;
+IF NOT FOUND THEN
+ IF checkdata THEN
+ RAISE EXCEPTION 'no report data found for period %',fromtime;
+ ELSE
+ DROP TABLE new_reports;
+ RETURN TRUE;
+ END IF;
+END IF;
+
+create index new_reports_uuid on new_reports(uuid);
+create index new_reports_signature on new_reports(signature);
+create index new_reports_address on new_reports(address);
+create index new_reports_domain on new_reports(domain);
+create index new_reports_reason on new_reports(reason);
+analyze new_reports;
+
+-- trim reports_bad to 2 days of data
+DELETE FROM reports_bad
+WHERE date_processed < ( now() - interval '2 days' );
+
+-- delete any reports which were already processed
+delete from new_reports
+using reports_clean
+where new_reports.uuid = reports_clean.uuid
+and reports_clean.date_processed between ( fromtime - interval '1 day' )
+and ( fromtime + fortime + interval '1 day' );
+
+-- RULE: strip leading "0.0.0 Linux" from Linux version strings
+UPDATE new_reports
+SET os_version = regexp_replace(os_version, $x$[0\.]+\s+Linux\s+$x$, '')
+WHERE os_version LIKE '%0.0.0%'
+ AND os_name ILIKE 'Linux%';
+
+-- RULE: IF camino, SET release_channel for camino 2.1
+-- camino 2.2 will have release_channel properly set
+
+UPDATE new_reports
+SET release_channel = 'release'
+WHERE product ilike 'camino'
+ AND version like '2.1%'
+ AND version not like '%pre%';
+
+UPDATE new_reports
+SET release_channel = 'beta'
+WHERE product ilike 'camino'
+ AND version like '2.1%'
+ AND version like '%pre%';
+
+-- insert signatures into signature list
+insert into signatures ( signature, first_report, first_build )
+select newsigs.* from (
+ select signature::citext as signature,
+ min(date_processed) as first_report,
+ min(build_numeric(build)) as first_build
+ from new_reports
+ group by signature::citext ) as newsigs
+left join signatures
+ on newsigs.signature = signatures.signature
+where signatures.signature IS NULL;
+
+-- insert oses into os list
+
+PERFORM update_os_versions_new_reports();
+
+-- insert reasons into reason list
+
+PERFORM update_lookup_new_reports('reason');
+
+-- insert addresses into address list
+
+PERFORM update_lookup_new_reports('address');
+
+-- insert flash_versions into flash version list
+
+PERFORM update_lookup_new_reports('flash_version');
+
+-- insert domains into the domain list
+
+PERFORM update_lookup_new_reports('domain');
+
+-- do not update reports_duplicates
+-- this procedure assumes that it has already been run
+-- later reports_duplicates will become a callable function from this function
+-- maybe
+
+-- create empty reports_clean_buffer
+create temporary table reports_clean_buffer
+(
+uuid text not null primary key,
+date_processed timestamptz not null,
+client_crash_date timestamptz,
+product_version_id int,
+build numeric,
+signature_id int,
+install_age interval,
+uptime interval,
+reason_id int,
+address_id int,
+os_name citext,
+os_version_id int,
+major_version int,
+minor_version int,
+hang_id text,
+flash_version_id int,
+process_type citext,
+release_channel citext,
+duplicate_of text,
+domain_id int,
+architecture citext,
+cores int
+) on commit drop ;
+
+-- populate the new buffer with uuid, date_processed,
+-- client_crash_date, build, install_time, uptime,
+-- hang_id, duplicate_of, reason, address, flash_version,
+-- release_channel
+
+-- RULE: convert install_age, uptime to INTERVAL
+-- RULE: convert reason, address, flash_version, URL domain to lookup list ID
+-- RULE: add possible duplicate UUID link
+-- RULE: convert release_channel to canonical release_channel based on
+-- channel match list
+
+INSERT INTO reports_clean_buffer
+SELECT new_reports.uuid,
+ new_reports.date_processed,
+ client_crash_date,
+ 0,
+ build_numeric(build),
+ signatures.signature_id,
+ install_age * interval '1 second',
+ uptime * interval '1 second',
+ reasons.reason_id,
+ addresses.address_id,
+ NULL, NULL, 0, 0,
+ hang_id,
+ flash_versions.flash_version_id,
+ process_type,
+ release_channel_matches.release_channel,
+ reports_duplicates.duplicate_of,
+ domains.domain_id,
+ architecture,
+ cores
+FROM new_reports
+LEFT OUTER JOIN release_channel_matches ON new_reports.release_channel ILIKE release_channel_matches.match_string
+LEFT OUTER JOIN signatures ON new_reports.signature = signatures.signature
+LEFT OUTER JOIN reasons ON new_reports.reason = reasons.reason
+LEFT OUTER JOIN addresses ON new_reports.address = addresses.address
+LEFT OUTER JOIN flash_versions ON new_reports.flash_version = flash_versions.flash_version
+LEFT OUTER JOIN reports_duplicates ON new_reports.uuid = reports_duplicates.uuid
+ AND reports_duplicates.date_processed BETWEEN (fromtime - interval '1 day') AND (fromtime + interval '1 day' )
+LEFT OUTER JOIN domains ON new_reports.domain = domains.domain
+ORDER BY new_reports.uuid;
+