| Version 4 (modified by , 3 years ago) ( diff ) |
|---|
Напредни извештаи од базата (SQL и складирани процедури)
Извештај за најдобрите магационери во однос на нивната највредна креирана фактура. Се прикажуваат информации за вкупната сума во фактурата која ја наплатиле и дополнително се прикажува фактурираниот артикл кој имал најголема вкупна цена во истата таа фактура
select u.firstname, u.lastname, u.username, u.email, max(ti.totalPrice) as topInvoiceSum,
(select a.articlename from articles a
left join invoicedarticles i2 on i2.articleid=a.articleid
where i2.price*i2.quantity=max(ba.totalPrice)) as topArticleName,
(select i2.price from articles a
left join invoicedarticles i2 on i2.articleid=a.articleid
where i2.price*i2.quantity=max(ba.totalPrice)) as topArticlePrice,
(select i2.quantity from articles a
left join invoicedarticles i2 on i2.articleid=a.articleid
where i2.price*i2.quantity=max(ba.totalPrice)) as topArticleQuantity,
max(ba.totalPrice) as topArticleTotalPrice from workers w
left join users u on u.userid=w.userid
left join
(
select i.invoiceid, i.workeruserid , sum(ia.price*ia.quantity) as totalPrice from invoices i
left join invoicedarticles ia on ia.invoiceid=i.invoiceid
group by i.invoiceid, i.workeruserid
) ti on ti.workeruserid=u.userid
left join
(
select ia2.invoiceid, a.articlename, ia2.price as price, ia2.quantity as quantity, ia2.price*ia2.quantity as totalPrice from invoicedarticles ia2
left join articles a on a.articleid=ia2.articleid
) ba on ba.invoiceid=ti.invoiceid
group by u.userid
order by topInvoiceSum desc
limit 5
Извештај за најнепрофитабилната категорија на артикли. Се прикажуваат информации за името на категоријата, нејзиниот профит и информации за вкупниот и просечниот прилив и одлив по артикл
select c.categoryname, prihod.pri-odliv.odl as profit, prihod.pri as priliv, odliv.odl as odliv,
(select avg(i2.quantity*i2.price) from invoicedarticles i2) as avgPrihod,
(select avg(o2.quantity*o2.price) from orderedarticles o2) as avgOdliv
from categories c
left join (
select abtc.categoryid, coalesce(sum(i.quantity*i.price), 0) as pri from articles a
left join article_belongs_to_category abtc on abtc.articleid=a.articleid
left join invoicedarticles i on i.articleid=a.articleid
group by abtc.categoryid
) prihod on prihod.categoryid=c.categoryid
left join (
select abtc.categoryid, coalesce(sum(o.quantity*o.price), 0) as odl from articles a
left join article_belongs_to_category abtc on abtc.articleid=a.articleid
left join orderedarticles o on o.articleid=a.articleid
group by abtc.categoryid
)odliv on odliv.categoryid=c.categoryid
where prihod.pri-odliv.odl=(select min(prihod.pri-odliv.odl) from categories c
left join (
select abtc.categoryid, coalesce(sum(i.quantity*i.price), 0) as pri from articles a
left join article_belongs_to_category abtc on abtc.articleid=a.articleid
left join invoicedarticles i on i.articleid=a.articleid
group by abtc.categoryid
) prihod on prihod.categoryid=c.categoryid
left join (
select abtc.categoryid, coalesce(sum(o.quantity*o.price), 0) as odl from articles a
left join article_belongs_to_category abtc on abtc.articleid=a.articleid
left join orderedarticles o on o.articleid=a.articleid
group by abtc.categoryid
)odliv on odliv.categoryid=c.categoryid)
Извештај за профитот на сите магацини според набавени артикли и продадени артикли во период од една година
select q1.locationname, prihod-odliv as profit from
(
select l.locationid, l.locationname, sum(i.price*i.quantity) as prihod from locations l
left join storedarticles s on s.locationid=l.locationid
left join invoicedarticles i on i.articleid=s.articleid
left join invoices i2 on i2.invoiceid=i.invoiceid and i2.datecreate between now()-interval '1 year' and now()
group by l.locationid
) as q1
full outer join
(
select l.locationid, l.locationname, sum(o.price*o.quantity) as odliv from locations l
left join orderedarticles o on o.locationid=l.locationid
left join orders o2 on o2.orderid=o.orderid and o2.datecreated between now()-interval '1 year' and now()
group by l.locationid
) q2 on q2.locationid=q1.locationid
Note:
See TracWiki
for help on using the wiki.
