59 lines
1.7 KiB
JavaScript
Executable File
59 lines
1.7 KiB
JavaScript
Executable File
exports.up = async (knex) => Promise.resolve()
|
|
.then(() => knex.schema.createTable('random_campaign', (table) => {
|
|
table.text('banner_id')
|
|
.references('id')
|
|
.inTable('banners');
|
|
|
|
table.text('url');
|
|
|
|
table.integer('entity_id')
|
|
.references('id')
|
|
.inTable('entities');
|
|
|
|
table.string('affiliate_id')
|
|
.references('id')
|
|
.inTable('affiliates');
|
|
|
|
table.integer('parent_id')
|
|
.references('id')
|
|
.inTable('entities');
|
|
}))
|
|
.then(() => knex.raw(`
|
|
ALTER TABLE banners ADD COLUMN ratio numeric GENERATED ALWAYS AS (ROUND(width::decimal/ height::decimal, 2)) STORED;
|
|
`))
|
|
.then(() => knex.raw(`
|
|
DROP FUNCTION IF EXISTS get_random_campaign;
|
|
DROP FUNCTION IF EXISTS banners_ratio;
|
|
|
|
CREATE FUNCTION get_random_campaign(min_ratio decimal default 0, max_ratio decimal default 1000.0) RETURNS random_campaign AS $$
|
|
SELECT * FROM (
|
|
SELECT DISTINCT ON (CASE WHEN parent_id IS NOT NULL THEN parent_id ELSE entity_id END)
|
|
banner_id, url, entity_id, affiliate_id, parent_id
|
|
FROM (
|
|
SELECT
|
|
campaigns.*, entities.parent_id as parent_id
|
|
FROM campaigns
|
|
LEFT JOIN entities ON entities.id = campaigns.entity_id
|
|
LEFT JOIN banners ON banners.id = campaigns.banner_id
|
|
WHERE banner_id IS NOT NULL
|
|
AND ratio >= min_ratio
|
|
AND ratio <= max_ratio
|
|
ORDER BY RANDOM()
|
|
) random_campaigns
|
|
) random_banners
|
|
ORDER BY RANDOM()
|
|
LIMIT 1;
|
|
$$ LANGUAGE SQL STABLE;
|
|
`));
|
|
|
|
exports.down = async (knex) => knex.raw(`
|
|
DROP FUNCTION IF EXISTS get_random_campaign;
|
|
DROP TABLE IF EXISTS random_campaign;
|
|
|
|
ALTER TABLE banners DROP COLUMN ratio;
|
|
|
|
CREATE FUNCTION banners_ratio(banner banners) RETURNS numeric AS $$
|
|
SELECT ROUND(banner.width::decimal / banner.height::decimal, 2);
|
|
$$ LANGUAGE SQL STABLE;
|
|
`);
|